return undef;
}
+=head2 OffsetFetchNext
+
+ SELECT * FROM ... OFFSET 10 ROWS FETCH NEXT 5 ROWS ONLY
+
+Suported by B<SQL Server 2012>, purported to be more efficient than L</RowNumberOver>.
+
+=cut
+sub _OffsetFetchNext {
+ my ($self, $sql, $rs_attrs, $rows, $offset ) = @_;
+
+ my $requested_order = (delete $rs_attrs->{order_by}) || \'1';
+
+ my $ord = $self->_order_by ($requested_order) || ' ORDER BY 1';
+
+ $sql .= $self->_parse_rs_attrs( $rs_attrs )
+ . $ord
+ . ' OFFSET ? ROWS FETCH NEXT ? ROWS ONLY';
+ push @{$self->{limit_bind}},
+ [ $self->__offset_bindtype => $offset || 0],
+ [ $self->__rows_bindtype => $rows];
+
+ return $sql;
+}
+
=head2 SkipFirst
SELECT SKIP $offset FIRST $limit * FROM ...
sub sql_limit_dialect {
my $self = shift;
+ my $supports_ofn = $self->_sql_server_2012_or_higher;
+
+ unless (defined $supports_ofn) {
+ # User is connecting via DBD::Sybase and has no permission to run
+ # stored procedures like xp_msver, or version detection failed for some
+ # other reason.
+ # So, we use a query to check if OFN is implemented.
+ try {
+ $self->_get_dbh->selectrow_array('SELECT 1 ORDER BY 1 OFFSET 0 ROWS');
+ $supports_ofn = 1;
+ };
+ }
+ return 'OffsetFetchNext' if $supports_ofn;
+
my $supports_rno = $self->_sql_server_2005_or_higher;
unless (defined $supports_rno) {
$supports_rno = 1;
};
}
+ return 'RowNumberOver' if $supports_rno;
- return $supports_rno ? 'RowNumberOver' : 'Top';
+ return 'Top';
}
sub _ping {
--- /dev/null
+use strict;
+use warnings;
+
+use Test::More;
+use lib qw(t/lib);
+use DBICTest;
+use DBIC::SqlMakerTest;
+
+my $schema = DBICTest->init_schema;
+
+my ($ROWS, $OFFSET) = (
+ DBIx::Class::SQLMaker::LimitDialects->__rows_bindtype,
+ DBIx::Class::SQLMaker::LimitDialects->__offset_bindtype,
+);
+
+# based on toplimit.t
+delete $schema->storage->_sql_maker->{_cached_syntax};
+$schema->storage->_sql_maker->limit_dialect ('OffsetFetchNext');
+
+my $books_45_and_owners = $schema->resultset ('BooksInLibrary')->search ({}, {
+ prefetch => 'owner', rows => 2,
+ columns => [ grep { $_ ne 'title' } $schema->source('BooksInLibrary')->columns ],
+});
+
+# no offset
+is_same_sql_bind(
+ $books_45_and_owners->as_query,
+ '(
+ SELECT me.id, me.source, me.owner, me.price, owner.id, owner.name
+ FROM books me
+ JOIN owners owner ON owner.id = me.owner
+ WHERE ( source = ? )
+ ORDER BY 1
+ OFFSET ? ROWS FETCH NEXT ? ROWS ONLY
+ )',
+ [
+ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
+ => 'Library' ],
+ [ $OFFSET => 0 ],
+ [ $ROWS => 2 ],
+ ],
+);
+
+$books_45_and_owners = $books_45_and_owners->search({}, { offset => 3 });
+for my $null_order (
+ undef,
+ '',
+ {},
+ [],
+ [{}],
+) {
+ my $rs = $books_45_and_owners->search ({}, {order_by => $null_order });
+ is_same_sql_bind(
+ $rs->as_query,
+ '(SELECT me.id, me.source, me.owner, me.price, owner.id, owner.name
+ FROM books me
+ JOIN owners owner ON owner.id = me.owner
+ WHERE ( source = ? )
+ ORDER BY 1
+ OFFSET ? ROWS
+ FETCH NEXT ? ROWS ONLY
+ )',
+ [
+ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
+ => 'Library' ],
+ [ $OFFSET => 3 ],
+ [ $ROWS => 2 ],
+ ],
+ );
+}
+
+{
+ my $rs = $schema->resultset('Artist')->search({}, {
+ columns => 'artistid',
+ offset => 1,
+ order_by => 'artistid',
+ });
+ local $rs->result_source->{name} = "weird \n newline/multi \t \t space containing \n table";
+
+ like (
+ ${$rs->as_query}->[0],
+ qr| weird \s \n \s newline/multi \s \t \s \t \s space \s containing \s \n \s table|x,
+ 'Newlines/spaces preserved in final sql',
+ );
+}
+
+my $attr = {};
+my $rs_selectas_rel = $schema->resultset('BooksInLibrary')->search(undef, {
+ columns => 'me.id',
+ offset => 3,
+ rows => 4,
+ '+columns' => { bar => \['? * ?', [ $attr => 11 ], [ $attr => 12 ]], baz => \[ '?', [ $attr => 13 ]] },
+ order_by => [ \['? / ?', [ $attr => 1 ], [ $attr => 2 ]], \[ '?', [ $attr => 3 ]] ],
+ having => \[ '?', [ $attr => 21 ] ],
+});
+
+is_same_sql_bind(
+ $rs_selectas_rel->as_query,
+ '(
+ SELECT me.id, ? * ?, ?
+ FROM books me
+ WHERE ( source = ? )
+ HAVING ?
+ ORDER BY ? / ?, ?
+ OFFSET ? ROWS
+ FETCH NEXT ? ROWS ONLY
+ )',
+ [
+ [ $attr => 11 ], [ $attr => 12 ], [ $attr => 13 ],
+ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ],
+ [ $attr => 21 ],
+ [ $attr => 1 ], [ $attr => 2 ], [ $attr => 3 ],
+ [ $OFFSET => 3 ],
+ [ $ROWS => 4 ],
+ ],
+ 'Pagination with sub-query in ORDER BY works'
+);
+
+
+done_testing;