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