use warnings;
use Test::More;
+use Test::Exception;
use lib qw(t/lib);
use DBICTest;
use DBIC::SqlMakerTest;
my $schema = DBICTest->init_schema;
+my $native_limit_dialect = $schema->storage->sql_maker->{limit_dialect};
my $attr = {};
my @where_bind = (
[ { sqlt_datatype => 'integer' } => 3 ],
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM owners me
+ LIMIT ? OFFSET ?
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 3 ],
+ [ { sqlt_datatype => 'integer' } => 1 ],
+ ]
+ ],
},
LimitXY => {
[ { sqlt_datatype => 'integer' } => 4 ],
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM owners me
+ LIMIT ?,?
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 1 ],
+ [ { sqlt_datatype => 'integer' } => 3 ],
+ ]
+ ],
},
SkipFirst => {
@order_bind,
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT SKIP ? FIRST ? me.name, me.id
+ FROM owners me
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 1 ],
+ [ { sqlt_datatype => 'integer' } => 3 ],
+ ]
+ ],
},
FirstSkip => {
@order_bind,
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT FIRST ? SKIP ? me.name, me.id
+ FROM owners me
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 3 ],
+ [ { sqlt_datatype => 'integer' } => 1 ],
+ ]
+ ],
},
RowNumberOver => do {
[ { sqlt_datatype => 'integer' } => 7 ],
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM (
+ SELECT me.name, me.id, ROW_NUMBER() OVER() AS rno__row__index
+ FROM (
+ SELECT me.name, me.id FROM owners me
+ ) me
+ ) me
+ WHERE rno__row__index >= ? AND rno__row__index <= ?
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 2 ],
+ [ { sqlt_datatype => 'integer' } => 4 ],
+ ]
+ ],
};
},
[ { sqlt_datatype => 'integer' } => 4 ],
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM (
+ SELECT me.name, me.id, ROWNUM rownum__index
+ FROM (
+ SELECT me.name, me.id
+ FROM owners me
+ ) me
+ ) me WHERE rownum__index BETWEEN ? AND ?
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 2 ],
+ [ { sqlt_datatype => 'integer' } => 4 ],
+ ]
+ ],
};
},
(map { [ @$_ ] } @order_bind), # without this is_deeply throws a fit
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM (
+ SELECT me.name, me.id
+ FROM owners me
+ ORDER BY me.id
+ FETCH FIRST 4 ROWS ONLY
+ ) me
+ ORDER BY me.id DESC
+ FETCH FIRST 3 ROWS ONLY
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [],
+ ],
},
Top => {
(map { [ @$_ ] } @order_bind), # without this is_deeply throws a fit
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT TOP 3 me.name, me.id
+ FROM (
+ SELECT TOP 4 me.name, me.id
+ FROM owners me
+ ORDER BY me.id
+ ) me
+ ORDER BY me.id DESC
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [],
+ ],
},
RowCountOrGenericSubQ => {
[ { sqlt_datatype => 'integer' } => 6 ],
],
],
+ limit_offset_prefetch => [
+ '(
+ SELECT me.name, books.id, books.source, books.owner, books.title, books.price
+ FROM (
+ SELECT me.name, me.id
+ FROM (
+ SELECT me.name, me.id FROM owners me
+ ) me
+ WHERE (
+ SELECT COUNT(*)
+ FROM owners rownum__emulation
+ WHERE rownum__emulation.id < me.id
+ ) BETWEEN ? AND ?
+ ORDER BY me.id
+ ) me
+ LEFT JOIN books books
+ ON books.owner = me.id
+ ORDER BY me.id
+ )',
+ [
+ [ { sqlt_datatype => 'integer' } => 1 ],
+ [ { sqlt_datatype => 'integer' } => 3 ],
+ ],
+ ],
}
};
@{$tests->{$limtype}{ordered_limit_offset}},
"$limtype: Ordered limit+offset with select/group/having",
) if $tests->{$limtype}{ordered_limit_offset};
+
+ # complex prefetch on partial-fetch root with limit
+ my $pref_rs = $schema->resultset('Owners')->search({}, {
+ rows => 3,
+ offset => 1,
+ columns => 'name', # only the owner name, still prefetch all the books
+ prefetch => 'books',
+ ($limtype =~ /GenericSubQ/ ? ( order_by => 'me.id' ) : () ), # needs a simple-column stable order to be happy
+ });
+
+ is_same_sql_bind (
+ $pref_rs->as_query,
+ @{$tests->{$limtype}{limit_offset_prefetch}},
+ "$limtype: Prefetch with limit+offset",
+ ) if $tests->{$limtype}{limit_offset_prefetch};
+
+ # we can actually run the query
+ if ($limtype eq $native_limit_dialect or $limtype eq 'GenericSubQ') {
+ lives_ok { is ($pref_rs->all, 1, 'Expected count of objects on limtied prefetch') }
+ "Complex limited prefetch works with supported limit $limtype"
+ }
}
done_testing;