Simplify 3-query skimming limits to omit the last redundant limit
[dbsrgits/DBIx-Class.git] / lib / DBIx / Class / SQLMaker / LimitDialects.pm
CommitLineData
d5dedbd6 1package DBIx::Class::SQLMaker::LimitDialects;
7fca91be 2
3use warnings;
4use strict;
5
7fca91be 6use List::Util 'first';
7use namespace::clean;
8
fcb7fcbb 9# constants are used not only here, but also in comparison tests
10sub __rows_bindtype () {
11 +{ sqlt_datatype => 'integer' }
12}
13sub __offset_bindtype () {
14 +{ sqlt_datatype => 'integer' }
15}
16sub __total_bindtype () {
17 +{ sqlt_datatype => 'integer' }
18}
19
d5dedbd6 20=head1 NAME
21
22DBIx::Class::SQLMaker::LimitDialects - SQL::Abstract::Limit-like functionality for DBIx::Class::SQLMaker
23
24=head1 DESCRIPTION
25
26This module replicates a lot of the functionality originally found in
27L<SQL::Abstract::Limit>. While simple limits would work as-is, the more
28complex dialects that require e.g. subqueries could not be reliably
29implemented without taking full advantage of the metadata locked within
30L<DBIx::Class::ResultSource> classes. After reimplementation of close to
3180% of the L<SQL::Abstract::Limit> functionality it was deemed more
32practical to simply make an independent DBIx::Class-specific limit-dialect
33provider.
34
35=head1 SQL LIMIT DIALECTS
36
37Note that the actual implementations listed below never use C<*> literally.
38Instead proper re-aliasing of selectors and order criteria is done, so that
39the limit dialect are safe to use on joined resultsets with clashing column
40names.
41
42Currently the provided dialects are:
43
d5dedbd6 44=head2 LimitOffset
45
46 SELECT ... LIMIT $limit OFFSET $offset
47
48Supported by B<PostgreSQL> and B<SQLite>
49
50=cut
7fca91be 51sub _LimitOffset {
fcb7fcbb 52 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
53 $sql .= $self->_parse_rs_attrs( $rs_attrs ) . " LIMIT ?";
54 push @{$self->{limit_bind}}, [ $self->__rows_bindtype => $rows ];
55 if ($offset) {
56 $sql .= " OFFSET ?";
57 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset ];
58 }
7fca91be 59 return $sql;
60}
61
d5dedbd6 62=head2 LimitXY
63
64 SELECT ... LIMIT $offset $limit
65
66Supported by B<MySQL> and any L<SQL::Statement> based DBD
67
68=cut
7fca91be 69sub _LimitXY {
fcb7fcbb 70 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
71 $sql .= $self->_parse_rs_attrs( $rs_attrs ) . " LIMIT ";
72 if ($offset) {
73 $sql .= '?, ';
74 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset ];
75 }
76 $sql .= '?';
77 push @{$self->{limit_bind}}, [ $self->__rows_bindtype => $rows ];
78
7fca91be 79 return $sql;
80}
d5dedbd6 81
82=head2 RowNumberOver
83
84 SELECT * FROM (
85 SELECT *, ROW_NUMBER() OVER( ORDER BY ... ) AS RNO__ROW__INDEX FROM (
86 SELECT ...
87 )
88 ) WHERE RNO__ROW__INDEX BETWEEN ($offset+1) AND ($limit+$offset)
89
90
91ANSI standard Limit/Offset implementation. Supported by B<DB2> and
92B<< MSSQL >= 2005 >>.
93
94=cut
7fca91be 95sub _RowNumberOver {
96 my ($self, $sql, $rs_attrs, $rows, $offset ) = @_;
97
7fca91be 98 # get selectors, and scan the order_by (if any)
cecf64bc 99 my $sq_attrs = $self->_subqueried_limit_attrs ( $sql, $rs_attrs );
7fca91be 100
101 # make up an order if none exists
102 my $requested_order = (delete $rs_attrs->{order_by}) || $self->_rno_default_order;
103 my $rno_ord = $self->_order_by ($requested_order);
104
105 # this is the order supplement magic
cecf64bc 106 my $mid_sel = $sq_attrs->{selection_outer};
107 if (my $extra_order_sel = $sq_attrs->{order_supplement}) {
7fca91be 108 for my $extra_col (sort
109 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
110 keys %$extra_order_sel
111 ) {
cecf64bc 112 $sq_attrs->{selection_inner} .= sprintf (', %s AS %s',
7fca91be 113 $extra_col,
114 $extra_order_sel->{$extra_col},
115 );
7fca91be 116 }
117 }
118
119 # and this is order re-alias magic
cecf64bc 120 for ($sq_attrs->{order_supplement}, $sq_attrs->{outer_renames}) {
7fca91be 121 for my $col (keys %$_) {
122 my $re_col = quotemeta ($col);
123 $rno_ord =~ s/$re_col/$_->{$col}/;
124 }
125 }
126
127 # whatever is left of the order_by (only where is processed at this point)
128 my $group_having = $self->_parse_rs_attrs($rs_attrs);
129
130 my $qalias = $self->_quote ($rs_attrs->{alias});
131 my $idx_name = $self->_quote ('rno__row__index');
132
69d3c270 133 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset + 1], [ $self->__total_bindtype => $offset + $rows ];
134
135 return <<EOS;
7fca91be 136
cecf64bc 137SELECT $sq_attrs->{selection_outer} FROM (
7fca91be 138 SELECT $mid_sel, ROW_NUMBER() OVER( $rno_ord ) AS $idx_name FROM (
cecf64bc 139 SELECT $sq_attrs->{selection_inner} $sq_attrs->{query_leftover}${group_having}
7fca91be 140 ) $qalias
fcb7fcbb 141) $qalias WHERE $idx_name >= ? AND $idx_name <= ?
7fca91be 142
143EOS
144
7fca91be 145}
146
147# some databases are happy with OVER (), some need OVER (ORDER BY (SELECT (1)) )
148sub _rno_default_order {
149 return undef;
150}
151
d5dedbd6 152=head2 SkipFirst
153
154 SELECT SKIP $offset FIRST $limit * FROM ...
155
156Suported by B<Informix>, almost like LimitOffset. According to
157L<SQL::Abstract::Limit> C<... SKIP $offset LIMIT $limit ...> is also supported.
158
159=cut
7fca91be 160sub _SkipFirst {
161 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
162
163 $sql =~ s/^ \s* SELECT \s+ //ix
70c28808 164 or $self->throw_exception("Unrecognizable SELECT: $sql");
7fca91be 165
166 return sprintf ('SELECT %s%s%s%s',
167 $offset
fcb7fcbb 168 ? do {
8b31f62e 169 push @{$self->{pre_select_bind}}, [ $self->__offset_bindtype => $offset];
fcb7fcbb 170 'SKIP ? '
171 }
7fca91be 172 : ''
173 ,
fcb7fcbb 174 do {
8b31f62e 175 push @{$self->{pre_select_bind}}, [ $self->__rows_bindtype => $rows ];
fcb7fcbb 176 'FIRST ? '
177 },
7fca91be 178 $sql,
179 $self->_parse_rs_attrs ($rs_attrs),
180 );
181}
182
d5dedbd6 183=head2 FirstSkip
184
185 SELECT FIRST $limit SKIP $offset * FROM ...
186
187Supported by B<Firebird/Interbase>, reverse of SkipFirst. According to
188L<SQL::Abstract::Limit> C<... ROWS $limit TO $offset ...> is also supported.
189
190=cut
7fca91be 191sub _FirstSkip {
192 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
193
194 $sql =~ s/^ \s* SELECT \s+ //ix
70c28808 195 or $self->throw_exception("Unrecognizable SELECT: $sql");
7fca91be 196
197 return sprintf ('SELECT %s%s%s%s',
fcb7fcbb 198 do {
8b31f62e 199 push @{$self->{pre_select_bind}}, [ $self->__rows_bindtype => $rows ];
fcb7fcbb 200 'FIRST ? '
201 },
7fca91be 202 $offset
fcb7fcbb 203 ? do {
8b31f62e 204 push @{$self->{pre_select_bind}}, [ $self->__offset_bindtype => $offset];
fcb7fcbb 205 'SKIP ? '
206 }
7fca91be 207 : ''
208 ,
209 $sql,
210 $self->_parse_rs_attrs ($rs_attrs),
211 );
212}
213
6a6394f1 214
d5dedbd6 215=head2 RowNum
216
6a6394f1 217Depending on the resultset attributes one of:
218
d5dedbd6 219 SELECT * FROM (
220 SELECT *, ROWNUM rownum__index FROM (
221 SELECT ...
d9672fb9 222 ) WHERE ROWNUM <= ($limit+$offset)
223 ) WHERE rownum__index >= ($offset+1)
d5dedbd6 224
6a6394f1 225or
226
227 SELECT * FROM (
228 SELECT *, ROWNUM rownum__index FROM (
229 SELECT ...
230 )
231 ) WHERE rownum__index BETWEEN ($offset+1) AND ($limit+$offset)
232
233or
234
235 SELECT * FROM (
236 SELECT ...
237 ) WHERE ROWNUM <= ($limit+1)
238
d5dedbd6 239Supported by B<Oracle>.
240
241=cut
7fca91be 242sub _RowNum {
243 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
244
cecf64bc 245 my $sq_attrs = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
7fca91be 246
247 my $qalias = $self->_quote ($rs_attrs->{alias});
248 my $idx_name = $self->_quote ('rownum__index');
249 my $order_group_having = $self->_parse_rs_attrs($rs_attrs);
250
cccd1876 251
252 # if no offset (e.g. first page) - we can skip one of the subqueries
253 if (! $offset) {
254 push @{$self->{limit_bind}}, [ $self->__rows_bindtype => $rows ];
255
256 return <<EOS;
cecf64bc 257SELECT $sq_attrs->{selection_outer} FROM (
258 SELECT $sq_attrs->{selection_inner} $sq_attrs->{query_leftover}${order_group_having}
cccd1876 259) $qalias WHERE ROWNUM <= ?
260EOS
261 }
262
6a6394f1 263 #
264 # There are two ways to limit in Oracle, one vastly faster than the other
265 # on large resultsets: https://decipherinfosys.wordpress.com/2007/08/09/paging-and-countstopkey-optimization/
266 # However Oracle is retarded and does not preserve stable ROWNUM() values
267 # when called twice in the same scope. Therefore unless the resultset is
268 # ordered by a unique set of columns, it is not safe to use the faster
269 # method, and the slower BETWEEN query is used instead
270 #
7cec4356 271 # FIXME - this is quite expensive, and does not perform caching of any sort
6a6394f1 272 # as soon as some of the DQ work becomes viable consider switching this
273 # over
7cec4356 274 if (
275 $rs_attrs->{order_by}
276 and
277 $rs_attrs->{_rsroot_rsrc}->storage->_order_by_is_stable(
278 $rs_attrs->{from}, $rs_attrs->{order_by}
279 )
280 ) {
cccd1876 281 push @{$self->{limit_bind}}, [ $self->__total_bindtype => $offset + $rows ], [ $self->__offset_bindtype => $offset + 1 ];
6a6394f1 282
cccd1876 283 return <<EOS;
cecf64bc 284SELECT $sq_attrs->{selection_outer} FROM (
285 SELECT $sq_attrs->{selection_outer}, ROWNUM $idx_name FROM (
286 SELECT $sq_attrs->{selection_inner} $sq_attrs->{query_leftover}${order_group_having}
fcb7fcbb 287 ) $qalias WHERE ROWNUM <= ?
288) $qalias WHERE $idx_name >= ?
7fca91be 289EOS
d9672fb9 290 }
291 else {
6a6394f1 292 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset + 1 ], [ $self->__total_bindtype => $offset + $rows ];
69d3c270 293
294 return <<EOS;
cecf64bc 295SELECT $sq_attrs->{selection_outer} FROM (
296 SELECT $sq_attrs->{selection_outer}, ROWNUM $idx_name FROM (
297 SELECT $sq_attrs->{selection_inner} $sq_attrs->{query_leftover}${order_group_having}
6a6394f1 298 ) $qalias
299) $qalias WHERE $idx_name BETWEEN ? AND ?
d9672fb9 300EOS
6a6394f1 301 }
302}
7fca91be 303
6a6394f1 304# used by _Top and _FetchFirst below
96eacdb7 305sub _prep_for_skimming_limit {
306 my ( $self, $sql, $rs_attrs ) = @_;
7fca91be 307
7fca91be 308 # get selectors
cecf64bc 309 my $sq_attrs = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
7fca91be 310
311 my $requested_order = delete $rs_attrs->{order_by};
cecf64bc 312 $sq_attrs->{order_by_requested} = $self->_order_by ($requested_order);
313 $sq_attrs->{grpby_having} = $self->_parse_rs_attrs ($rs_attrs);
7fca91be 314
a66b662c 315 # without an offset things are easy
316 if (! $rs_attrs->{offset}) {
317 $sq_attrs->{order_by_inner} = $sq_attrs->{order_by_requested};
86bb5a27 318 }
319 else {
a66b662c 320 $sq_attrs->{quoted_rs_alias} = $self->_quote ($rs_attrs->{alias});
321
322 # localise as we already have all the bind values we need
323 local $self->{order_bind};
324
325 # make up an order unless supplied or sanity check what we are given
326 my $inner_order;
327 if ($sq_attrs->{order_by_requested}) {
328 $self->throw_exception (
329 'Unable to safely perform "skimming type" limit with supplied unstable order criteria'
330 ) unless $rs_attrs->{_rsroot_rsrc}->schema->storage->_order_by_is_stable(
331 $rs_attrs->{from},
332 $requested_order
333 );
7fca91be 334
a66b662c 335 $inner_order = $requested_order;
336 }
337 else {
338 $inner_order = [ map
339 { "$rs_attrs->{alias}.$_" }
340 ( @{
341 $rs_attrs->{_rsroot_rsrc}->_identifying_column_set
342 ||
343 $self->throw_exception(sprintf(
344 'Unable to auto-construct stable order criteria for "skimming type" limit '
345 . "dialect based on source '%s'", $rs_attrs->{_rsroot_rsrc}->name) );
346 } )
347 ];
348 }
7fca91be 349
a66b662c 350 $sq_attrs->{order_by_inner} = $self->_order_by ($inner_order);
cecf64bc 351
a66b662c 352 my @out_chunks;
353 for my $ch ($self->_order_by_chunks ($inner_order)) {
354 $ch = $ch->[0] if ref $ch eq 'ARRAY';
7fca91be 355
a66b662c 356 $ch =~ s/\s+ ( ASC|DESC ) \s* $//ix;
357 my $dir = uc ($1||'ASC');
358 push @out_chunks, \join (' ', $ch, $dir eq 'ASC' ? 'DESC' : 'ASC' );
7fca91be 359 }
360
a66b662c 361 $sq_attrs->{order_by_middle} = $self->_order_by (\@out_chunks);
362
363 # this is the order supplement magic
364 $sq_attrs->{selection_middle} = $sq_attrs->{selection_outer};
365 if (my $extra_order_sel = $sq_attrs->{order_supplement}) {
366 for my $extra_col (sort
367 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
368 keys %$extra_order_sel
369 ) {
370 $sq_attrs->{selection_inner} .= sprintf (', %s AS %s',
371 $extra_col,
372 $extra_order_sel->{$extra_col},
373 );
374
375 $sq_attrs->{selection_middle} .= ', ' . $extra_order_sel->{$extra_col};
376 }
377
378 # Whatever order bindvals there are, they will be realiased and
379 # reselected, and need to show up at end of the initial inner select
380 push @{$self->{select_bind}}, @{$self->{order_bind}};
381
382 # if this is a part of something bigger, we need to add back all
383 # the extra order_by's, as they may be relied upon by the outside
384 # of a prefetch or something
385 if ($rs_attrs->{_is_internal_subuery}) {
386 $sq_attrs->{selection_outer} .= sprintf ", $extra_order_sel->{$_} AS $_"
387 for sort
388 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
389 grep { $_ !~ /[^\w\-]/ } # ignore functions
390 keys %$extra_order_sel
391 ;
392 }
cecf64bc 393 }
86bb5a27 394
a66b662c 395 # and this is order re-alias magic
396 for my $map ($sq_attrs->{order_supplement}, $sq_attrs->{outer_renames}) {
397 for my $col (sort { $map->{$a} cmp $map->{$b} } keys %{$map||{}}) {
398 my $re_col = quotemeta ($col);
399 $_ =~ s/$re_col/$map->{$col}/
400 for ($sq_attrs->{order_by_middle}, $sq_attrs->{order_by_requested});
401 }
7fca91be 402 }
403 }
404
cecf64bc 405 $sq_attrs;
96eacdb7 406}
407
408=head2 Top
409
410 SELECT * FROM
411
412 SELECT TOP $limit FROM (
413 SELECT TOP $limit FROM (
414 SELECT TOP ($limit+$offset) ...
415 ) ORDER BY $reversed_original_order
416 ) ORDER BY $original_order
417
418Unreliable Top-based implementation, supported by B<< MSSQL < 2005 >>.
419
420=head3 CAVEAT
421
422Due to its implementation, this limit dialect returns B<incorrect results>
423when $limit+$offset > total amount of rows in the resultset.
424
425=cut
426
427sub _Top {
428 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
429
cecf64bc 430 my $lim = $self->_prep_for_skimming_limit($sql, $rs_attrs);
7fca91be 431
432 $sql = sprintf ('SELECT TOP %u %s %s %s %s',
433 $rows + ($offset||0),
a66b662c 434 $offset ? $lim->{selection_inner} : $lim->{selection_original},
cecf64bc 435 $lim->{query_leftover},
436 $lim->{grpby_having},
437 $lim->{order_by_inner},
7fca91be 438 );
439
440 $sql = sprintf ('SELECT TOP %u %s FROM ( %s ) %s %s',
441 $rows,
cecf64bc 442 $lim->{selection_middle},
7fca91be 443 $sql,
cecf64bc 444 $lim->{quoted_rs_alias},
445 $lim->{order_by_middle},
7fca91be 446 ) if $offset;
447
1b07861d 448 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s',
cecf64bc 449 $lim->{selection_outer},
96eacdb7 450 $sql,
cecf64bc 451 $lim->{quoted_rs_alias},
452 $lim->{order_by_requested},
453 ) if $offset and (
454 $lim->{order_by_requested} or $lim->{selection_middle} ne $lim->{selection_outer}
455 );
96eacdb7 456
457 return $sql;
458}
459
460=head2 FetchFirst
461
462 SELECT * FROM
463 (
464 SELECT * FROM (
465 SELECT * FROM (
466 SELECT * FROM ...
467 ) ORDER BY $reversed_original_order
468 FETCH FIRST $limit ROWS ONLY
469 ) ORDER BY $original_order
470 FETCH FIRST $limit ROWS ONLY
471 )
472
473Unreliable FetchFirst-based implementation, supported by B<< IBM DB2 <= V5R3 >>.
474
475=head3 CAVEAT
476
477Due to its implementation, this limit dialect returns B<incorrect results>
478when $limit+$offset > total amount of rows in the resultset.
479
480=cut
481
482sub _FetchFirst {
483 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
484
cecf64bc 485 my $lim = $self->_prep_for_skimming_limit($sql, $rs_attrs);
96eacdb7 486
487 $sql = sprintf ('SELECT %s %s %s %s FETCH FIRST %u ROWS ONLY',
a66b662c 488 $offset ? $lim->{selection_inner} : $lim->{selection_original},
cecf64bc 489 $lim->{query_leftover},
490 $lim->{grpby_having},
491 $lim->{order_by_inner},
96eacdb7 492 $rows + ($offset||0),
493 );
494
495 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s FETCH FIRST %u ROWS ONLY',
cecf64bc 496 $lim->{selection_middle},
96eacdb7 497 $sql,
cecf64bc 498 $lim->{quoted_rs_alias},
499 $lim->{order_by_middle},
96eacdb7 500 $rows,
501 ) if $offset;
502
cecf64bc 503
1b07861d 504 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s',
cecf64bc 505 $lim->{selection_outer},
7fca91be 506 $sql,
cecf64bc 507 $lim->{quoted_rs_alias},
508 $lim->{order_by_requested},
cecf64bc 509 ) if $offset and (
510 $lim->{order_by_requested} or $lim->{selection_middle} ne $lim->{selection_outer}
511 );
7fca91be 512
7fca91be 513 return $sql;
514}
515
d5dedbd6 516=head2 RowCountOrGenericSubQ
517
518This is not exactly a limit dialect, but more of a proxy for B<Sybase ASE>.
519If no $offset is supplied the limit is simply performed as:
520
521 SET ROWCOUNT $limit
522 SELECT ...
523 SET ROWCOUNT 0
524
525Otherwise we fall back to L</GenericSubQ>
526
527=cut
96eacdb7 528
7fca91be 529sub _RowCountOrGenericSubQ {
530 my $self = shift;
531 my ($sql, $rs_attrs, $rows, $offset) = @_;
532
533 return $self->_GenericSubQ(@_) if $offset;
534
535 return sprintf <<"EOF", $rows, $sql;
536SET ROWCOUNT %d
537%s
538SET ROWCOUNT 0
539EOF
540}
541
d5dedbd6 542=head2 GenericSubQ
543
544 SELECT * FROM (
545 SELECT ...
546 )
547 WHERE (
548 SELECT COUNT(*) FROM $original_table cnt WHERE cnt.id < $original_table.id
549 ) BETWEEN $offset AND ($offset+$rows-1)
550
551This is the most evil limit "dialect" (more of a hack) for I<really> stupid
552databases. It works by ordering the set by some unique column, and calculating
553the amount of rows that have a less-er value (thus emulating a L</RowNum>-like
554index). Of course this implies the set can only be ordered by a single unique
555column. Also note that this technique can be and often is B<excruciatingly
556slow>.
557
558Currently used by B<Sybase ASE>, due to lack of any other option.
559
560=cut
7fca91be 561sub _GenericSubQ {
562 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
563
4376a157 564 my $root_rsrc = $rs_attrs->{_rsroot_rsrc};
7fca91be 565 my $root_tbl_name = $root_rsrc->name;
566
528e717e 567 my ($first_order_by) = do {
7fca91be 568 local $self->{quote_char};
528e717e 569 map { ref $_ ? $_->[0] : $_ } $self->_order_by_chunks ($rs_attrs->{order_by})
570 } or $self->throw_exception (
571 'Generic Subquery Limit does not work on resultsets without an order. Provide a single, '
572 . 'unique-column order criteria.'
573 );
7fca91be 574
528e717e 575 $first_order_by =~ s/\s+ ( ASC|DESC ) \s* $//ix;
7fca91be 576 my $direction = lc ($1 || 'asc');
577
528e717e 578 my ($first_ord_alias, $first_ord_col) = $first_order_by =~ /^ (?: ([^\.]+) \. )? ([^\.]+) $/x;
7fca91be 579
528e717e 580 $self->throw_exception(sprintf
581 "Generic Subquery Limit order criteria can be only based on the root-source '%s'"
582 . " (aliased as '%s')", $root_rsrc->source_name, $rs_attrs->{alias},
583 ) if ($first_ord_alias and $first_ord_alias ne $rs_attrs->{alias});
7fca91be 584
528e717e 585 $first_ord_alias ||= $rs_attrs->{alias};
7fca91be 586
70c28808 587 $self->throw_exception(
528e717e 588 "Generic Subquery Limit first order criteria '$first_ord_col' must be unique"
589 ) unless $root_rsrc->_identifying_column_set([$first_ord_col]);
7fca91be 590
cecf64bc 591 my $sq_attrs = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
7fca91be 592
593 my $cmp_op = $direction eq 'desc' ? '>' : '<';
594 my $count_tbl_alias = 'rownum__emulation';
595
596 my $order_sql = $self->_order_by (delete $rs_attrs->{order_by});
597 my $group_having_sql = $self->_parse_rs_attrs($rs_attrs);
598
cecf64bc 599 my $in_sel = $sq_attrs->{selection_inner};
600
7fca91be 601 # add the order supplement (if any) as this is what will be used for the outer WHERE
cecf64bc 602 $in_sel .= ", $_" for keys %{$sq_attrs->{order_supplement}};
7fca91be 603
69d3c270 604 my $rownum_cond;
605 if ($offset) {
606 $rownum_cond = 'BETWEEN ? AND ?';
607
608 push @{$self->{limit_bind}},
609 [ $self->__offset_bindtype => $offset ],
610 [ $self->__total_bindtype => $offset + $rows - 1]
611 ;
612 }
613 else {
614 $rownum_cond = '< ?';
615
616 push @{$self->{limit_bind}},
617 [ $self->__rows_bindtype => $rows ]
618 ;
619 }
620
621 return sprintf ("
cecf64bc 622SELECT $sq_attrs->{selection_outer}
7fca91be 623 FROM (
cecf64bc 624 SELECT $in_sel $sq_attrs->{query_leftover}${group_having_sql}
7fca91be 625 ) %s
69d3c270 626WHERE ( SELECT COUNT(*) FROM %s %s WHERE %s $cmp_op %s ) $rownum_cond
7fca91be 627$order_sql
69d3c270 628 ", map { $self->_quote ($_) } (
629 $rs_attrs->{alias},
630 $root_tbl_name,
631 $count_tbl_alias,
528e717e 632 "$count_tbl_alias.$first_ord_col",
633 "$first_ord_alias.$first_ord_col",
69d3c270 634 ));
7fca91be 635}
636
637
638# !!! THIS IS ALSO HORRIFIC !!! /me ashamed
639#
640# Generates inner/outer select lists for various limit dialects
641# which result in one or more subqueries (e.g. RNO, Top, RowNum)
642# Any non-root-table columns need to have their table qualifier
643# turned into a column alias (otherwise names in subqueries clash
644# and/or lose their source table)
645#
69d3c270 646# Returns mangled proto-sql, inner/outer strings of SQL QUOTED selectors
647# with aliases (to be used in whatever select statement), and an alias
8273e845 648# index hashref of QUOTED SEL => QUOTED ALIAS pairs (to maybe be used
69d3c270 649# for string-subst higher up).
7fca91be 650# If an order_by is supplied, the inner select needs to bring out columns
651# used in implicit (non-selected) orders, and the order condition itself
652# needs to be realiased to the proper names in the outer query. Thus we
653# also return a hashref (order doesn't matter) of QUOTED EXTRA-SEL =>
654# QUOTED ALIAS pairs, which is a list of extra selectors that do *not*
655# exist in the original select list
7fca91be 656sub _subqueried_limit_attrs {
69d3c270 657 my ($self, $proto_sql, $rs_attrs) = @_;
7fca91be 658
70c28808 659 $self->throw_exception(
660 'Limit dialect implementation usable only in the context of DBIC (missing $rs_attrs)'
661 ) unless ref ($rs_attrs) eq 'HASH';
7fca91be 662
f74d22e2 663 # mangle the input sql as we will be replacing the selector entirely
664 unless (
665 $rs_attrs->{_selector_sql}
666 and
667 $proto_sql =~ s/^ \s* SELECT \s* \Q$rs_attrs->{_selector_sql}//ix
668 ) {
669 $self->throw_exception("Unrecognizable SELECT: $proto_sql");
670 }
69d3c270 671
3f5b99fe 672 my ($re_sep, $re_alias) = map { quotemeta $_ } ( $self->{name_sep}, $rs_attrs->{alias} );
7fca91be 673
69d3c270 674 # insulate from the multiple _recurse_fields calls below
675 local $self->{select_bind};
676
7fca91be 677 # correlate select and as, build selection index
678 my (@sel, $in_sel_index);
679 for my $i (0 .. $#{$rs_attrs->{select}}) {
680
681 my $s = $rs_attrs->{select}[$i];
682 my $sql_sel = $self->_recurse_fields ($s);
683 my $sql_alias = (ref $s) eq 'HASH' ? $s->{-as} : undef;
684
7fca91be 685 push @sel, {
686 sql => $sql_sel,
69d3c270 687 unquoted_sql => do {
688 local $self->{quote_char};
689 $self->_recurse_fields ($s);
690 },
7fca91be 691 as =>
692 $sql_alias
693 ||
694 $rs_attrs->{as}[$i]
695 ||
70c28808 696 $self->throw_exception("Select argument $i ($s) without corresponding 'as'")
7fca91be 697 ,
698 };
699
700 $in_sel_index->{$sql_sel}++;
701 $in_sel_index->{$self->_quote ($sql_alias)}++ if $sql_alias;
702
703 # record unqualified versions too, so we do not have
704 # to reselect the same column twice (in qualified and
705 # unqualified form)
706 if (! ref $s && $sql_sel =~ / $re_sep (.+) $/x) {
707 $in_sel_index->{$1}++;
708 }
709 }
710
711
712 # re-alias and remove any name separators from aliases,
713 # unless we are dealing with the current source alias
714 # (which will transcend the subqueries as it is necessary
715 # for possible further chaining)
cecf64bc 716 my ($sel, $renamed);
7fca91be 717 for my $node (@sel) {
a66b662c 718 push @{$sel->{original}}, $node->{sql};
719
3f5b99fe 720 if (
721 $node->{as} =~ / (?<! ^ $re_alias ) \. /x
722 or
723 $node->{unquoted_sql} =~ / (?<! ^ $re_alias ) $re_sep /x
724 ) {
7fca91be 725 $node->{as} = $self->_unqualify_colname($node->{as});
726 my $quoted_as = $self->_quote($node->{as});
cecf64bc 727 push @{$sel->{inner}}, sprintf '%s AS %s', $node->{sql}, $quoted_as;
728 push @{$sel->{outer}}, $quoted_as;
729 $renamed->{$node->{sql}} = $quoted_as;
7fca91be 730 }
731 else {
cecf64bc 732 push @{$sel->{inner}}, $node->{sql};
733 push @{$sel->{outer}}, $self->_quote ($node->{as});
7fca91be 734 }
735 }
cecf64bc 736
7fca91be 737 # see if the order gives us anything
cecf64bc 738 my $extra_order_sel;
7fca91be 739 for my $chunk ($self->_order_by_chunks ($rs_attrs->{order_by})) {
740 # order with bind
741 $chunk = $chunk->[0] if (ref $chunk) eq 'ARRAY';
742 $chunk =~ s/\s+ (?: ASC|DESC ) \s* $//ix;
743
744 next if $in_sel_index->{$chunk};
745
cecf64bc 746 $extra_order_sel->{$chunk} ||= $self->_quote (
747 'ORDER__BY__' . scalar keys %{$extra_order_sel||{}}
7fca91be 748 );
749 }
750
cecf64bc 751 return {
752 query_leftover => $proto_sql,
753 (map {( "selection_$_" => join (', ', @{$sel->{$_}} ) )} keys %$sel ),
754 outer_renames => $renamed,
755 order_supplement => $extra_order_sel,
756 };
7fca91be 757}
758
759sub _unqualify_colname {
760 my ($self, $fqcn) = @_;
3f5b99fe 761 $fqcn =~ s/ \. /__/xg;
7fca91be 762 return $fqcn;
763}
764
7651;
d5dedbd6 766
767=head1 AUTHORS
768
769See L<DBIx::Class/CONTRIBUTORS>.
770
771=head1 LICENSE
772
773You may distribute this code under the same terms as Perl itself.
774
775=cut