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