wrap expander and expander list
[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
7250aa13 7my $sqlac = SQL::Abstract::ExtraClauses->new(unknown_unop_always_func => 1);
c42752fc 8
9my ($sql, @bind) = $sqlac->select({
7250aa13 10 select => [ qw(artist.id artist.name), { -json_agg => 'cd' } ],
c42752fc 11 from => [
b99e9a14 12 { artists => { -as => 'artist' } },
13 -join => [ cds => as => 'cd' => on => { 'cd.artist_id' => 'artist.id' } ],
c42752fc 14 ],
15 where => { 'artist.genres', => { '@>', { -value => [ 'Rock' ] } } },
16 order_by => 'artist.name',
17 group_by => 'artist.id',
7250aa13 18 having => { '>' => [ { -count => 'cd.id' }, 3 ] }
c42752fc 19});
20
21is_same_sql_bind(
22 $sql, \@bind,
23 q{
24 SELECT artist.id, artist.name, JSON_AGG(cd)
b99e9a14 25 FROM artists AS artist JOIN cds AS cd ON cd.artist_id = artist.id
c42752fc 26 WHERE artist.genres @> ?
c42752fc 27 GROUP BY artist.id
28 HAVING COUNT(cd.id) > ?
2b0b3d43 29 ORDER BY artist.name
c42752fc 30 },
31 [ [ 'Rock' ], 3 ]
32);
33
4a2c263b 34($sql) = $sqlac->select({
35 select => [ 'a' ],
36 from => [ { -values => [ [ 1, 2 ], [ 3, 4 ] ] }, -as => [ qw(t a b) ] ],
37});
38
39is_same_sql($sql, q{SELECT a FROM (VALUES (1, 2), (3, 4)) AS t(a,b)});
40
e0eb8d26 41($sql) = $sqlac->update({
42 update => 'employees',
43 set => { sales_count => { sales_count => { '+', \1 } } },
44 from => 'accounts',
45 where => {
46 'accounts.name' => { '=' => \"'Acme Corporation'" },
47 'employees.id' => { -ident => 'accounts.sales_person' },
48 }
49});
50
51is_same_sql(
52 $sql,
53 q{UPDATE employees SET sales_count = sales_count + 1 FROM accounts
54 WHERE accounts.name = 'Acme Corporation'
55 AND employees.id = accounts.sales_person
56 }
57);
58
59($sql) = $sqlac->update({
60 update => [ qw(tab1 tab2) ],
61 set => {
62 'tab1.column1' => { -ident => 'value1' },
63 'tab1.column2' => { -ident => 'value2' },
64 },
65 where => { 'tab1.id' => { -ident => 'tab2.id' } },
66});
67
68is_same_sql(
69 $sql,
70 q{UPDATE tab1, tab2 SET tab1.column1 = value1, tab1.column2 = value2
71 WHERE tab1.id = tab2.id}
72);
73
74is_same_sql(
75 $sqlac->delete({
76 from => 'x',
77 using => 'y',
78 where => { 'x.id' => { -ident => 'y.x_id' } }
79 }),
80 q{DELETE FROM x USING y WHERE x.id = y.x_id}
81);
82
83is_same_sql(
84 $sqlac->select({
85 select => [ 'x.*', 'y.*' ],
86 from => [ 'x', -join => [ 'y', using => 'y_id' ] ],
87 }),
88 q{SELECT x.*, y.* FROM x JOIN y USING (y_id)},
89);
90
1b0749b8 91is_same_sql(
92 $sqlac->select({
93 select => 'x.*',
94 from => [ { -select => { select => '*', from => 'y' } }, -as => 'x' ],
95 }),
96 q{SELECT x.* FROM (SELECT * FROM y) AS x},
97);
98
f8d50921 99is_same_sql(
100 $sqlac->insert({
101 into => 'foo',
93253a11 102 select => { select => '*', from => 'bar' }
f8d50921 103 }),
104 q{INSERT INTO foo SELECT * FROM bar}
105);
106
93253a11 107($sql, @bind) = $sqlac->insert({
108 into => 'eh',
109 rowvalues => [ [ 1, 2 ], [ 3, 4 ], [ 5, 6 ] ]
110});
111
112is_same_sql_bind(
113 $sql, \@bind,
114 q{INSERT INTO eh VALUES (?, ?), (?, ?), (?, ?)},
115 [ 1..6 ],
116);
117
7250aa13 118is_same_sql(
119 $sqlac->select({
120 select => '*',
121 from => 'foo',
122 where => { -not_exists => {
123 -select => {
124 select => \1,
125 from => 'bar',
126 where => { 'foo.id' => { -ident => 'bar.foo_id' } }
127 },
128 } },
129 }),
130 q{SELECT * FROM foo
131 WHERE NOT EXISTS (SELECT 1 FROM bar WHERE foo.id = bar.foo_id)},
132);
133
abf13001 134is_same_sql(
135 $sqlac->select({
136 select => '*',
137 from => 'foo',
138 where => { id => {
139 '=' => { -select => { select => { -max => 'id' }, from => 'foo' } }
140 } },
141 }),
142 q{SELECT * FROM foo WHERE id = (SELECT MAX(id) FROM foo)},
143);
144
68525dce 145{
34570093 146 my $sqlac = $sqlac->clone
147 ->clauses_of(
148 select => (
149 $sqlac->clauses_of('select'),
150 qw(limit offset),
151 )
152 );
68525dce 153
154 ($sql, @bind) = $sqlac->select({
155 select => '*',
156 from => 'foo',
157 limit => 10,
158 offset => 20,
159 });
160
161 is_same_sql_bind(
162 $sql, \@bind,
163 q{SELECT * FROM foo LIMIT ? OFFSET ?}, [ 10, 20 ]
164 );
165}
166
d175037f 167$sql = $sqlac->select({
75d47dd0 168 select => { -as => [ \1, 'x' ] },
169 union => { -select => { select => { -as => [ \2, 'x' ] } } },
2b0b3d43 170 order_by => { -desc => 'x' },
171});
172
173is_same_sql(
174 $sql,
175 q{(SELECT 1 AS x) UNION (SELECT 2 AS x) ORDER BY x DESC},
176);
177
d175037f 178$sql = $sqlac->select({
179 select => '*',
180 from => 'foo',
181 except => { -select => { select => '*', from => 'foo_exclusions' } }
182});
183
184is_same_sql(
185 $sql,
186 q{(SELECT * FROM foo) EXCEPT (SELECT * FROM foo_exclusions)},
187);
188
1ba47f38 189$sql = $sqlac->select({
190 with => [ foo => { -select => { select => \1 } } ],
191 select => '*',
192 from => 'foo'
193});
194
195is_same_sql(
196 $sql,
541af914 197 q{WITH foo AS (SELECT 1) SELECT * FROM foo},
1ba47f38 198);
199
f9f1fdcd 200$sql = $sqlac->update({
201 _ => [ 'tree_table', -join => {
202 to => { -select => {
203 with_recursive => [
204 [ tree_with_path => qw(id parent_id path) ],
205 { -select => {
206 _ => [
207 qw(id parent_id),
208 { -as => [
209 { -cast => { -as => [ id => char => 255 ] } },
210 'path'
211 ] },
212 ],
213 from => 'tree_table',
214 where => { parent_id => undef },
215 union_all => {
216 -select => {
217 _ => [ qw(t.id t.parent_id),
218 { -as => [
219 { -concat => [ 'r.path', \q{'/'}, 't.id' ] },
220 'path',
221 ] },
222 ],
223 from => [
224 tree_table => -as => t =>
225 -join => {
226 to => 'tree_with_path',
227 as => 'r',
228 on => { 't.parent_id' => 'r.id' },
229 },
230 ],
231 } },
232 } },
233 ],
234 select => '*',
235 from => 'tree_with_path'
236 } },
237 as => 'tree',
238 on => { 'tree.id' => 'tree_with_path.id' },
239 } ],
240 set => { path => { -ident => [ qw(tree path) ] } },
241});
242
243is_same_sql(
244 $sql,
245 q{
246 UPDATE tree_table JOIN (
541af914 247 WITH RECURSIVE tree_with_path(id, parent_id, path) AS (
f9f1fdcd 248 (
249 SELECT id, parent_id, CAST(id AS char(255)) AS path
250 FROM tree_table
251 WHERE parent_id IS NULL
252 )
253 UNION ALL
254 (
255 SELECT t.id, t.parent_id, CONCAT(r.path, '/', t.id) AS path
256 FROM tree_table AS t
257 JOIN tree_with_path AS r ON t.parent_id = r.id
258 )
541af914 259 )
f9f1fdcd 260 SELECT * FROM tree_with_path
261 ) AS tree
262 ON tree.id = tree_with_path.id
263 SET path = tree.path
264 },
265);
266
c42752fc 267done_testing;