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