1 package DBIx::Class::SQLMaker::LimitDialects;
6 use List::Util 'first';
9 # constants are used not only here, but also in comparison tests
10 sub __rows_bindtype () {
11 +{ sqlt_datatype => 'integer' }
13 sub __offset_bindtype () {
14 +{ sqlt_datatype => 'integer' }
16 sub __total_bindtype () {
17 +{ sqlt_datatype => 'integer' }
22 DBIx::Class::SQLMaker::LimitDialects - SQL::Abstract::Limit-like functionality for DBIx::Class::SQLMaker
26 This module replicates a lot of the functionality originally found in
27 L<SQL::Abstract::Limit>. While simple limits would work as-is, the more
28 complex dialects that require e.g. subqueries could not be reliably
29 implemented without taking full advantage of the metadata locked within
30 L<DBIx::Class::ResultSource> classes. After reimplementation of close to
31 80% of the L<SQL::Abstract::Limit> functionality it was deemed more
32 practical to simply make an independent DBIx::Class-specific limit-dialect
35 =head1 SQL LIMIT DIALECTS
37 Note that the actual implementations listed below never use C<*> literally.
38 Instead proper re-aliasing of selectors and order criteria is done, so that
39 the limit dialect are safe to use on joined resultsets with clashing column
42 Currently the provided dialects are:
46 SELECT ... LIMIT $limit OFFSET $offset
48 Supported by B<PostgreSQL> and B<SQLite>
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 ];
57 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset ];
64 SELECT ... LIMIT $offset $limit
66 Supported by B<MySQL> and any L<SQL::Statement> based DBD
70 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
71 $sql .= $self->_parse_rs_attrs( $rs_attrs ) . " LIMIT ";
74 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset ];
77 push @{$self->{limit_bind}}, [ $self->__rows_bindtype => $rows ];
85 SELECT *, ROW_NUMBER() OVER( ORDER BY ... ) AS RNO__ROW__INDEX FROM (
88 ) WHERE RNO__ROW__INDEX BETWEEN ($offset+1) AND ($limit+$offset)
91 ANSI standard Limit/Offset implementation. Supported by B<DB2> and
96 my ($self, $sql, $rs_attrs, $rows, $offset ) = @_;
98 # get selectors, and scan the order_by (if any)
99 my ($stripped_sql, $in_sel, $out_sel, $alias_map, $extra_order_sel)
100 = $self->_subqueried_limit_attrs ( $sql, $rs_attrs );
102 # make up an order if none exists
103 my $requested_order = (delete $rs_attrs->{order_by}) || $self->_rno_default_order;
104 my $rno_ord = $self->_order_by ($requested_order);
106 # this is the order supplement magic
107 my $mid_sel = $out_sel;
108 if ($extra_order_sel) {
109 for my $extra_col (sort
110 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
111 keys %$extra_order_sel
113 $in_sel .= sprintf (', %s AS %s',
115 $extra_order_sel->{$extra_col},
118 $mid_sel .= ', ' . $extra_order_sel->{$extra_col};
122 # and this is order re-alias magic
123 for ($extra_order_sel, $alias_map) {
124 for my $col (keys %$_) {
125 my $re_col = quotemeta ($col);
126 $rno_ord =~ s/$re_col/$_->{$col}/;
130 # whatever is left of the order_by (only where is processed at this point)
131 my $group_having = $self->_parse_rs_attrs($rs_attrs);
133 my $qalias = $self->_quote ($rs_attrs->{alias});
134 my $idx_name = $self->_quote ('rno__row__index');
136 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset + 1], [ $self->__total_bindtype => $offset + $rows ];
140 SELECT $out_sel FROM (
141 SELECT $mid_sel, ROW_NUMBER() OVER( $rno_ord ) AS $idx_name FROM (
142 SELECT $in_sel ${stripped_sql}${group_having}
144 ) $qalias WHERE $idx_name >= ? AND $idx_name <= ?
150 # some databases are happy with OVER (), some need OVER (ORDER BY (SELECT (1)) )
151 sub _rno_default_order {
157 SELECT SKIP $offset FIRST $limit * FROM ...
159 Suported by B<Informix>, almost like LimitOffset. According to
160 L<SQL::Abstract::Limit> C<... SKIP $offset LIMIT $limit ...> is also supported.
164 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
166 $sql =~ s/^ \s* SELECT \s+ //ix
167 or $self->throw_exception("Unrecognizable SELECT: $sql");
169 return sprintf ('SELECT %s%s%s%s',
172 push @{$self->{pre_select_bind}}, [ $self->__offset_bindtype => $offset];
178 push @{$self->{pre_select_bind}}, [ $self->__rows_bindtype => $rows ];
182 $self->_parse_rs_attrs ($rs_attrs),
188 SELECT FIRST $limit SKIP $offset * FROM ...
190 Supported by B<Firebird/Interbase>, reverse of SkipFirst. According to
191 L<SQL::Abstract::Limit> C<... ROWS $limit TO $offset ...> is also supported.
195 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
197 $sql =~ s/^ \s* SELECT \s+ //ix
198 or $self->throw_exception("Unrecognizable SELECT: $sql");
200 return sprintf ('SELECT %s%s%s%s',
202 push @{$self->{pre_select_bind}}, [ $self->__rows_bindtype => $rows ];
207 push @{$self->{pre_select_bind}}, [ $self->__offset_bindtype => $offset];
213 $self->_parse_rs_attrs ($rs_attrs),
220 Depending on the resultset attributes one of:
223 SELECT *, ROWNUM rownum__index FROM (
225 ) WHERE ROWNUM <= ($limit+$offset)
226 ) WHERE rownum__index >= ($offset+1)
231 SELECT *, ROWNUM rownum__index FROM (
234 ) WHERE rownum__index BETWEEN ($offset+1) AND ($limit+$offset)
240 ) WHERE ROWNUM <= ($limit+1)
242 Supported by B<Oracle>.
246 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
248 my ($stripped_sql, $insel, $outsel) = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
250 my $qalias = $self->_quote ($rs_attrs->{alias});
251 my $idx_name = $self->_quote ('rownum__index');
252 my $order_group_having = $self->_parse_rs_attrs($rs_attrs);
255 # There are two ways to limit in Oracle, one vastly faster than the other
256 # on large resultsets: https://decipherinfosys.wordpress.com/2007/08/09/paging-and-countstopkey-optimization/
257 # However Oracle is retarded and does not preserve stable ROWNUM() values
258 # when called twice in the same scope. Therefore unless the resultset is
259 # ordered by a unique set of columns, it is not safe to use the faster
260 # method, and the slower BETWEEN query is used instead
262 # FIXME - this is quite expensive, and doe snot perform caching of any sort
263 # as soon as some of the DQ work becomes viable consider switching this
265 if ( __order_by_is_unique($rs_attrs) ) {
267 # if offset is 0 (first page) the we can skip a subquery
269 push @{$self->{limit_bind}}, [ $self->__rows_bindtype => $rows ];
272 SELECT $outsel FROM (
273 SELECT $insel ${stripped_sql}${order_group_having}
274 ) $qalias WHERE ROWNUM <= ?
278 push @{$self->{limit_bind}}, [ $self->__total_bindtype => $offset + $rows ], [ $self->__offset_bindtype => $offset + 1 ];
281 SELECT $outsel FROM (
282 SELECT $outsel, ROWNUM $idx_name FROM (
283 SELECT $insel ${stripped_sql}${order_group_having}
284 ) $qalias WHERE ROWNUM <= ?
285 ) $qalias WHERE $idx_name >= ?
290 push @{$self->{limit_bind}}, [ $self->__offset_bindtype => $offset + 1 ], [ $self->__total_bindtype => $offset + $rows ];
293 SELECT $outsel FROM (
294 SELECT $outsel, ROWNUM $idx_name FROM (
295 SELECT $insel ${stripped_sql}${order_group_having}
297 ) $qalias WHERE $idx_name BETWEEN ? AND ?
302 # determine if the supplied order_by contains a unique column (set)
303 sub __order_by_is_unique {
304 my $rs_attrs = shift;
305 my $rsrc = $rs_attrs->{_rsroot_rsrc};
306 my $order_by = $rs_attrs->{order_by}
309 my $storage = $rsrc->schema->storage;
311 my @order_by_cols = map { $_->[0] } $storage->_extract_order_criteria($order_by)
315 $storage->_resolve_column_info($rs_attrs->{from}, \@order_by_cols);
318 map {( "$_" => $_ )} map { $_->{-result_source} } values %$colinfo
321 my $supplied_order = {
323 grep { exists $colinfo->{$_} and ! $colinfo->{$_}{is_nullable} }
327 return 0 unless keys %$supplied_order;
330 map { values %$_ } map { +{ $_->unique_constraints } } values %$sources
333 unless first { ! exists $supplied_order->{$_} } @$uks;
339 # used by _Top and _FetchFirst below
340 sub _prep_for_skimming_limit {
341 my ( $self, $sql, $rs_attrs ) = @_;
344 my (%r, $alias_map, $extra_order_sel);
345 ($r{inner_sql}, $r{in_sel}, $r{out_sel}, $alias_map, $extra_order_sel)
346 = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
348 my $requested_order = delete $rs_attrs->{order_by};
349 $r{order_by_requested} = $self->_order_by ($requested_order);
351 # make up an order unless supplied
352 my $inner_order = ($r{order_by_requested}
355 { "$rs_attrs->{alias}.$_" }
356 ( $rs_attrs->{_rsroot_rsrc}->_pri_cols )
360 # localise as we already have all the bind values we need
362 local $self->{order_bind};
363 $r{order_by_inner} = $self->_order_by ($inner_order);
366 for my $ch ($self->_order_by_chunks ($inner_order)) {
367 $ch = $ch->[0] if ref $ch eq 'ARRAY';
369 $ch =~ s/\s+ ( ASC|DESC ) \s* $//ix;
370 my $dir = uc ($1||'ASC');
372 push @out_chunks, \join (' ', $ch, $dir eq 'ASC' ? 'DESC' : 'ASC' );
375 $r{order_by_reversed} = $self->_order_by (\@out_chunks);
378 # this is the order supplement magic
379 $r{mid_sel} = $r{out_sel};
380 if ($extra_order_sel) {
381 for my $extra_col (sort
382 { $extra_order_sel->{$a} cmp $extra_order_sel->{$b} }
383 keys %$extra_order_sel
385 $r{in_sel} .= sprintf (', %s AS %s',
387 $extra_order_sel->{$extra_col},
390 $r{mid_sel} .= ', ' . $extra_order_sel->{$extra_col};
393 # Whatever order bindvals there are, they will be realiased and
394 # need to show up in front of the entire initial inner subquery
395 push @{$self->{pre_select_bind}}, @{$self->{order_bind}};
398 # and this is order re-alias magic
399 for my $map ($extra_order_sel, $alias_map) {
400 for my $col (keys %$map) {
401 my $re_col = quotemeta ($col);
402 $_ =~ s/$re_col/$map->{$col}/
403 for ($r{order_by_reversed}, $r{order_by_requested});
407 # generate the rest of the sql
408 $r{grpby_having} = $self->_parse_rs_attrs ($rs_attrs);
410 $r{quoted_rs_alias} = $self->_quote ($rs_attrs->{alias});
419 SELECT TOP $limit FROM (
420 SELECT TOP $limit FROM (
421 SELECT TOP ($limit+$offset) ...
422 ) ORDER BY $reversed_original_order
423 ) ORDER BY $original_order
425 Unreliable Top-based implementation, supported by B<< MSSQL < 2005 >>.
429 Due to its implementation, this limit dialect returns B<incorrect results>
430 when $limit+$offset > total amount of rows in the resultset.
435 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
437 my %l = %{ $self->_prep_for_skimming_limit($sql, $rs_attrs) };
439 $sql = sprintf ('SELECT TOP %u %s %s %s %s',
440 $rows + ($offset||0),
447 $sql = sprintf ('SELECT TOP %u %s FROM ( %s ) %s %s',
452 $l{order_by_reversed},
455 $sql = sprintf ('SELECT TOP %u %s FROM ( %s ) %s %s',
460 $l{order_by_requested},
461 ) if ( ($offset && $l{order_by_requested}) || ($l{mid_sel} ne $l{out_sel}) );
473 ) ORDER BY $reversed_original_order
474 FETCH FIRST $limit ROWS ONLY
475 ) ORDER BY $original_order
476 FETCH FIRST $limit ROWS ONLY
479 Unreliable FetchFirst-based implementation, supported by B<< IBM DB2 <= V5R3 >>.
483 Due to its implementation, this limit dialect returns B<incorrect results>
484 when $limit+$offset > total amount of rows in the resultset.
489 my ( $self, $sql, $rs_attrs, $rows, $offset ) = @_;
491 my %l = %{ $self->_prep_for_skimming_limit($sql, $rs_attrs) };
493 $sql = sprintf ('SELECT %s %s %s %s FETCH FIRST %u ROWS ONLY',
498 $rows + ($offset||0),
501 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s FETCH FIRST %u ROWS ONLY',
505 $l{order_by_reversed},
509 $sql = sprintf ('SELECT %s FROM ( %s ) %s %s FETCH FIRST %u ROWS ONLY',
513 $l{order_by_requested},
515 ) if ( ($offset && $l{order_by_requested}) || ($l{mid_sel} ne $l{out_sel}) );
520 =head2 RowCountOrGenericSubQ
522 This is not exactly a limit dialect, but more of a proxy for B<Sybase ASE>.
523 If no $offset is supplied the limit is simply performed as:
529 Otherwise we fall back to L</GenericSubQ>
533 sub _RowCountOrGenericSubQ {
535 my ($sql, $rs_attrs, $rows, $offset) = @_;
537 return $self->_GenericSubQ(@_) if $offset;
539 return sprintf <<"EOF", $rows, $sql;
552 SELECT COUNT(*) FROM $original_table cnt WHERE cnt.id < $original_table.id
553 ) BETWEEN $offset AND ($offset+$rows-1)
555 This is the most evil limit "dialect" (more of a hack) for I<really> stupid
556 databases. It works by ordering the set by some unique column, and calculating
557 the amount of rows that have a less-er value (thus emulating a L</RowNum>-like
558 index). Of course this implies the set can only be ordered by a single unique
559 column. Also note that this technique can be and often is B<excruciatingly
562 Currently used by B<Sybase ASE>, due to lack of any other option.
566 my ($self, $sql, $rs_attrs, $rows, $offset) = @_;
568 my $root_rsrc = $rs_attrs->{_rsroot_rsrc};
569 my $root_tbl_name = $root_rsrc->name;
571 my ($order_by, @rest) = do {
572 local $self->{quote_char};
573 $self->_order_by_chunks ($rs_attrs->{order_by})
583 ( ref $order_by eq 'ARRAY' and @$order_by == 1 )
586 $self->throw_exception (
587 'Generic Subquery Limit does not work on resultsets without an order, or resultsets '
588 . 'with complex order criteria (multicolumn and/or functions). Provide a single, '
589 . 'unique-column order criteria.'
593 ($order_by) = @$order_by if ref $order_by;
595 $order_by =~ s/\s+ ( ASC|DESC ) \s* $//ix;
596 my $direction = lc ($1 || 'asc');
598 my ($unq_sort_col) = $order_by =~ /(?:^|\.)([^\.]+)$/;
600 my $inf = $root_rsrc->storage->_resolve_column_info (
601 $rs_attrs->{from}, [$order_by, $unq_sort_col]
604 my $ord_colinfo = $inf->{$order_by} || $self->throw_exception("Unable to determine source of order-criteria '$order_by'");
606 if ($ord_colinfo->{-result_source}->name ne $root_tbl_name) {
607 $self->throw_exception(sprintf
608 "Generic Subquery Limit order criteria can be only based on the root-source '%s'"
609 . " (aliased as '%s')", $root_rsrc->source_name, $rs_attrs->{alias},
613 # make sure order column is qualified
614 $order_by = "$rs_attrs->{alias}.$order_by"
615 unless $order_by =~ /^$rs_attrs->{alias}\./;
618 my $ucs = { $root_rsrc->unique_constraints };
619 for (values %$ucs ) {
620 if (@$_ == 1 && "$rs_attrs->{alias}.$_->[0]" eq $order_by) {
625 $self->throw_exception(
626 "Generic Subquery Limit order criteria column '$order_by' must be unique (no unique constraint found)"
629 my ($stripped_sql, $in_sel, $out_sel, $alias_map, $extra_order_sel)
630 = $self->_subqueried_limit_attrs ($sql, $rs_attrs);
632 my $cmp_op = $direction eq 'desc' ? '>' : '<';
633 my $count_tbl_alias = 'rownum__emulation';
635 my $order_sql = $self->_order_by (delete $rs_attrs->{order_by});
636 my $group_having_sql = $self->_parse_rs_attrs($rs_attrs);
638 # add the order supplement (if any) as this is what will be used for the outer WHERE
639 $in_sel .= ", $_" for keys %{$extra_order_sel||{}};
643 $rownum_cond = 'BETWEEN ? AND ?';
645 push @{$self->{limit_bind}},
646 [ $self->__offset_bindtype => $offset ],
647 [ $self->__total_bindtype => $offset + $rows - 1]
651 $rownum_cond = '< ?';
653 push @{$self->{limit_bind}},
654 [ $self->__rows_bindtype => $rows ]
661 SELECT $in_sel ${stripped_sql}${group_having_sql}
663 WHERE ( SELECT COUNT(*) FROM %s %s WHERE %s $cmp_op %s ) $rownum_cond
665 ", map { $self->_quote ($_) } (
669 "$count_tbl_alias.$unq_sort_col",
675 # !!! THIS IS ALSO HORRIFIC !!! /me ashamed
677 # Generates inner/outer select lists for various limit dialects
678 # which result in one or more subqueries (e.g. RNO, Top, RowNum)
679 # Any non-root-table columns need to have their table qualifier
680 # turned into a column alias (otherwise names in subqueries clash
681 # and/or lose their source table)
683 # Returns mangled proto-sql, inner/outer strings of SQL QUOTED selectors
684 # with aliases (to be used in whatever select statement), and an alias
685 # index hashref of QUOTED SEL => QUOTED ALIAS pairs (to maybe be used
686 # for string-subst higher up).
687 # If an order_by is supplied, the inner select needs to bring out columns
688 # used in implicit (non-selected) orders, and the order condition itself
689 # needs to be realiased to the proper names in the outer query. Thus we
690 # also return a hashref (order doesn't matter) of QUOTED EXTRA-SEL =>
691 # QUOTED ALIAS pairs, which is a list of extra selectors that do *not*
692 # exist in the original select list
693 sub _subqueried_limit_attrs {
694 my ($self, $proto_sql, $rs_attrs) = @_;
696 $self->throw_exception(
697 'Limit dialect implementation usable only in the context of DBIC (missing $rs_attrs)'
698 ) unless ref ($rs_attrs) eq 'HASH';
700 # mangle the input sql as we will be replacing the selector entirely
702 $rs_attrs->{_selector_sql}
704 $proto_sql =~ s/^ \s* SELECT \s* \Q$rs_attrs->{_selector_sql}//ix
706 $self->throw_exception("Unrecognizable SELECT: $proto_sql");
709 my ($re_sep, $re_alias) = map { quotemeta $_ } ( $self->{name_sep}, $rs_attrs->{alias} );
711 # insulate from the multiple _recurse_fields calls below
712 local $self->{select_bind};
714 # correlate select and as, build selection index
715 my (@sel, $in_sel_index);
716 for my $i (0 .. $#{$rs_attrs->{select}}) {
718 my $s = $rs_attrs->{select}[$i];
719 my $sql_sel = $self->_recurse_fields ($s);
720 my $sql_alias = (ref $s) eq 'HASH' ? $s->{-as} : undef;
725 local $self->{quote_char};
726 $self->_recurse_fields ($s);
733 $self->throw_exception("Select argument $i ($s) without corresponding 'as'")
737 $in_sel_index->{$sql_sel}++;
738 $in_sel_index->{$self->_quote ($sql_alias)}++ if $sql_alias;
740 # record unqualified versions too, so we do not have
741 # to reselect the same column twice (in qualified and
743 if (! ref $s && $sql_sel =~ / $re_sep (.+) $/x) {
744 $in_sel_index->{$1}++;
749 # re-alias and remove any name separators from aliases,
750 # unless we are dealing with the current source alias
751 # (which will transcend the subqueries as it is necessary
752 # for possible further chaining)
753 my (@in_sel, @out_sel, %renamed);
754 for my $node (@sel) {
756 $node->{as} =~ / (?<! ^ $re_alias ) \. /x
758 $node->{unquoted_sql} =~ / (?<! ^ $re_alias ) $re_sep /x
760 $node->{as} = $self->_unqualify_colname($node->{as});
761 my $quoted_as = $self->_quote($node->{as});
762 push @in_sel, sprintf '%s AS %s', $node->{sql}, $quoted_as;
763 push @out_sel, $quoted_as;
764 $renamed{$node->{sql}} = $quoted_as;
767 push @in_sel, $node->{sql};
768 push @out_sel, $self->_quote ($node->{as});
771 # see if the order gives us anything
773 for my $chunk ($self->_order_by_chunks ($rs_attrs->{order_by})) {
775 $chunk = $chunk->[0] if (ref $chunk) eq 'ARRAY';
776 $chunk =~ s/\s+ (?: ASC|DESC ) \s* $//ix;
778 next if $in_sel_index->{$chunk};
780 $extra_order_sel{$chunk} ||= $self->_quote (
781 'ORDER__BY__' . scalar keys %extra_order_sel
787 (map { join (', ', @$_ ) } (
792 keys %extra_order_sel ? \%extra_order_sel : (),
796 sub _unqualify_colname {
797 my ($self, $fqcn) = @_;
798 $fqcn =~ s/ \. /__/xg;
806 See L<DBIx::Class/CONTRIBUTORS>.
810 You may distribute this code under the same terms as Perl itself.