don't expand unknown clauses, nerf returning support if overriden
[scpubgit/Q-Branch.git] / xt / clauses.t
CommitLineData
c42752fc 1use strict;
2use warnings;
3use Test::More;
4a2c263b 4use SQL::Abstract::Test import => [ qw(is_same_sql_bind is_same_sql) ];
c42752fc 5use SQL::Abstract::ExtraClauses;
6
07070f1a 7my $sqlac = SQL::Abstract::ExtraClauses->new(
8 unknown_unop_always_func => 1,
9 lazy_join_sql_parts => 1,
10);
c42752fc 11
54a2a1e5 12is_deeply(
13 [ $sqlac->statement_list ],
14 [ sort qw(select update insert delete) ],
15);
16
c42752fc 17my ($sql, @bind) = $sqlac->select({
7250aa13 18 select => [ qw(artist.id artist.name), { -json_agg => 'cd' } ],
c42752fc 19 from => [
b99e9a14 20 { artists => { -as => 'artist' } },
21 -join => [ cds => as => 'cd' => on => { 'cd.artist_id' => 'artist.id' } ],
c42752fc 22 ],
23 where => { 'artist.genres', => { '@>', { -value => [ 'Rock' ] } } },
24 order_by => 'artist.name',
25 group_by => 'artist.id',
7250aa13 26 having => { '>' => [ { -count => 'cd.id' }, 3 ] }
c42752fc 27});
28
07070f1a 29::Dwarn([ $sql->formatter->_simplify($sql->to_array), $sql->stringify ]);
30
c42752fc 31is_same_sql_bind(
32 $sql, \@bind,
33 q{
34 SELECT artist.id, artist.name, JSON_AGG(cd)
b99e9a14 35 FROM artists AS artist JOIN cds AS cd ON cd.artist_id = artist.id
c42752fc 36 WHERE artist.genres @> ?
c42752fc 37 GROUP BY artist.id
38 HAVING COUNT(cd.id) > ?
2b0b3d43 39 ORDER BY artist.name
c42752fc 40 },
41 [ [ 'Rock' ], 3 ]
42);
43
4a2c263b 44($sql) = $sqlac->select({
45 select => [ 'a' ],
46 from => [ { -values => [ [ 1, 2 ], [ 3, 4 ] ] }, -as => [ qw(t a b) ] ],
47});
48
49is_same_sql($sql, q{SELECT a FROM (VALUES (1, 2), (3, 4)) AS t(a,b)});
50
e0eb8d26 51($sql) = $sqlac->update({
52 update => 'employees',
53 set => { sales_count => { sales_count => { '+', \1 } } },
54 from => 'accounts',
55 where => {
56 'accounts.name' => { '=' => \"'Acme Corporation'" },
57 'employees.id' => { -ident => 'accounts.sales_person' },
58 }
59});
60
61is_same_sql(
62 $sql,
63 q{UPDATE employees SET sales_count = sales_count + 1 FROM accounts
64 WHERE accounts.name = 'Acme Corporation'
65 AND employees.id = accounts.sales_person
66 }
67);
68
69($sql) = $sqlac->update({
70 update => [ qw(tab1 tab2) ],
71 set => {
72 'tab1.column1' => { -ident => 'value1' },
73 'tab1.column2' => { -ident => 'value2' },
74 },
75 where => { 'tab1.id' => { -ident => 'tab2.id' } },
76});
77
78is_same_sql(
79 $sql,
80 q{UPDATE tab1, tab2 SET tab1.column1 = value1, tab1.column2 = value2
81 WHERE tab1.id = tab2.id}
82);
83
84is_same_sql(
85 $sqlac->delete({
86 from => 'x',
87 using => 'y',
88 where => { 'x.id' => { -ident => 'y.x_id' } }
89 }),
90 q{DELETE FROM x USING y WHERE x.id = y.x_id}
91);
92
93is_same_sql(
94 $sqlac->select({
95 select => [ 'x.*', 'y.*' ],
96 from => [ 'x', -join => [ 'y', using => 'y_id' ] ],
97 }),
98 q{SELECT x.*, y.* FROM x JOIN y USING (y_id)},
99);
100
1b0749b8 101is_same_sql(
102 $sqlac->select({
103 select => 'x.*',
104 from => [ { -select => { select => '*', from => 'y' } }, -as => 'x' ],
105 }),
106 q{SELECT x.* FROM (SELECT * FROM y) AS x},
107);
108
f8d50921 109is_same_sql(
110 $sqlac->insert({
111 into => 'foo',
93253a11 112 select => { select => '*', from => 'bar' }
f8d50921 113 }),
114 q{INSERT INTO foo SELECT * FROM bar}
115);
116
93253a11 117($sql, @bind) = $sqlac->insert({
118 into => 'eh',
119 rowvalues => [ [ 1, 2 ], [ 3, 4 ], [ 5, 6 ] ]
120});
121
122is_same_sql_bind(
123 $sql, \@bind,
124 q{INSERT INTO eh VALUES (?, ?), (?, ?), (?, ?)},
125 [ 1..6 ],
126);
127
7250aa13 128is_same_sql(
129 $sqlac->select({
130 select => '*',
131 from => 'foo',
132 where => { -not_exists => {
133 -select => {
134 select => \1,
135 from => 'bar',
136 where => { 'foo.id' => { -ident => 'bar.foo_id' } }
137 },
138 } },
139 }),
140 q{SELECT * FROM foo
141 WHERE NOT EXISTS (SELECT 1 FROM bar WHERE foo.id = bar.foo_id)},
142);
143
abf13001 144is_same_sql(
145 $sqlac->select({
146 select => '*',
147 from => 'foo',
148 where => { id => {
149 '=' => { -select => { select => { -max => 'id' }, from => 'foo' } }
150 } },
151 }),
152 q{SELECT * FROM foo WHERE id = (SELECT MAX(id) FROM foo)},
153);
154
68525dce 155{
34570093 156 my $sqlac = $sqlac->clone
157 ->clauses_of(
158 select => (
159 $sqlac->clauses_of('select'),
160 qw(limit offset),
161 )
162 );
68525dce 163
164 ($sql, @bind) = $sqlac->select({
165 select => '*',
166 from => 'foo',
167 limit => 10,
168 offset => 20,
169 });
170
171 is_same_sql_bind(
172 $sql, \@bind,
173 q{SELECT * FROM foo LIMIT ? OFFSET ?}, [ 10, 20 ]
174 );
175}
176
d175037f 177$sql = $sqlac->select({
75d47dd0 178 select => { -as => [ \1, 'x' ] },
179 union => { -select => { select => { -as => [ \2, 'x' ] } } },
2b0b3d43 180 order_by => { -desc => 'x' },
181});
182
183is_same_sql(
184 $sql,
185 q{(SELECT 1 AS x) UNION (SELECT 2 AS x) ORDER BY x DESC},
186);
187
d175037f 188$sql = $sqlac->select({
189 select => '*',
190 from => 'foo',
191 except => { -select => { select => '*', from => 'foo_exclusions' } }
192});
193
194is_same_sql(
195 $sql,
196 q{(SELECT * FROM foo) EXCEPT (SELECT * FROM foo_exclusions)},
197);
198
1ba47f38 199$sql = $sqlac->select({
200 with => [ foo => { -select => { select => \1 } } ],
201 select => '*',
202 from => 'foo'
203});
204
205is_same_sql(
206 $sql,
541af914 207 q{WITH foo AS (SELECT 1) SELECT * FROM foo},
1ba47f38 208);
209
f9f1fdcd 210$sql = $sqlac->update({
211 _ => [ 'tree_table', -join => {
212 to => { -select => {
213 with_recursive => [
214 [ tree_with_path => qw(id parent_id path) ],
215 { -select => {
216 _ => [
217 qw(id parent_id),
218 { -as => [
219 { -cast => { -as => [ id => char => 255 ] } },
220 'path'
221 ] },
222 ],
223 from => 'tree_table',
224 where => { parent_id => undef },
225 union_all => {
226 -select => {
227 _ => [ qw(t.id t.parent_id),
228 { -as => [
229 { -concat => [ 'r.path', \q{'/'}, 't.id' ] },
230 'path',
231 ] },
232 ],
233 from => [
234 tree_table => -as => t =>
235 -join => {
236 to => 'tree_with_path',
237 as => 'r',
238 on => { 't.parent_id' => 'r.id' },
239 },
240 ],
241 } },
242 } },
243 ],
244 select => '*',
245 from => 'tree_with_path'
246 } },
247 as => 'tree',
248 on => { 'tree.id' => 'tree_with_path.id' },
249 } ],
250 set => { path => { -ident => [ qw(tree path) ] } },
251});
252
253is_same_sql(
254 $sql,
255 q{
256 UPDATE tree_table JOIN (
541af914 257 WITH RECURSIVE tree_with_path(id, parent_id, path) AS (
f9f1fdcd 258 (
259 SELECT id, parent_id, CAST(id AS char(255)) AS path
260 FROM tree_table
261 WHERE parent_id IS NULL
262 )
263 UNION ALL
264 (
265 SELECT t.id, t.parent_id, CONCAT(r.path, '/', t.id) AS path
266 FROM tree_table AS t
267 JOIN tree_with_path AS r ON t.parent_id = r.id
268 )
541af914 269 )
f9f1fdcd 270 SELECT * FROM tree_with_path
271 ) AS tree
272 ON tree.id = tree_with_path.id
273 SET path = tree.path
274 },
275);
276
2329b891 277
278($sql, @bind) = $sqlac->insert({
279 with => [
280 faculty => {
281 -select => {
282 _ => [qw /p.person p.email/],
283 from => [ person => -as => 'p' ],
284 where => {
285 'p.person_type' => 'faculty',
286 'p.person_status' => { '!=' => 'pending' },
287 'p.default_license_id' => undef,
288 },
289 },
290 },
291 grandfather => {
292 -insert => {
293 into => 'license',
294 fields => [ qw(kind expires_on valid_from) ],
295 select => {
296 select => [\(qw('grandfather' '2017-06-30' '2016-07-01'))],
297 from => 'faculty',
298 },
299 returning => 'license_id',
300 }
301 },
302 ],
303 into => 'license_person',
6d3bcf02 304 fields => [ qw(person_id license_id) ],
2329b891 305 select => {
306 _ => ['person_id', 'license_id'],
307 from => ['grandfather'],
308 where => {
309 'a.index' => { -ident => 'b.index' },
310 },
311 },
312});
313
314is_same_sql_bind(
315 $sql, \@bind,
316 q{
317 WITH faculty AS (
318 SELECT p.person, p.email FROM person AS p
319 WHERE (
320 p.default_license_id IS NULL
321 AND p.person_status != ?
322 AND p.person_type = ?
323 )
324 ), grandfather AS (
325 INSERT INTO license (kind, expires_on, valid_from)
326 SELECT 'grandfather', '2017-06-30', '2016-07-01'
327 FROM faculty RETURNING license_id
6d3bcf02 328 ) INSERT INTO license_person (person_id, license_id)
2329b891 329 SELECT person_id, license_id FROM grandfather WHERE a.index = b.index
330 },
331 [ qw(pending faculty) ],
332);
333
b1904bd5 334
335($sql, @bind) = $sqlac->delete({
336 with => [
337 instructors => {
338 -select => {
339 _ => [qw/p.person_id email default_license_id/],
340 from => [
341 person => -as => 'p',
342 -join => {
343 to => 'license_person',
344 as => 'lp',
345 on => { 'lp.person_id' => 'p.person_id' },
346 },
347 -join => {
348 to => 'license',
349 as => 'l',
350 on => { 'l.license_id' => 'lp.license_id' },
351 },
352 ],
353 where => {
354 'p.person_type' => 'faculty',
355 'p.person_status' => { '!=' => 'pending' },
356 'l.kind' => 'pending',
357 },
358 group_by => [qw/ p.person_id /],
359 having => { '>' => [ { -count => 'l.license_id' }, 1 ] }
360 },
361 },
362 deletable_licenses => {
363 -select => {
364 _ => [qw/lp.ctid lp.person_id lp.license_id/],
365 from => [
366 instructors => -as => 'i',
367 -join => {
368 to => 'license_person',
369 as => 'lp',
370 on => { 'lp.person_id' => 'i.person_id' },
371 },
372 -join => {
373 to => 'license',
374 as => 'l',
375 on => { 'l.license_id' => 'lp.license_id' },
376 },
377 ],
378 where => {
379 'lp.license_id' => {
380 '<>' => {-ident => 'i.default_license_id'}
381 },
382 'l.kind' => 'pending',
383 },
384 },
385 },
386 ],
387 from => 'license_person',
388 where => {
389 ctid => { -in =>
390 {
391 -select => {
392 _ => ['ctid'],
393 from => 'deletable_licenses',
394 }
395 }
396 }
397 }
398});
399
400is_same_sql_bind(
401 $sql, \@bind,
402 q{
403 with instructors as (
404 select p.person_id, email, default_license_id
405 from person as p
406 join license_person as lp on lp.person_id = p.person_id
407 join license as l on l.license_id = lp.license_id
408 where l.kind = ?
409 AND p.person_status != ?
410 AND p.person_type = ?
411 group by p.person_id
412 having COUNT(l.license_id) > ?),
413 deletable_licenses as (
414 select lp.ctid, lp.person_id, lp.license_id
415 from instructors as i
416 join license_person as lp on lp.person_id = i.person_id
417 join license as l on l.license_id = lp.license_id
418 where l.kind = ?
419 and lp.license_id <> i.default_license_id
420 )
421 delete from license_person
422 where ctid IN (
423 (select ctid from deletable_licenses)
424 )
425 },
426 [qw(
427 pending pending faculty 1 pending
428 )]
429);
430
48b71e3b 431($sql, @bind) = $sqlac->update({
432 _ => ['survey'],
433 set => {
434 license_id => { -ident => 'info.default_license_id' },
435 },
436 from => [
437 -select => {
438 select => [qw( s.survey_id p.default_license_id p.person_id)],
439 from => [
440 person => -as => 'p',
441 -join => {
442 to => 'class',
443 as => 'c',
444 on => { 'c.faculty_id' => 'p.person_id' },
445 },
446 -join => {
447 to => 'survey',
448 as => 's',
449 on => { 's.class_id' => 'c.class_id' },
450 },
451 ],
452 where => { 'p.institution_id' => { -value => 15031 } },
453 },
454 -as => 'info',
455 ],
456 where => {
457 'info.survey_id' => { -ident => 'survey.survey_id' },
458 }
459});
460
461is_same_sql_bind(
462 $sql, \@bind,
463 q{
464 update survey
465 set license_id=info.default_license_id
466 from (
467 select s.survey_id, p.default_license_id, p.person_id
468 from person AS p
469 join class AS c on c.faculty_id = p.person_id
470 join survey AS s on s.class_id = c.class_id
471 where p.institution_id = ?
472 ) AS info
473 where info.survey_id=survey.survey_id
474 },
475 [qw(
476 15031
477 )]
478);
479
480
481
c42752fc 482done_testing;