Start running more limit dialect torture tests if possible
[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
d77ee505 361 my $is_desc = (
362 $ch =~ s/\s+ ( ASC|DESC ) \s* $//ix
363 and
364 uc($1) eq 'DESC'
365 ) ? 1 : 0;
366 push @out_chunks, \join (' ', $ch, $is_desc ? 'ASC' : 'DESC' );
7fca91be 367 }
368
a66b662c 369 $sq_attrs->{order_by_middle} = $self->_order_by (\@out_chunks);
370
371 # this is the order supplement magic
372 $sq_attrs->{selection_middle} = $sq_attrs->{selection_outer};
373 if (my $extra_order_sel = $sq_attrs->{order_supplement}) {
374 for my $extra_col (sort
375 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
376 keys %$extra_order_sel
377 ) {
378 $sq_attrs->{selection_inner} .= sprintf (', %s AS %s',
379 $extra_col,
380 $extra_order_sel->{$extra_col},
381 );
382
383 $sq_attrs->{selection_middle} .= ', ' . $extra_order_sel->{$extra_col};
384 }
385
386 # Whatever order bindvals there are, they will be realiased and
387 # reselected, and need to show up at end of the initial inner select
388 push @{$self->{select_bind}}, @{$self->{order_bind}};
cecf64bc 389 }
86bb5a27 390
a66b662c 391 # and this is order re-alias magic
392 for my $map ($sq_attrs->{order_supplement}, $sq_attrs->{outer_renames}) {
833733fe 393 for my $col (sort { (length $b) <=> (length $a) } keys %{$map||{}}) {
a66b662c 394 my $re_col = quotemeta ($col);
395 $_ =~ s/$re_col/$map->{$col}/
396 for ($sq_attrs->{order_by_middle}, $sq_attrs->{order_by_requested});
397 }
7fca91be 398 }
399 }
400
cecf64bc 401 $sq_attrs;
96eacdb7 402}
403
404=head2 Top
405
406 SELECT * FROM
407
408 SELECT TOP $limit FROM (
409 SELECT TOP $limit FROM (
410 SELECT TOP ($limit+$offset) ...
411 ) ORDER BY $reversed_original_order
412 ) ORDER BY $original_order
413
414Unreliable Top-based implementation, supported by B<< MSSQL < 2005 >>.
415
416=head3 CAVEAT
417
418Due to its implementation, this limit dialect returns B<incorrect results>
419when $limit+$offset > total amount of rows in the resultset.
420
421=cut
422
423sub _Top {
424 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
425
cecf64bc 426 my $lim = $self->_prep_for_skimming_limit($sql, $rs_attrs);
7fca91be 427
428 $sql = sprintf ('SELECT TOP %u %s %s %s %s',
429 $rows + ($offset||0),
a66b662c 430 $offset ? $lim->{selection_inner} : $lim->{selection_original},
cecf64bc 431 $lim->{query_leftover},
432 $lim->{grpby_having},
433 $lim->{order_by_inner},
7fca91be 434 );
435
436 $sql = sprintf ('SELECT TOP %u %s FROM ( %s ) %s %s',
437 $rows,
cecf64bc 438 $lim->{selection_middle},
7fca91be 439 $sql,
cecf64bc 440 $lim->{quoted_rs_alias},
441 $lim->{order_by_middle},
7fca91be 442 ) if $offset;
443
1b07861d 444 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s',
cecf64bc 445 $lim->{selection_outer},
96eacdb7 446 $sql,
cecf64bc 447 $lim->{quoted_rs_alias},
448 $lim->{order_by_requested},
449 ) if $offset and (
450 $lim->{order_by_requested} or $lim->{selection_middle} ne $lim->{selection_outer}
451 );
96eacdb7 452
453 return $sql;
454}
455
456=head2 FetchFirst
457
458 SELECT * FROM
459 (
460 SELECT * FROM (
461 SELECT * FROM (
462 SELECT * FROM ...
463 ) ORDER BY $reversed_original_order
464 FETCH FIRST $limit ROWS ONLY
465 ) ORDER BY $original_order
466 FETCH FIRST $limit ROWS ONLY
467 )
468
469Unreliable FetchFirst-based implementation, supported by B<< IBM DB2 <= V5R3 >>.
470
471=head3 CAVEAT
472
473Due to its implementation, this limit dialect returns B<incorrect results>
474when $limit+$offset > total amount of rows in the resultset.
475
476=cut
477
478sub _FetchFirst {
479 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
480
cecf64bc 481 my $lim = $self->_prep_for_skimming_limit($sql, $rs_attrs);
96eacdb7 482
483 $sql = sprintf ('SELECT %s %s %s %s FETCH FIRST %u ROWS ONLY',
a66b662c 484 $offset ? $lim->{selection_inner} : $lim->{selection_original},
cecf64bc 485 $lim->{query_leftover},
486 $lim->{grpby_having},
487 $lim->{order_by_inner},
96eacdb7 488 $rows + ($offset||0),
489 );
490
491 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s FETCH FIRST %u ROWS ONLY',
cecf64bc 492 $lim->{selection_middle},
96eacdb7 493 $sql,
cecf64bc 494 $lim->{quoted_rs_alias},
495 $lim->{order_by_middle},
96eacdb7 496 $rows,
497 ) if $offset;
498
cecf64bc 499
1b07861d 500 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s',
cecf64bc 501 $lim->{selection_outer},
7fca91be 502 $sql,
cecf64bc 503 $lim->{quoted_rs_alias},
504 $lim->{order_by_requested},
cecf64bc 505 ) if $offset and (
506 $lim->{order_by_requested} or $lim->{selection_middle} ne $lim->{selection_outer}
507 );
7fca91be 508
7fca91be 509 return $sql;
510}
511
d5dedbd6 512=head2 GenericSubQ
513
514 SELECT * FROM (
515 SELECT ...
516 )
517 WHERE (
518 SELECT COUNT(*) FROM $original_table cnt WHERE cnt.id < $original_table.id
519 ) BETWEEN $offset AND ($offset+$rows-1)
520
521This is the most evil limit "dialect" (more of a hack) for I<really> stupid
522databases. It works by ordering the set by some unique column, and calculating
523the amount of rows that have a less-er value (thus emulating a L</RowNum>-like
524index). Of course this implies the set can only be ordered by a single unique
038b8126 525column.
526
527Also note that this technique can be and often is B<excruciatingly slow>. You
528may have much better luck using L<DBIx::Class::ResultSet/software_limit>
529instead.
d5dedbd6 530
531Currently used by B<Sybase ASE>, due to lack of any other option.
532
533=cut
7fca91be 534sub _GenericSubQ {
535 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
536
4376a157 537 my $root_rsrc = $rs_attrs->{_rsroot_rsrc};
7fca91be 538 my $root_tbl_name = $root_rsrc->name;
539
528e717e 540 my ($first_order_by) = do {
7fca91be 541 local $self->{quote_char};
2d841fdc 542 local $self->{order_bind};
528e717e 543 map { ref $_ ? $_->[0] : $_ } $self->_order_by_chunks ($rs_attrs->{order_by})
544 } or $self->throw_exception (
545 'Generic Subquery Limit does not work on resultsets without an order. Provide a single, '
546 . 'unique-column order criteria.'
547 );
7fca91be 548
d77ee505 549 my $direction = (
550 $first_order_by =~ s/\s+ ( ASC|DESC ) \s* $//ix
551 ) ? lc($1) : 'asc';
7fca91be 552
528e717e 553 my ($first_ord_alias, $first_ord_col) = $first_order_by =~ /^ (?: ([^\.]+) \. )? ([^\.]+) $/x;
7fca91be 554
528e717e 555 $self->throw_exception(sprintf
556 "Generic Subquery Limit order criteria can be only based on the root-source '%s'"
557 . " (aliased as '%s')", $root_rsrc->source_name, $rs_attrs->{alias},
558 ) if ($first_ord_alias and $first_ord_alias ne $rs_attrs->{alias});
7fca91be 559
528e717e 560 $first_ord_alias ||= $rs_attrs->{alias};
7fca91be 561
70c28808 562 $self->throw_exception(
528e717e 563 "Generic Subquery Limit first order criteria '$first_ord_col' must be unique"
564 ) unless $root_rsrc->_identifying_column_set([$first_ord_col]);
7fca91be 565
2d841fdc 566 my $sq_attrs = do {
567 # perform the mangling only using the very first order crietria
568 # (the one we care about)
569 local $rs_attrs->{order_by} = $first_order_by;
570 $self->_subqueried_limit_attrs ($sql, $rs_attrs);
571 };
7fca91be 572
573 my $cmp_op = $direction eq 'desc' ? '>' : '<';
574 my $count_tbl_alias = 'rownum__emulation';
575
2d841fdc 576 my ($order_sql, @order_bind) = do {
577 local $self->{order_bind};
578 my $s = $self->_order_by (delete $rs_attrs->{order_by});
579 ($s, @{$self->{order_bind}});
580 };
7fca91be 581 my $group_having_sql = $self->_parse_rs_attrs($rs_attrs);
582
cecf64bc 583 my $in_sel = $sq_attrs->{selection_inner};
584
7fca91be 585 # add the order supplement (if any) as this is what will be used for the outer WHERE
cecf64bc 586 $in_sel .= ", $_" for keys %{$sq_attrs->{order_supplement}};
7fca91be 587
69d3c270 588 my $rownum_cond;
589 if ($offset) {
590 $rownum_cond = 'BETWEEN ? AND ?';
591
592 push @{$self->{limit_bind}},
593 [ $self->__offset_bindtype => $offset ],
594 [ $self->__total_bindtype => $offset + $rows - 1]
595 ;
596 }
597 else {
598 $rownum_cond = '< ?';
599
600 push @{$self->{limit_bind}},
601 [ $self->__rows_bindtype => $rows ]
602 ;
603 }
604
2d841fdc 605 # even though binds in order_by make no sense here (the rs needs to be
606 # ordered by a unique column first) - pass whatever there may be through
607 # anyway
608 push @{$self->{limit_bind}}, @order_bind;
609
69d3c270 610 return sprintf ("
cecf64bc 611SELECT $sq_attrs->{selection_outer}
7fca91be 612 FROM (
cecf64bc 613 SELECT $in_sel $sq_attrs->{query_leftover}${group_having_sql}
7fca91be 614 ) %s
69d3c270 615WHERE ( SELECT COUNT(*) FROM %s %s WHERE %s $cmp_op %s ) $rownum_cond
7fca91be 616$order_sql
69d3c270 617 ", map { $self->_quote ($_) } (
618 $rs_attrs->{alias},
619 $root_tbl_name,
620 $count_tbl_alias,
528e717e 621 "$count_tbl_alias.$first_ord_col",
622 "$first_ord_alias.$first_ord_col",
69d3c270 623 ));
7fca91be 624}
625
626
627# !!! THIS IS ALSO HORRIFIC !!! /me ashamed
628#
629# Generates inner/outer select lists for various limit dialects
630# which result in one or more subqueries (e.g. RNO, Top, RowNum)
631# Any non-root-table columns need to have their table qualifier
632# turned into a column alias (otherwise names in subqueries clash
633# and/or lose their source table)
634#
69d3c270 635# Returns mangled proto-sql, inner/outer strings of SQL QUOTED selectors
636# with aliases (to be used in whatever select statement), and an alias
8273e845 637# index hashref of QUOTED SEL => QUOTED ALIAS pairs (to maybe be used
69d3c270 638# for string-subst higher up).
7fca91be 639# If an order_by is supplied, the inner select needs to bring out columns
640# used in implicit (non-selected) orders, and the order condition itself
641# needs to be realiased to the proper names in the outer query. Thus we
642# also return a hashref (order doesn't matter) of QUOTED EXTRA-SEL =>
643# QUOTED ALIAS pairs, which is a list of extra selectors that do *not*
644# exist in the original select list
7fca91be 645sub _subqueried_limit_attrs {
69d3c270 646 my ($self, $proto_sql, $rs_attrs) = @_;
7fca91be 647
70c28808 648 $self->throw_exception(
649 'Limit dialect implementation usable only in the context of DBIC (missing $rs_attrs)'
650 ) unless ref ($rs_attrs) eq 'HASH';
7fca91be 651
f74d22e2 652 # mangle the input sql as we will be replacing the selector entirely
653 unless (
654 $rs_attrs->{_selector_sql}
655 and
656 $proto_sql =~ s/^ \s* SELECT \s* \Q$rs_attrs->{_selector_sql}//ix
657 ) {
658 $self->throw_exception("Unrecognizable SELECT: $proto_sql");
659 }
69d3c270 660
3f5b99fe 661 my ($re_sep, $re_alias) = map { quotemeta $_ } ( $self->{name_sep}, $rs_attrs->{alias} );
7fca91be 662
69d3c270 663 # insulate from the multiple _recurse_fields calls below
664 local $self->{select_bind};
665
7fca91be 666 # correlate select and as, build selection index
667 my (@sel, $in_sel_index);
668 for my $i (0 .. $#{$rs_attrs->{select}}) {
669
670 my $s = $rs_attrs->{select}[$i];
671 my $sql_sel = $self->_recurse_fields ($s);
672 my $sql_alias = (ref $s) eq 'HASH' ? $s->{-as} : undef;
673
7fca91be 674 push @sel, {
90ed89cb 675 arg => $s,
7fca91be 676 sql => $sql_sel,
69d3c270 677 unquoted_sql => do {
678 local $self->{quote_char};
679 $self->_recurse_fields ($s);
680 },
7fca91be 681 as =>
682 $sql_alias
683 ||
684 $rs_attrs->{as}[$i]
685 ||
70c28808 686 $self->throw_exception("Select argument $i ($s) without corresponding 'as'")
7fca91be 687 ,
688 };
689
f1be7448 690 # anything with a placeholder in it needs re-selection
691 $in_sel_index->{$sql_sel}++ unless $sql_sel =~ / (?: ^ | \W ) \? (?: \W | $ ) /x;
692
7fca91be 693 $in_sel_index->{$self->_quote ($sql_alias)}++ if $sql_alias;
694
695 # record unqualified versions too, so we do not have
696 # to reselect the same column twice (in qualified and
697 # unqualified form)
698 if (! ref $s && $sql_sel =~ / $re_sep (.+) $/x) {
699 $in_sel_index->{$1}++;
700 }
701 }
702
703
704 # re-alias and remove any name separators from aliases,
705 # unless we are dealing with the current source alias
706 # (which will transcend the subqueries as it is necessary
707 # for possible further chaining)
4d45ab4b 708 # same for anything we do not recognize
cecf64bc 709 my ($sel, $renamed);
7fca91be 710 for my $node (@sel) {
a66b662c 711 push @{$sel->{original}}, $node->{sql};
712
3f5b99fe 713 if (
4d45ab4b 714 ! $in_sel_index->{$node->{sql}}
715 or
3f5b99fe 716 $node->{as} =~ / (?<! ^ $re_alias ) \. /x
717 or
718 $node->{unquoted_sql} =~ / (?<! ^ $re_alias ) $re_sep /x
719 ) {
7fca91be 720 $node->{as} = $self->_unqualify_colname($node->{as});
721 my $quoted_as = $self->_quote($node->{as});
cecf64bc 722 push @{$sel->{inner}}, sprintf '%s AS %s', $node->{sql}, $quoted_as;
723 push @{$sel->{outer}}, $quoted_as;
724 $renamed->{$node->{sql}} = $quoted_as;
7fca91be 725 }
726 else {
cecf64bc 727 push @{$sel->{inner}}, $node->{sql};
90ed89cb 728 push @{$sel->{outer}}, $self->_quote (ref $node->{arg} ? $node->{as} : $node->{arg});
7fca91be 729 }
730 }
cecf64bc 731
7fca91be 732 # see if the order gives us anything
cecf64bc 733 my $extra_order_sel;
7fca91be 734 for my $chunk ($self->_order_by_chunks ($rs_attrs->{order_by})) {
735 # order with bind
736 $chunk = $chunk->[0] if (ref $chunk) eq 'ARRAY';
737 $chunk =~ s/\s+ (?: ASC|DESC ) \s* $//ix;
738
739 next if $in_sel_index->{$chunk};
740
cecf64bc 741 $extra_order_sel->{$chunk} ||= $self->_quote (
08a1eaad 742 'ORDER__BY__' . sprintf '%03d', scalar keys %{$extra_order_sel||{}}
7fca91be 743 );
744 }
745
cecf64bc 746 return {
747 query_leftover => $proto_sql,
748 (map {( "selection_$_" => join (', ', @{$sel->{$_}} ) )} keys %$sel ),
749 outer_renames => $renamed,
750 order_supplement => $extra_order_sel,
751 };
7fca91be 752}
753
754sub _unqualify_colname {
755 my ($self, $fqcn) = @_;
3f5b99fe 756 $fqcn =~ s/ \. /__/xg;
7fca91be 757 return $fqcn;
758}
759
7601;
d5dedbd6 761
762=head1 AUTHORS
763
764See L<DBIx::Class/CONTRIBUTORS>.
765
766=head1 LICENSE
767
768You may distribute this code under the same terms as Perl itself.
769
770=cut