alnk once again points out that mst is an idiot
[scpubgit/Q-Branch.git] / lib / SQL / Abstract / Plugin / ExtraClauses.pm
CommitLineData
d10d5b94 1package SQL::Abstract::Plugin::ExtraClauses;
1ff9018c 2
df5d0507 3use Moo;
4
d10d5b94 5with 'SQL::Abstract::Role::Plugin';
ec49a2e1 6
7sub register_extensions {
8 my ($self, $sqla) = @_;
f1c52c0c 9
ad078c71 10 my @clauses = $sqla->clauses_of('select');
2b0b3d43 11 my @before_setop;
12 CLAUSE: foreach my $idx (0..$#clauses) {
13 if ($clauses[$idx] eq 'order_by') {
14 @before_setop = @clauses[0..$idx-1];
15 splice(@clauses, $idx, 0, qw(setop group_by having));
16 last CLAUSE;
17 }
18 }
f1c52c0c 19
2b0b3d43 20 die "Huh?" unless @before_setop;
4be5ded3 21 $sqla->clauses_of(select => @clauses);
58ebc7fa 22
ad078c71 23 $sqla->clauses_of(update => sub {
ee706e89 24 my ($self, @clauses) = @_;
25 splice(@clauses, 2, 0, 'from');
26 @clauses;
27 });
28
ad078c71 29 $sqla->clauses_of(delete => sub {
ee706e89 30 my ($self, @clauses) = @_;
31 splice(@clauses, 1, 0, 'using');
32 @clauses;
33 });
34
4be5ded3 35 $self->register(
f1c52c0c 36 (map +(
37 "${_}er" => [
38 do {
39 my $x = $_;
40 (map +($_ => "_${x}_${_}"), qw(join from_list alias))
41 }
42 ]
43 ), qw(expand render)),
44 binop_expander => [ as => '_expand_op_as' ],
45 renderer => [ as => '_render_as' ],
46 expander => [ cast => '_expand_cast' ],
4be5ded3 47 clause_expanders => [
f1c52c0c 48 'select.group_by'
8480fb63 49 => sub { $_[0]->expand_expr({ -list => $_[2] }, -ident) },
f1c52c0c 50 'select.having'
51 => sub { $_[0]->expand_expr($_[2]) },
4be5ded3 52 'update.from' => '_expand_from_list',
f1c52c0c 53 "update.target", '_expand_update_clause_target',
54 "update.update", '_expand_update_clause_target',
4be5ded3 55 'delete.using' => '_expand_from_list',
56 'insert.rowvalues' => sub {
57 +(from => $_[0]->expand_expr({ -values => $_[2] }));
58 },
59 'insert.select' => sub {
60 +(from => $_[0]->expand_expr({ -select => $_[2] }));
61 },
62 ],
58ebc7fa 63 );
26994fdd 64
116bc0b6 65 $sqla->expander(old_from => $sqla->clause_expander('select.from'));
66 $sqla->wrap_clause_expander('select.from', sub {
67 my ($orig) = @_;
68 sub {
69 my ($sqla, undef, $args) = @_;
70 if (ref($args) eq 'HASH') {
71 return $self->_expand_from_list(undef, $args);
72 }
73 if (
74 ref($args) eq 'ARRAY'
75 and grep { !ref($_) and $_ =~ /^-/ } @$args
76 ) {
77 return $self->_expand_from_list(undef, $args);
78 }
79 return $sqla->$orig(undef, $args);
80 }
81 });
82
2b0b3d43 83 # set ops
ad078c71 84 $sqla->wrap_expander(select => sub {
c671eba6 85 $self->cb('_expand_select', $_[0], \@before_setop);
3f9899e5 86 });
2b0b3d43 87
4be5ded3 88 $self->register(
89 clause_renderer => [
90 'select.setop' => sub { $_[0]->render_aqt($_[2]) }
91 ],
de3eeaea 92 expander => [
93 map +($_ => '_expand_setop', "${_}_all" => '_expand_setop'), qw(union intersect except) ],
4be5ded3 94 renderer => [ map +($_ => '_render_setop'), qw(union intersect except) ],
e2db8228 95 );
2b0b3d43 96
41086177 97 my $setop_expander = $self->cb('_expand_clause_setop');
f61bfd7b 98
ad078c71 99 $sqla->clause_expanders(
f61bfd7b 100 map +($_ => $setop_expander),
101 map "select.${_}",
102 map +($_, "${_}_all", "${_}_distinct"),
103 qw(union intersect except)
104 );
d175037f 105
4be5ded3 106 foreach my $stmt (qw(select insert update delete)) {
ad078c71 107 $sqla->clauses_of($stmt => 'with', $sqla->clauses_of($stmt));
4be5ded3 108 $self->register(
109 clause_expanders => [
110 "${stmt}.with" => '_expand_with',
111 "${stmt}.with_recursive" => '_expand_with',
112 ],
113 clause_renderer => [ "${stmt}.with" => '_render_with' ],
114 );
a97ecd95 115 }
2f4717ad 116
ad078c71 117 return $sqla;
1ff9018c 118}
119
c671eba6 120sub _expand_select {
093442c8 121 my ($self, $orig, $before_setop, @args) = @_;
122 my $exp = $self->sqla->$orig(@args);
c671eba6 123 return $exp unless my $setop = (my $sel = $exp->{-select})->{setop};
124 if (my @keys = grep $sel->{$_}, @$before_setop) {
125 my %inner; @inner{@keys} = delete @{$sel}{@keys};
126 unshift @{(values(%$setop))[0]{queries}},
127 { -select => \%inner };
128 }
129 return $exp;
130}
131
7741b7ad 132sub _expand_from_list {
133 my ($self, undef, $args) = @_;
134 if (ref($args) eq 'HASH') {
38e67490 135 return $args if $args->{-from_list};
7741b7ad 136 return { -from_list => [ $self->expand_expr($args) ] };
137 }
138 my @list;
86a6ebf4 139 my @args = ref($args) eq 'ARRAY' ? @$args : ($args);
7741b7ad 140 while (my $entry = shift @args) {
b99e9a14 141 if (!ref($entry) and $entry =~ /^-(.*)/) {
142 if ($1 eq 'as') {
143 $list[-1] = $self->expand_expr({ -as => [
144 $list[-1], map +(ref($_) eq 'ARRAY' ? @$_ : $_), shift(@args)
145 ]});
146 next;
147 }
7741b7ad 148 $entry = { $entry => shift @args };
149 }
150 my $aqt = $self->expand_expr($entry, -ident);
151 if ($aqt->{-join} and not $aqt->{-join}{from}) {
152 $aqt->{-join}{from} = pop @list;
153 }
154 push @list, $aqt;
155 }
09742461 156 return $list[0] if @list == 1;
7741b7ad 157 return { -from_list => \@list };
158}
159
160sub _expand_join {
161 my ($self, undef, $args) = @_;
162 my %proto = (
163 ref($args) eq 'HASH'
164 ? %$args
d36cb439 165 : (to => @$args)
7741b7ad 166 );
b99e9a14 167 if (my $as = delete $proto{as}) {
ca97398a 168 $proto{to} = $self->expand_expr(
169 { -as => [ { -from_list => $proto{to} }, $as ] }
170 );
b99e9a14 171 }
e0eb8d26 172 if (defined($proto{using}) and ref(my $using = $proto{using}) ne 'HASH') {
13c99dad 173 $proto{using} = [
e0eb8d26 174 map [ $self->expand_expr($_, -ident) ],
175 ref($using) eq 'ARRAY' ? @$using: $using
13c99dad 176 ];
e0eb8d26 177 }
ca97398a 178 my %ret = (
179 type => delete $proto{type},
180 to => $self->expand_expr({ -from_list => delete $proto{to} }, -ident)
ca97398a 181 );
182 %ret = (%ret,
183 map +($_ => $self->expand_expr($proto{$_}, -ident)),
184 sort keys %proto
185 );
7741b7ad 186 return +{ -join => \%ret };
187}
188
189sub _render_from_list {
a01911a2 190 my ($self, undef, $list) = @_;
a1f8b6ef 191 return $self->join_query_parts(', ', @$list);
7741b7ad 192}
193
194sub _render_join {
a01911a2 195 my ($self, undef, $args) = @_;
7741b7ad 196
197 my @parts = (
412f9efe 198 $args->{from},
1601bb47 199 { -keyword => join '_', ($args->{type}||()), 'join' },
ca97398a 200 (map +($_->{-ident} || $_->{-as}
201 ? $_
202 : ('(', $self->render_aqt($_, 1), ')')),
09742461 203 map +(@{$_->{-from_list}||[]} == 1 ? $_->{-from_list}[0] : $_),
204 $args->{to}
ca97398a 205 ),
7741b7ad 206 ($args->{on} ? (
1601bb47 207 { -keyword => 'on' },
412f9efe 208 $args->{on},
7741b7ad 209 ) : ()),
210 ($args->{using} ? (
1601bb47 211 { -keyword => 'using' },
13c99dad 212 '(', $args->{using}, ')',
7741b7ad 213 ) : ()),
214 );
0236f122 215 return $self->join_query_parts(' ', @parts);
7741b7ad 216}
217
b99e9a14 218sub _expand_op_as {
219 my ($self, undef, $vv, $k) = @_;
984db0d7 220 my @vv = (ref($vv) eq 'ARRAY' ? @$vv : $vv);
984db0d7 221 my $ik = $self->expand_expr($k, -ident);
4979c509 222 return +{ -as => [ $ik, $self->expand_expr($vv[0], -ident) ] }
984db0d7 223 if @vv == 1 and ref($vv[0]) eq 'HASH';
224
225 my @as = map $self->expand_expr($_, -ident), @vv;
4979c509 226 return { -as => [ $ik, $self->expand_expr({ -alias => \@as }) ] };
b99e9a14 227}
228
229sub _render_as {
a01911a2 230 my ($self, undef, $args) = @_;
984db0d7 231 my ($thing, $alias) = @$args;
0236f122 232 return $self->join_query_parts(
ac7992be 233 ' ',
984db0d7 234 $thing,
1601bb47 235 { -keyword => 'as' },
984db0d7 236 $alias,
1ba47f38 237 );
238}
239
240sub _render_alias {
984db0d7 241 my ($self, undef, $args) = @_;
1ba47f38 242 my ($as, @cols) = @$args;
243 return (@cols
0236f122 244 ? $self->join_query_parts('',
a1f8b6ef 245 $as,
3f312d2e 246 '(',
247 $self->join_query_parts(
248 ', ',
249 @cols
250 ),
251 ')',
1ba47f38 252 )
253 : $self->render_aqt($as)
b99e9a14 254 );
255}
256
f9f1fdcd 257sub _expand_update_clause_target {
fe8b493f 258 my ($self, undef, $target) = @_;
f9f1fdcd 259 +(target => $self->_expand_from_list(undef, $target));
260}
261
2f4717ad 262sub _expand_cast {
263 my ($self, undef, $thing) = @_;
264 return { -func => [ cast => $thing ] } if ref($thing) eq 'HASH';
265 my ($cast, $to) = @{$thing};
266 +{ -func => [ cast => { -as => [
267 $self->expand_expr($cast),
268 $self->expand_expr($to, -ident),
269 ] } ] };
270}
271
272sub _expand_alias {
273 my ($self, undef, $args) = @_;
274 if (ref($args) eq 'HASH' and my $alias = $args->{-alias}) {
275 $args = $alias;
276 }
4979c509 277 my @parts = map $self->expand_expr($_, -ident),
278 ref($args) eq 'ARRAY' ? @{$args} : $args;
279 return $parts[0] if @parts == 1;
280 return { -alias => \@parts };
2f4717ad 281}
282
283sub _expand_with {
284 my ($self, $name, $with) = @_;
285 my (undef, $type) = split '_', $name;
286 if (ref($with) eq 'HASH') {
287 return +{
288 %$with,
289 queries => [
290 map +[
291 $self->expand_expr({ -alias => $_->[0] }, -ident),
292 $self->expand_expr($_->[1]),
293 ], @{$with->{queries}}
294 ]
295 }
296 }
297 my @with = @$with;
298 my @exp;
299 while (my ($alias, $query) = splice @with, 0, 2) {
300 push @exp, [
301 $self->expand_expr({ -alias => $alias }, -ident),
302 $self->expand_expr($query)
303 ];
304 }
305 return +(with => { ($type ? (type => $type) : ()), queries => \@exp });
306}
307
308sub _render_with {
309 my ($self, undef, $with) = @_;
310 my $q_part = $self->join_query_parts(', ',
311 map {
312 my ($alias, $query) = @$_;
313 $self->join_query_parts(' ',
314 $alias,
1601bb47 315 { -keyword => 'as' },
2f4717ad 316 $query,
317 )
318 } @{$with->{queries}}
319 );
320 return $self->join_query_parts(' ',
1601bb47 321 { -keyword => join '_', 'with', ($with->{type}||'') },
2f4717ad 322 $q_part,
323 );
324}
325
51046d0e 326sub _expand_setop {
327 my ($self, $setop, $args) = @_;
de3eeaea 328 my $is_all = $setop =~ s/_all$//;
51046d0e 329 +{ "-${setop}" => {
de3eeaea 330 ($is_all ? (type => 'all') : ()),
331 (ref($args) eq 'ARRAY'
332 ? (queries => [ map $self->expand_expr($_), @$args ])
333 : (
334 %$args,
335 queries => [ map $self->expand_expr($_), @{$args->{queries}} ]
336 )
337 ),
51046d0e 338 } };
339}
340
b5f4a869 341sub _render_setop {
342 my ($self, $setop, $args) = @_;
343 $self->join_query_parts(
1601bb47 344 { -keyword => ' '.join('_', $setop, ($args->{type}||())).' ' },
b5f4a869 345 @{$args->{queries}}
346 );
347}
348
41086177 349sub _expand_clause_setop {
350 my ($self, $setop, $args) = @_;
351 my ($op, $type) = split '_', $setop;
352 +(setop => $self->expand_expr({
353 "-${op}" => {
354 ($type ? (type => $type) : ()),
355 queries => (ref($args) eq 'ARRAY' ? $args : [ $args ])
356 }
357 }));
358}
359
1ff9018c 3601;
3001f097 361
583c7957 362__END__
363
3001f097 364=head1 NAME
365
366SQL::Abstract::ExtraClauses - new/experimental additions to L<SQL::Abstract>
367
368=head1 SYNOPSIS
369
370 my $sqla = SQL::Abstract->new;
371 SQL::Abstract::ExtraClauses->apply_to($sqla);
372
6aac9987 373=head1 WARNING
374
375This module is basically a nursery for things that seem like a good idea
376to live in until we figure out if we were right about that.
377
3001f097 378=head1 METHODS
379
380=head2 apply_to
381
382Applies the plugin to an L<SQL::Abstract> object.
383
f1c52c0c 384=head2 register_extensions
385
386Registers the extensions described below
387
3001f097 388=head2 cb
389
390For plugin authors, creates a callback to call a method on the plugin.
391
f1c52c0c 392=head2 register
393
394For plugin authors, registers callbacks more easily.
395
3001f097 396=head2 sqla
397
398Available only during plugin callback executions, contains the currently
399active L<SQL::Abstract> object.
400
583c7957 401=head1 NODE TYPES
402
403=head2 alias
404
405Represents a table alias. Expands name and column names with ident as default.
406
407 # expr
408 { -alias => [ 't', 'x', 'y', 'z' ] }
409
410 # aqt
411 { -alias => [
412 { -ident => [ 't' ] }, { -ident => [ 'x' ] },
413 { -ident => [ 'y' ] }, { -ident => [ 'z' ] },
414 ] }
415
416 # query
417 t(x, y, z)
418 []
419
420=head2 as
421
422Represents an sql AS. LHS is expanded with ident as default, RHS is treated
423as a list of arguments for the alias node.
424
425 # expr
426 { foo => { -as => 'bar' } }
427
428 # aqt
4979c509 429 { -as => [ { -ident => [ 'foo' ] }, { -ident => [ 'bar' ] } ] }
583c7957 430
431 # query
432 foo AS bar
433 []
434
435 # expr
436 { -as => [ { -select => { _ => 'blah' } }, 't', 'blah' ] }
437
438 # aqt
439 { -as => [
440 { -select =>
441 { select => { -op => [ ',', { -ident => [ 'blah' ] } ] } }
442 },
443 { -alias => [ { -ident => [ 't' ] }, { -ident => [ 'blah' ] } ] },
444 ] }
445
446 # query
447 (SELECT blah) AS t(blah)
448 []
449
450=head2 cast
451
452 # expr
453 { -cast => [ { -ident => 'birthday' }, 'date' ] }
454
455 # aqt
456 { -func => [
457 'cast', {
458 -as => [ { -ident => [ 'birthday' ] }, { -ident => [ 'date' ] } ]
459 },
460 ] }
461
462 # query
463 CAST(birthday AS date)
464 []
465
d36cb439 466=head2 join
467
468If given an arrayref, pretends it was given a hashref with the first
469element of the arrayref as the value for 'to' and the remaining pairs copied.
470
471Given a hashref, the 'as' key is if presented expanded to wrap the 'to'.
472
473If present the 'using' key is expanded as a list of idents.
474
475Known keys are: 'from' (the left hand side), 'type' ('left', 'right', or
476nothing), 'to' (the right hand side), 'on' and 'using'.
477
478 # expr
479 { -join => {
480 from => 'lft',
481 on => { 'lft.bloo' => { '>' => 'rgt.blee' } },
482 to => 'rgt',
483 type => 'left',
484 } }
485
486 # aqt
487 { -join => {
488 from => { -ident => [ 'lft' ] },
489 on => { -op => [
490 '>', { -ident => [ 'lft', 'bloo' ] },
491 { -ident => [ 'rgt', 'blee' ] },
492 ] },
493 to => { -ident => [ 'rgt' ] },
494 type => 'left',
495 } }
496
497 # query
498 lft LEFT JOIN rgt ON lft.bloo > rgt.blee
499 []
500
501=head2 from_list
502
503List of components of the FROM clause; -foo type elements indicate a pair
504with the next element; this is easiest if I show you:
505
506 # expr
507 { -from_list => [
508 't1', -as => 'table_one', -join =>
509 [ 't2', 'on', { 'table_one.x' => 't2.x' } ],
510 ] }
511
512 # aqt
09742461 513 { -join => {
4979c509 514 from =>
515 {
516 -as => [ { -ident => [ 't1' ] }, { -ident => [ 'table_one' ] } ]
517 },
09742461 518 on => { -op => [
519 '=', { -ident => [ 'table_one', 'x' ] },
520 { -ident => [ 't2', 'x' ] },
521 ] },
522 to => { -ident => [ 't2' ] },
523 type => undef,
524 } }
d36cb439 525
526 # query
527 t1 AS table_one JOIN t2 ON table_one.x = t2.x
528 []
529
530Or with using:
531
532 # expr
533 { -from_list =>
534 [ 't1', -as => 'table_one', -join => [ 't2', 'using', [ 'x' ] ] ]
535 }
536
537 # aqt
09742461 538 { -join => {
4979c509 539 from =>
540 {
541 -as => [ { -ident => [ 't1' ] }, { -ident => [ 'table_one' ] } ]
542 },
09742461 543 to => { -ident => [ 't2' ] },
544 type => undef,
545 using =>
546 { -op => [ 'or', { -op => [ 'or', { -ident => [ 'x' ] } ] } ] },
547 } }
d36cb439 548
549 # query
550 t1 AS table_one JOIN t2 USING ( x )
551 []
552
553With oddities:
554
555 # expr
556 { -from_list => [
ca97398a 557 'x', -join =>
558 [ [ 'y', -join => [ 'z', 'type', 'left' ] ], 'type', 'left' ],
d36cb439 559 ] }
560
561 # aqt
09742461 562 { -join => {
563 from => { -ident => [ 'x' ] },
564 to => { -join => {
565 from => { -ident => [ 'y' ] },
566 to => { -ident => [ 'z' ] },
d36cb439 567 type => 'left',
09742461 568 } },
569 type => 'left',
570 } }
d36cb439 571
572 # query
573 x LEFT JOIN ( y LEFT JOIN z )
574 []
575
de3eeaea 576=head2 setops
577
578Expanders are provided for union, union_all, intersect, intersect_all,
579except and except_all, and each takes an arrayref of queries:
580
581 # expr
582 { -union => [
583 { -select => { _ => { -value => 1 } } },
584 { -select => { _ => { -value => 2 } } },
585 ] }
586
587 # aqt
588 { -union => { queries => [
589 { -select =>
590 { select => { -op => [ ',', { -bind => [ undef, 1 ] } ] } }
591 },
592 { -select =>
593 { select => { -op => [ ',', { -bind => [ undef, 2 ] } ] } }
594 },
595 ] } }
596
597 # query
598 (SELECT ?) UNION (SELECT ?)
599 [ 1, 2 ]
600
601 # expr
602 { -union_all => [
603 { -select => { _ => { -value => 1 } } },
604 { -select => { _ => { -value => 2 } } },
605 { -select => { _ => { -value => 1 } } },
606 ] }
607
608 # aqt
609 { -union => {
610 queries => [
611 { -select =>
612 { select => { -op => [ ',', { -bind => [ undef, 1 ] } ] } }
613 },
614 { -select =>
615 { select => { -op => [ ',', { -bind => [ undef, 2 ] } ] } }
616 },
617 { -select =>
618 { select => { -op => [ ',', { -bind => [ undef, 1 ] } ] } }
619 },
620 ],
621 type => 'all',
622 } }
623
624 # query
625 (SELECT ?) UNION ALL (SELECT ?) UNION ALL (SELECT ?)
626 [ 1, 2, 1 ]
627
6aac9987 628=head1 STATEMENT EXTENSIONS
629
630=head2 group by clause for select
631
632Expanded as a list with an ident default:
633
634 # expr
635 { -select => { group_by => [ 'foo', 'bar' ] } }
636
637 # aqt
638 { -select => { group_by =>
639 {
640 -op => [ ',', { -ident => [ 'foo' ] }, { -ident => [ 'bar' ] } ]
641 }
642 } }
643
644 # query
645 GROUP BY foo, bar
646 []
647
648=head2 having clause for select
649
650Basic expr, just like where, given having is pretty much post-group-by
651where clause:
652
653 # expr
654 { -select =>
655 { having => { '>' => [ { -count => { -ident => 'foo' } }, 3 ] } }
656 }
657
658 # aqt
659 { -select => { having => { -op => [
660 '>', { -func => [ 'count', { -ident => [ 'foo' ] } ] },
661 { -bind => [ undef, 3 ] },
662 ] } } }
663
664 # query
665 HAVING COUNT(foo) > ?
666 [ 3 ]
667
de3eeaea 668=head2 setop clauses
669
670If a select query contains a clause matching any of the setop node types,
671clauses that appear before the setop would in the resulting query are
672gathered together and moved into an inner select node:
673
674 # expr
675 { -select => {
676 _ => '*',
677 from => 'foo',
678 order_by => 'baz',
679 union =>
680 {
681 -select => { _ => '*', from => 'bar', where => { thing => 1 } }
682 },
683 where => { thing => 1 },
684 } }
685
686 # aqt
687 { -select => {
688 order_by => { -op => [ ',', { -ident => [ 'baz' ] } ] },
689 setop => { -union => { queries => [
690 { -select => {
691 from => { -ident => [ 'foo' ] },
692 select => { -op => [ ',', { -ident => [ '*' ] } ] },
693 where => { -op => [
694 '=', { -ident => [ 'thing' ] },
695 { -bind => [ 'thing', 1 ] },
696 ] },
697 } }, ] },
698 { -select => {
699 from => { -ident => [ 'bar' ] },
700 select => { -op => [ ',', { -ident => [ '*' ] } ] },
701 where => { -op => [
702 '=', { -ident => [ 'thing' ] },
703 { -bind => [ 'thing', 1 ] },
704 } },
705 ] } },
706 } }
707
708 # query
709 (SELECT * FROM foo WHERE thing = ?) UNION (
710 SELECT * FROM bar WHERE thing = ?
711 )
712 ORDER BY baz
713 [ 1, 1 ]
714
49dba492 715=head2 update from clause
716
717Some databases allow an additional FROM clause to reference other tables
718for the data to update; this clause is expanded as a normal from list, check
719your database for what is and isn't allowed in practice.
720
721 # expr
722 { -update => {
723 _ => 'employees',
724 from => 'accounts',
725 set => { sales_count => { sales_count => { '+' => \1 } } },
726 where => {
727 'accounts.name' => { '=' => \"'Acme Corporation'" },
728 'employees.id' => { -ident => 'accounts.sales_person' },
729 },
730 } }
731
732 # aqt
733 { -update => {
734 from => { -ident => [ 'accounts' ] },
735 set => { -op => [
736 ',', { -op => [
737 '=', { -ident => [ 'sales_count' ] }, { -op => [
738 '+', { -ident => [ 'sales_count' ] },
739 { -literal => [ 1 ] },
740 ] },
741 ] },
742 ] },
743 target => { -ident => [ 'employees' ] },
744 where => { -op => [
745 'and', { -op => [
746 '=', { -ident => [ 'accounts', 'name' ] },
747 { -literal => [ "'Acme Corporation'" ] },
748 ] }, { -op => [
749 '=', { -ident => [ 'employees', 'id' ] },
750 { -ident => [ 'accounts', 'sales_person' ] },
751 ] },
752 ] },
753 } }
754
755 # query
756 UPDATE employees SET sales_count = sales_count + 1 FROM accounts
757 WHERE (
758 accounts.name = 'Acme Corporation'
759 AND employees.id = accounts.sales_person
760 )
49dba492 761 []
762
763=head2 delete using clause
764
765Some databases allow an additional USING clause to reference other tables
766for the data to update; this clause is expanded as a normal from list, check
767your database for what is and isn't allowed in practice.
768
769 # expr
770 { -delete => {
771 from => 'x',
772 using => 'y',
773 where => { 'x.id' => { -ident => 'y.x_id' } },
774 } }
775
776 # aqt
777 { -delete => {
778 target => { -op => [ ',', { -ident => [ 'x' ] } ] },
779 using => { -ident => [ 'y' ] },
780 where => { -op => [
781 '=', { -ident => [ 'x', 'id' ] },
782 { -ident => [ 'y', 'x_id' ] },
783 ] },
784 } }
785
786 # query
787 DELETE FROM x USING y WHERE x.id = y.x_id
788 []
789
e376aa80 790=head2 insert rowvalues and select clauses
791
792rowvalues and select are shorthand for
793
794 { from => { -select ... } }
795
796and
797
798 { from => { -values ... } }
799
800respectively:
801
802 # expr
803 { -insert =>
804 { into => 'numbers', rowvalues => [ [ 1, 2 ], [ 3, 4 ], [ 5, 6 ] ] }
805 }
806
807 # aqt
808 { -insert => {
809 from => { -values => [
810 { -row =>
811 [ { -bind => [ undef, 1 ] }, { -bind => [ undef, 2 ] } ]
812 },
813 { -row =>
814 [ { -bind => [ undef, 3 ] }, { -bind => [ undef, 4 ] } ]
815 },
816 { -row =>
817 [ { -bind => [ undef, 5 ] }, { -bind => [ undef, 6 ] } ]
818 },
819 ] },
820 target => { -ident => [ 'numbers' ] },
821 } }
822
823 # query
824 INSERT INTO numbers VALUES (?, ?), (?, ?), (?, ?)
825 [ 1, 2, 3, 4, 5, 6 ]
826
827 # expr
828 { -insert =>
829 { into => 'numbers', select => { _ => '*', from => 'old_numbers' } }
830 }
831
832 # aqt
833 { -insert => {
834 from => { -select => {
835 from => { -ident => [ 'old_numbers' ] },
836 select => { -op => [ ',', { -ident => [ '*' ] } ] },
837 } },
838 target => { -ident => [ 'numbers' ] },
839 } }
840
841 # query
842 INSERT INTO numbers SELECT * FROM old_numbers
843 []
844
845=head2 with and with_recursive clauses
846
847These clauses are available on select/insert/update/delete queries; check
848your database for applicability (e.g. mysql supports all four but mariadb
849only select).
850
851The value should be an arrayref of name/query pairs:
852
853 # expr
854 { -select => {
855 from => 'foo',
856 select => '*',
857 with => [ 'foo', { -select => { select => \1 } } ],
858 } }
859
860 # aqt
861 { -select => {
862 from => { -ident => [ 'foo' ] },
863 select => { -op => [ ',', { -ident => [ '*' ] } ] },
864 with => { queries => [ [
865 { -ident => [ 'foo' ] }, { -select =>
866 { select => { -op => [ ',', { -literal => [ 1 ] } ] } }
867 },
868 ] ] },
869 } }
870
871 # query
872 WITH foo AS (SELECT 1) SELECT * FROM foo
873 []
874
875A more complete example (designed for mariadb, (ab)using the fact that
876mysqloids materialise subselects in FROM into an unindexed temp table to
877circumvent the restriction that you can't select from the table you're
878currently updating:
879
880 # expr
881 { -update => {
882 _ => [
883 'tree_table', -join => {
884 as => 'tree',
885 on => { 'tree.id' => 'tree_with_path.id' },
886 to => { -select => {
887 from => 'tree_with_path',
888 select => '*',
889 with_recursive => [
890 [ 'tree_with_path', 'id', 'parent_id', 'path' ],
891 { -select => {
892 _ => [
893 'id', 'parent_id', { -as => [
894 { -cast => { -as => [ 'id', 'char', 255 ] } },
895 'path',
896 ] } ],
897 from => 'tree_table',
898 union_all => { -select => {
899 _ => [
900 't.id', 't.parent_id', { -as => [
901 { -concat => [ 'r.path', \"'/'", 't.id' ] },
902 'path',
903 ] },
904 ],
905 from => [
906 'tree_table', -as => 't', -join => {
907 as => 'r',
908 on => { 't.parent_id' => 'r.id' },
909 to => 'tree_with_path',
910 },
911 ],
912 } },
913 where => { parent_id => undef },
914 } },
915 ],
916 } },
917 },
918 ],
919 set => { path => { -ident => [ 'tree', 'path' ] } },
920 } }
921
922 # query
923 UPDATE
924 tree_table JOIN
925 (
926 WITH RECURSIVE
927 tree_with_path(id, parent_id, path) AS (
928 (
929 SELECT id, parent_id, CAST(id AS char(255)) AS path
930 FROM tree_table WHERE parent_id IS NULL
931 ) UNION ALL (
932 SELECT t.id, t.parent_id, CONCAT(r.path, '/', t.id) AS path
933 FROM
934 tree_table AS t JOIN tree_with_path AS r ON
935 t.parent_id = r.id
936 )
937 )
938 SELECT * FROM tree_with_path
939 ) AS tree
940 ON tree.id = tree_with_path.id
941 SET path = tree.path
942 []
943
3001f097 944=cut