Move find_co_root into DBICTest::Util
[dbsrgits/DBIx-Class.git] / t / sqlmaker / limit_dialects / toplimit.t
CommitLineData
65c2b042 1use strict;
2use warnings;
3
4use Test::More;
65c2b042 5use lib qw(t/lib);
a5a7bb73 6use DBICTest ':DiffSQL';
ed0648ee 7
e606d0ce 8my $schema = DBICTest->init_schema;
65c2b042 9
e606d0ce 10# Trick the sqlite DB to use Top limit emulation
8f6dbee9 11# We could test all of this via $sq->$op directly,
ed0648ee 12# but some conditions need a $rsrc
20f44a33 13delete $schema->storage->_sql_maker->{_cached_syntax};
e606d0ce 14$schema->storage->_sql_maker->limit_dialect ('Top');
15
86bb5a27 16my $books_45_and_owners = $schema->resultset ('BooksInLibrary')->search ({}, {
17 prefetch => 'owner', rows => 2, offset => 3,
18 columns => [ grep { $_ ne 'title' } $schema->source('BooksInLibrary')->columns ],
19});
e606d0ce 20
20f44a33 21for my $null_order (
22 undef,
23 '',
24 {},
25 [],
26 [{}],
27) {
28 my $rs = $books_45_and_owners->search ({}, {order_by => $null_order });
e606d0ce 29 is_same_sql_bind(
20f44a33 30 $rs->as_query,
31 '(SELECT TOP 2
90ed89cb 32 me.id, me.source, me.owner, me.price, owner__id, owner__name
20f44a33 33 FROM (
34 SELECT TOP 5
86bb5a27 35 me.id, me.source, me.owner, me.price, owner.id AS owner__id, owner.name AS owner__name
20f44a33 36 FROM books me
37 JOIN owners owner ON owner.id = me.owner
38 WHERE ( source = ? )
39 ORDER BY me.id
40 ) me
41 ORDER BY me.id DESC
42 )',
0e773352 43 [ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
44 => 'Library' ] ],
65c2b042 45 );
46}
47
69d3c270 48{
49my $subq = $schema->resultset('Owners')->search({
50 'count.id' => { -ident => 'owner.id' },
51}, { alias => 'owner' })->count_rs;
52
53my $rs_selectas_rel = $schema->resultset('BooksInLibrary')->search ({}, {
54 columns => [
55 { owner_name => 'owner.name' },
56 { owner_books => $subq->as_query },
57 ],
58 join => 'owner',
59 rows => 2,
60 offset => 3,
61});
62
63is_same_sql_bind(
64 $rs_selectas_rel->as_query,
65 '(
66 SELECT TOP 2 owner_name, owner_books
67 FROM (
68 SELECT TOP 5 owner.name AS owner_name,
69 ( SELECT COUNT( * )
70 FROM owners owner
71 WHERE ( count.id = owner.id )
72 ) AS owner_books
73 FROM books me
74 JOIN owners owner ON owner.id = me.owner
75 WHERE ( source = ? )
76 ORDER BY me.id
77 ) me
78 ORDER BY me.id DESC
79 )',
80 [ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
81 => 'Library' ] ],
82 'pagination with subqueries works'
83);
84
85}
20f44a33 86
87for my $ord_set (
e606d0ce 88 {
86bb5a27 89 order_by => \'title DESC',
90 order_inner => 'title DESC',
08a1eaad 91 order_outer => 'ORDER__BY__001 ASC',
92 order_req => 'ORDER__BY__001 DESC',
93 exselect_outer => 'ORDER__BY__001',
94 exselect_inner => 'title AS ORDER__BY__001',
e606d0ce 95 },
96 {
86bb5a27 97 order_by => { -asc => 'title' },
98 order_inner => 'title ASC',
08a1eaad 99 order_outer => 'ORDER__BY__001 DESC',
100 order_req => 'ORDER__BY__001 ASC',
101 exselect_outer => 'ORDER__BY__001',
102 exselect_inner => 'title AS ORDER__BY__001',
e606d0ce 103 },
104 {
86bb5a27 105 order_by => { -desc => 'title' },
106 order_inner => 'title DESC',
08a1eaad 107 order_outer => 'ORDER__BY__001 ASC',
108 order_req => 'ORDER__BY__001 DESC',
109 exselect_outer => 'ORDER__BY__001',
110 exselect_inner => 'title AS ORDER__BY__001',
e606d0ce 111 },
112 {
86bb5a27 113 order_by => 'title',
114 order_inner => 'title',
08a1eaad 115 order_outer => 'ORDER__BY__001 DESC',
116 order_req => 'ORDER__BY__001',
117 exselect_outer => 'ORDER__BY__001',
118 exselect_inner => 'title AS ORDER__BY__001',
e606d0ce 119 },
120 {
86bb5a27 121 order_by => [ qw{ title me.owner} ],
122 order_inner => 'title, me.owner',
08a1eaad 123 order_outer => 'ORDER__BY__001 DESC, me.owner DESC',
124 order_req => 'ORDER__BY__001, me.owner',
125 exselect_outer => 'ORDER__BY__001',
126 exselect_inner => 'title AS ORDER__BY__001',
e606d0ce 127 },
128 {
86bb5a27 129 order_by => ['title', { -desc => 'bar' } ],
130 order_inner => 'title, bar DESC',
08a1eaad 131 order_outer => 'ORDER__BY__001 DESC, ORDER__BY__002 ASC',
132 order_req => 'ORDER__BY__001, ORDER__BY__002 DESC',
133 exselect_outer => 'ORDER__BY__001, ORDER__BY__002',
134 exselect_inner => 'title AS ORDER__BY__001, bar AS ORDER__BY__002',
e606d0ce 135 },
136 {
86bb5a27 137 order_by => { -asc => [qw{ title bar }] },
138 order_inner => 'title ASC, bar ASC',
08a1eaad 139 order_outer => 'ORDER__BY__001 DESC, ORDER__BY__002 DESC',
140 order_req => 'ORDER__BY__001 ASC, ORDER__BY__002 ASC',
141 exselect_outer => 'ORDER__BY__001, ORDER__BY__002',
142 exselect_inner => 'title AS ORDER__BY__001, bar AS ORDER__BY__002',
e606d0ce 143 },
144 {
145 order_by => [
86bb5a27 146 'title',
e606d0ce 147 { -desc => [qw{bar}] },
20f44a33 148 { -asc => [qw{me.owner sensors}]},
e606d0ce 149 ],
86bb5a27 150 order_inner => 'title, bar DESC, me.owner ASC, sensors ASC',
08a1eaad 151 order_outer => 'ORDER__BY__001 DESC, ORDER__BY__002 ASC, me.owner DESC, ORDER__BY__003 DESC',
152 order_req => 'ORDER__BY__001, ORDER__BY__002 DESC, me.owner ASC, ORDER__BY__003 ASC',
153 exselect_outer => 'ORDER__BY__001, ORDER__BY__002, ORDER__BY__003',
154 exselect_inner => 'title AS ORDER__BY__001, bar AS ORDER__BY__002, sensors AS ORDER__BY__003',
e606d0ce 155 },
20f44a33 156) {
157 my $o_sel = $ord_set->{exselect_outer}
158 ? ', ' . $ord_set->{exselect_outer}
159 : ''
160 ;
161 my $i_sel = $ord_set->{exselect_inner}
162 ? ', ' . $ord_set->{exselect_inner}
163 : ''
164 ;
83dee2e9 165
20f44a33 166 is_same_sql_bind(
167 $books_45_and_owners->search ({}, {order_by => $ord_set->{order_by}})->as_query,
90ed89cb 168 "(SELECT me.id, me.source, me.owner, me.price, owner__id, owner__name
20f44a33 169 FROM (
170 SELECT TOP 2
90ed89cb 171 me.id, me.source, me.owner, me.price, owner__id, owner__name$o_sel
20f44a33 172 FROM (
173 SELECT TOP 5
86bb5a27 174 me.id, me.source, me.owner, me.price, owner.id AS owner__id, owner.name AS owner__name$i_sel
20f44a33 175 FROM books me
176 JOIN owners owner ON owner.id = me.owner
177 WHERE ( source = ? )
178 ORDER BY $ord_set->{order_inner}
179 ) me
180 ORDER BY $ord_set->{order_outer}
181 ) me
182 ORDER BY $ord_set->{order_req}
183 )",
0e773352 184 [ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
185 => 'Library' ] ],
94fa8410 186 );
20f44a33 187}
8f6dbee9 188
20f44a33 189# with groupby
8f6dbee9 190is_same_sql_bind (
20f44a33 191 $books_45_and_owners->search ({}, { group_by => 'title', order_by => 'title' })->as_query,
86bb5a27 192 '(SELECT me.id, me.source, me.owner, me.price, owner.id, owner.name
20f44a33 193 FROM (
97e130fa 194 SELECT me.id, me.source, me.owner, me.price, me.title
20f44a33 195 FROM (
196 SELECT TOP 2
97e130fa 197 me.id, me.source, me.owner, me.price, me.title
20f44a33 198 FROM (
199 SELECT TOP 5
97e130fa 200 me.id, me.source, me.owner, me.price, me.title
20f44a33 201 FROM books me
202 JOIN owners owner ON owner.id = me.owner
203 WHERE ( source = ? )
204 GROUP BY title
205 ORDER BY title
206 ) me
97e130fa 207 ORDER BY title DESC
20f44a33 208 ) me
97e130fa 209 ORDER BY title
83dee2e9 210 ) me
20f44a33 211 JOIN owners owner ON owner.id = me.owner
212 WHERE ( source = ? )
213 ORDER BY title
214 )',
0e773352 215 [ map { [
216 { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
217 => 'Library' ]
218 } (1,2) ],
8f6dbee9 219);
a5f843e3 220
20f44a33 221# test deprecated column mixing over join boundaries
41eac664 222my $rs_selectas_top = $schema->resultset ('BooksInLibrary')->search ({}, {
223 '+select' => ['owner.name'],
224 '+as' => ['owner_name'],
225 join => 'owner',
69d3c270 226 rows => 1
41eac664 227});
a5f843e3 228
229is_same_sql_bind( $rs_selectas_top->search({})->as_query,
41eac664 230 '(SELECT
231 TOP 1 me.id, me.source, me.owner, me.title, me.price,
a66b662c 232 owner.name
41eac664 233 FROM books me
234 JOIN owners owner ON owner.id = me.owner
235 WHERE ( source = ? )
0e773352 236 )',
237 [ [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' }
238 => 'Library' ] ],
a5f843e3 239 );
240
d7632687 241{
242 my $rs = $schema->resultset('Artist')->search({}, {
86bb5a27 243 columns => 'artistid',
d7632687 244 offset => 1,
86bb5a27 245 order_by => 'artistid',
d7632687 246 });
247 local $rs->result_source->{name} = "weird \n newline/multi \t \t space containing \n table";
248
249 like (
250 ${$rs->as_query}->[0],
251 qr| weird \s \n \s newline/multi \s \t \s \t \s space \s containing \s \n \s table|x,
252 'Newlines/spaces preserved in final sql',
253 );
254}
255
f74d22e2 256{
257my $subq = $schema->resultset('Owners')->search({
258 'books.owner' => { -ident => 'owner.id' },
259}, { alias => 'owner', select => ['id'] } )->count_rs;
260
261my $rs_selectas_rel = $schema->resultset('BooksInLibrary')->search( { -exists => $subq->as_query }, { select => ['id','owner'], rows => 1 } );
262
263is_same_sql_bind(
264 $rs_selectas_rel->as_query,
a66b662c 265 '(SELECT TOP 1 me.id, me.owner FROM books me WHERE ( ( (EXISTS (SELECT COUNT( * ) FROM owners owner WHERE ( books.owner = owner.id ))) AND source = ? ) ) )',
f74d22e2 266 [
267 [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ],
268 ],
269 'Pagination with sub-query in WHERE works'
270);
271
272}
273
a5f843e3 274done_testing;