4 use SQL::Abstract::Test import => [ qw(is_same_sql_bind is_same_sql) ];
5 use SQL::Abstract::ExtraClauses;
7 my $sqlac = SQL::Abstract::ExtraClauses->new(unknown_unop_always_func => 1);
10 [ $sqlac->statement_list ],
11 [ sort qw(select update insert delete) ],
14 my ($sql, @bind) = $sqlac->select({
15 select => [ qw(artist.id artist.name), { -json_agg => 'cd' } ],
17 { artists => { -as => 'artist' } },
18 -join => [ cds => as => 'cd' => on => { 'cd.artist_id' => 'artist.id' } ],
20 where => { 'artist.genres', => { '@>', { -value => [ 'Rock' ] } } },
21 order_by => 'artist.name',
22 group_by => 'artist.id',
23 having => { '>' => [ { -count => 'cd.id' }, 3 ] }
29 SELECT artist.id, artist.name, JSON_AGG(cd)
30 FROM artists AS artist JOIN cds AS cd ON cd.artist_id = artist.id
31 WHERE artist.genres @> ?
33 HAVING COUNT(cd.id) > ?
39 ($sql) = $sqlac->select({
41 from => [ { -values => [ [ 1, 2 ], [ 3, 4 ] ] }, -as => [ qw(t a b) ] ],
44 is_same_sql($sql, q{SELECT a FROM (VALUES (1, 2), (3, 4)) AS t(a,b)});
46 ($sql) = $sqlac->update({
47 update => 'employees',
48 set => { sales_count => { sales_count => { '+', \1 } } },
51 'accounts.name' => { '=' => \"'Acme Corporation'" },
52 'employees.id' => { -ident => 'accounts.sales_person' },
58 q{UPDATE employees SET sales_count = sales_count + 1 FROM accounts
59 WHERE accounts.name = 'Acme Corporation'
60 AND employees.id = accounts.sales_person
64 ($sql) = $sqlac->update({
65 update => [ qw(tab1 tab2) ],
67 'tab1.column1' => { -ident => 'value1' },
68 'tab1.column2' => { -ident => 'value2' },
70 where => { 'tab1.id' => { -ident => 'tab2.id' } },
75 q{UPDATE tab1, tab2 SET tab1.column1 = value1, tab1.column2 = value2
76 WHERE tab1.id = tab2.id}
83 where => { 'x.id' => { -ident => 'y.x_id' } }
85 q{DELETE FROM x USING y WHERE x.id = y.x_id}
90 select => [ 'x.*', 'y.*' ],
91 from => [ 'x', -join => [ 'y', using => 'y_id' ] ],
93 q{SELECT x.*, y.* FROM x JOIN y USING (y_id)},
99 from => [ { -select => { select => '*', from => 'y' } }, -as => 'x' ],
101 q{SELECT x.* FROM (SELECT * FROM y) AS x},
107 select => { select => '*', from => 'bar' }
109 q{INSERT INTO foo SELECT * FROM bar}
112 ($sql, @bind) = $sqlac->insert({
114 rowvalues => [ [ 1, 2 ], [ 3, 4 ], [ 5, 6 ] ]
119 q{INSERT INTO eh VALUES (?, ?), (?, ?), (?, ?)},
127 where => { -not_exists => {
131 where => { 'foo.id' => { -ident => 'bar.foo_id' } }
136 WHERE NOT EXISTS (SELECT 1 FROM bar WHERE foo.id = bar.foo_id)},
144 '=' => { -select => { select => { -max => 'id' }, from => 'foo' } }
147 q{SELECT * FROM foo WHERE id = (SELECT MAX(id) FROM foo)},
151 my $sqlac = $sqlac->clone
154 $sqlac->clauses_of('select'),
159 ($sql, @bind) = $sqlac->select({
168 q{SELECT * FROM foo LIMIT ? OFFSET ?}, [ 10, 20 ]
172 $sql = $sqlac->select({
173 select => { -as => [ \1, 'x' ] },
174 union => { -select => { select => { -as => [ \2, 'x' ] } } },
175 order_by => { -desc => 'x' },
180 q{(SELECT 1 AS x) UNION (SELECT 2 AS x) ORDER BY x DESC},
183 $sql = $sqlac->select({
186 except => { -select => { select => '*', from => 'foo_exclusions' } }
191 q{(SELECT * FROM foo) EXCEPT (SELECT * FROM foo_exclusions)},
194 $sql = $sqlac->select({
195 with => [ foo => { -select => { select => \1 } } ],
202 q{WITH foo AS (SELECT 1) SELECT * FROM foo},
205 $sql = $sqlac->update({
206 _ => [ 'tree_table', -join => {
209 [ tree_with_path => qw(id parent_id path) ],
214 { -cast => { -as => [ id => char => 255 ] } },
218 from => 'tree_table',
219 where => { parent_id => undef },
222 _ => [ qw(t.id t.parent_id),
224 { -concat => [ 'r.path', \q{'/'}, 't.id' ] },
229 tree_table => -as => t =>
231 to => 'tree_with_path',
233 on => { 't.parent_id' => 'r.id' },
240 from => 'tree_with_path'
243 on => { 'tree.id' => 'tree_with_path.id' },
245 set => { path => { -ident => [ qw(tree path) ] } },
251 UPDATE tree_table JOIN (
252 WITH RECURSIVE tree_with_path(id, parent_id, path) AS (
254 SELECT id, parent_id, CAST(id AS char(255)) AS path
256 WHERE parent_id IS NULL
260 SELECT t.id, t.parent_id, CONCAT(r.path, '/', t.id) AS path
262 JOIN tree_with_path AS r ON t.parent_id = r.id
265 SELECT * FROM tree_with_path
267 ON tree.id = tree_with_path.id