Reduced regex munging of operators and streamlined backcompat syntax implementation.
[scpubgit/Q-Branch.git] / lib / SQL / Abstract.pm
CommitLineData
96449e8e 1package SQL::Abstract; # see doc at end of file
2
3# LDNOTE : this code is heavy refactoring from original SQLA.
4# Several design decisions will need discussion during
5# the test / diffusion / acceptance phase; those are marked with flag
6# 'LDNOTE' (note by laurent.dami AT free.fr)
7
8use Carp;
9use strict;
10use warnings;
fffe6900 11use List::Util qw/first/;
12use Scalar::Util qw/blessed/;
96449e8e 13
14#======================================================================
15# GLOBALS
16#======================================================================
17
a120d3e3 18our $VERSION = '1.56';
7479e27e 19
22f1a437 20# This would confuse some packagers
21#$VERSION = eval $VERSION; # numify for warning-free dev releases
96449e8e 22
23our $AUTOLOAD;
24
25# special operators (-in, -between). May be extended/overridden by user.
26# See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
27my @BUILTIN_SPECIAL_OPS = (
3a2e1a5e 28 {regex => qr/^(not )?between$/i, handler => '_where_field_BETWEEN'},
29 {regex => qr/^(not )?in$/i, handler => '_where_field_IN'},
96449e8e 30);
31
97a920ef 32# unaryish operators - key maps to handler
59f23b3d 33my @BUILTIN_UNARY_OPS = (
2463c5e4 34 { regex => qr/^and (\s? \d+)?$/xi, handler => '_where_op_ANDOR', numchk => 1 },
35 { regex => qr/^or (\s? \d+)?$/xi, handler => '_where_op_ANDOR', numchk => 1 },
36 { regex => qr/^nest (\s? \d+)?$/xi, handler => '_where_op_NEST', numchk => 1 },
59f23b3d 37 { regex => qr/^(not \s?)? bool$/xi, handler => '_where_op_BOOL' },
38);
97a920ef 39
96449e8e 40#======================================================================
41# DEBUGGING AND ERROR REPORTING
42#======================================================================
43
44sub _debug {
45 return unless $_[0]->{debug}; shift; # a little faster
46 my $func = (caller(1))[3];
47 warn "[$func] ", @_, "\n";
48}
49
50sub belch (@) {
51 my($func) = (caller(1))[3];
52 carp "[$func] Warning: ", @_;
53}
54
55sub puke (@) {
56 my($func) = (caller(1))[3];
57 croak "[$func] Fatal: ", @_;
58}
59
60
61#======================================================================
62# NEW
63#======================================================================
64
65sub new {
66 my $self = shift;
67 my $class = ref($self) || $self;
68 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
69
70 # choose our case by keeping an option around
71 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
72
73 # default logic for interpreting arrayrefs
ef559da3 74 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
96449e8e 75
76 # how to return bind vars
77 # LDNOTE: changed nwiger code : why this 'delete' ??
78 # $opt{bindtype} ||= delete($opt{bind_type}) || 'normal';
79 $opt{bindtype} ||= 'normal';
80
81 # default comparison is "=", but can be overridden
82 $opt{cmp} ||= '=';
83
84 # try to recognize which are the 'equality' and 'unequality' ops
85 # (temporary quickfix, should go through a more seasoned API)
86 $opt{equality_op} = qr/^(\Q$opt{cmp}\E|is|(is\s+)?like)$/i;
87 $opt{inequality_op} = qr/^(!=|<>|(is\s+)?not(\s+like)?)$/i;
88
89 # SQL booleans
90 $opt{sqltrue} ||= '1=1';
91 $opt{sqlfalse} ||= '0=1';
92
93 # special operators
94 $opt{special_ops} ||= [];
95 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
96
59f23b3d 97 # unary operators
98 $opt{unary_ops} ||= [];
99 push @{$opt{unary_ops}}, @BUILTIN_UNARY_OPS;
100
96449e8e 101 return bless \%opt, $class;
102}
103
104
105
106#======================================================================
107# INSERT methods
108#======================================================================
109
110sub insert {
111 my $self = shift;
112 my $table = $self->_table(shift);
113 my $data = shift || return;
114
115 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
116 my ($sql, @bind) = $self->$method($data);
117 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
118 return wantarray ? ($sql, @bind) : $sql;
119}
120
121sub _insert_HASHREF { # explicit list of fields and then values
122 my ($self, $data) = @_;
123
124 my @fields = sort keys %$data;
125
fe3ae272 126 my ($sql, @bind) = $self->_insert_values($data);
96449e8e 127
128 # assemble SQL
129 $_ = $self->_quote($_) foreach @fields;
130 $sql = "( ".join(", ", @fields).") ".$sql;
131
132 return ($sql, @bind);
133}
134
135sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
136 my ($self, $data) = @_;
137
138 # no names (arrayref) so can't generate bindtype
139 $self->{bindtype} ne 'columns'
140 or belch "can't do 'columns' bindtype when called with arrayref";
141
fe3ae272 142 # fold the list of values into a hash of column name - value pairs
143 # (where the column names are artificially generated, and their
144 # lexicographical ordering keep the ordering of the original list)
145 my $i = "a"; # incremented values will be in lexicographical order
146 my $data_in_hash = { map { ($i++ => $_) } @$data };
147
148 return $self->_insert_values($data_in_hash);
149}
150
151sub _insert_ARRAYREFREF { # literal SQL with bind
152 my ($self, $data) = @_;
153
154 my ($sql, @bind) = @${$data};
155 $self->_assert_bindval_matches_bindtype(@bind);
156
157 return ($sql, @bind);
158}
159
160
161sub _insert_SCALARREF { # literal SQL without bind
162 my ($self, $data) = @_;
163
164 return ($$data);
165}
166
167sub _insert_values {
168 my ($self, $data) = @_;
169
96449e8e 170 my (@values, @all_bind);
fe3ae272 171 foreach my $column (sort keys %$data) {
172 my $v = $data->{$column};
96449e8e 173
174 $self->_SWITCH_refkind($v, {
175
176 ARRAYREF => sub {
177 if ($self->{array_datatypes}) { # if array datatype are activated
178 push @values, '?';
fe3ae272 179 push @all_bind, $self->_bindtype($column, $v);
96449e8e 180 }
181 else { # else literal SQL with bind
182 my ($sql, @bind) = @$v;
fe3ae272 183 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 184 push @values, $sql;
185 push @all_bind, @bind;
186 }
187 },
188
189 ARRAYREFREF => sub { # literal SQL with bind
190 my ($sql, @bind) = @${$v};
fe3ae272 191 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 192 push @values, $sql;
193 push @all_bind, @bind;
194 },
195
196 # THINK : anything useful to do with a HASHREF ?
5db47f9f 197 HASHREF => sub { # (nothing, but old SQLA passed it through)
198 #TODO in SQLA >= 2.0 it will die instead
199 belch "HASH ref as bind value in insert is not supported";
200 push @values, '?';
fe3ae272 201 push @all_bind, $self->_bindtype($column, $v);
5db47f9f 202 },
96449e8e 203
204 SCALARREF => sub { # literal SQL without bind
205 push @values, $$v;
206 },
207
208 SCALAR_or_UNDEF => sub {
209 push @values, '?';
fe3ae272 210 push @all_bind, $self->_bindtype($column, $v);
96449e8e 211 },
212
213 });
214
215 }
216
217 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
218 return ($sql, @all_bind);
219}
220
221
96449e8e 222
223#======================================================================
224# UPDATE methods
225#======================================================================
226
227
228sub update {
229 my $self = shift;
230 my $table = $self->_table(shift);
231 my $data = shift || return;
232 my $where = shift;
233
234 # first build the 'SET' part of the sql statement
235 my (@set, @all_bind);
236 puke "Unsupported data type specified to \$sql->update"
237 unless ref $data eq 'HASH';
238
239 for my $k (sort keys %$data) {
240 my $v = $data->{$k};
241 my $r = ref $v;
242 my $label = $self->_quote($k);
243
244 $self->_SWITCH_refkind($v, {
245 ARRAYREF => sub {
246 if ($self->{array_datatypes}) { # array datatype
247 push @set, "$label = ?";
248 push @all_bind, $self->_bindtype($k, $v);
249 }
250 else { # literal SQL with bind
251 my ($sql, @bind) = @$v;
fe3ae272 252 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 253 push @set, "$label = $sql";
fe3ae272 254 push @all_bind, @bind;
96449e8e 255 }
256 },
257 ARRAYREFREF => sub { # literal SQL with bind
258 my ($sql, @bind) = @${$v};
fe3ae272 259 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 260 push @set, "$label = $sql";
fe3ae272 261 push @all_bind, @bind;
96449e8e 262 },
263 SCALARREF => sub { # literal SQL without bind
264 push @set, "$label = $$v";
265 },
266 SCALAR_or_UNDEF => sub {
267 push @set, "$label = ?";
268 push @all_bind, $self->_bindtype($k, $v);
269 },
270 });
271 }
272
273 # generate sql
274 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ')
275 . join ', ', @set;
276
277 if ($where) {
278 my($where_sql, @where_bind) = $self->where($where);
279 $sql .= $where_sql;
280 push @all_bind, @where_bind;
281 }
282
283 return wantarray ? ($sql, @all_bind) : $sql;
284}
285
286
287
288
289#======================================================================
290# SELECT
291#======================================================================
292
293
294sub select {
295 my $self = shift;
296 my $table = $self->_table(shift);
297 my $fields = shift || '*';
298 my $where = shift;
299 my $order = shift;
300
301 my($where_sql, @bind) = $self->where($where, $order);
302
303 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields
304 : $fields;
305 my $sql = join(' ', $self->_sqlcase('select'), $f,
306 $self->_sqlcase('from'), $table)
307 . $where_sql;
308
309 return wantarray ? ($sql, @bind) : $sql;
310}
311
312#======================================================================
313# DELETE
314#======================================================================
315
316
317sub delete {
318 my $self = shift;
319 my $table = $self->_table(shift);
320 my $where = shift;
321
322
323 my($where_sql, @bind) = $self->where($where);
324 my $sql = $self->_sqlcase('delete from') . " $table" . $where_sql;
325
326 return wantarray ? ($sql, @bind) : $sql;
327}
328
329
330#======================================================================
331# WHERE: entry point
332#======================================================================
333
334
335
336# Finally, a separate routine just to handle WHERE clauses
337sub where {
338 my ($self, $where, $order) = @_;
339
340 # where ?
341 my ($sql, @bind) = $self->_recurse_where($where);
342 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
343
344 # order by?
345 if ($order) {
346 $sql .= $self->_order_by($order);
347 }
348
349 return wantarray ? ($sql, @bind) : $sql;
350}
351
352
353sub _recurse_where {
354 my ($self, $where, $logic) = @_;
355
356 # dispatch on appropriate method according to refkind of $where
357 my $method = $self->_METHOD_FOR_refkind("_where", $where);
311b2151 358
359
360 my ($sql, @bind) = $self->$method($where, $logic);
361
362 # DBIx::Class directly calls _recurse_where in scalar context, so
363 # we must implement it, even if not in the official API
364 return wantarray ? ($sql, @bind) : $sql;
96449e8e 365}
366
367
368
369#======================================================================
370# WHERE: top-level ARRAYREF
371#======================================================================
372
373
374sub _where_ARRAYREF {
5e1d09d5 375 my ($self, $where, $logic) = @_;
96449e8e 376
5e1d09d5 377 $logic = uc($logic || $self->{logic});
96449e8e 378 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
379
380 my @clauses = @$where;
381
96449e8e 382 my (@sql_clauses, @all_bind);
96449e8e 383 # need to use while() so can shift() for pairs
384 while (my $el = shift @clauses) {
385
386 # switch according to kind of $el and get corresponding ($sql, @bind)
387 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
388
389 # skip empty elements, otherwise get invalid trailing AND stuff
390 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
391
474e3335 392 ARRAYREFREF => sub { @{${$el}} if @{${$el}}},
393
96449e8e 394 HASHREF => sub {$self->_recurse_where($el, 'and') if %$el},
395 # LDNOTE : previous SQLA code for hashrefs was creating a dirty
396 # side-effect: the first hashref within an array would change
397 # the global logic to 'AND'. So [ {cond1, cond2}, [cond3, cond4] ]
398 # was interpreted as "(cond1 AND cond2) OR (cond3 AND cond4)",
399 # whereas it should be "(cond1 AND cond2) OR (cond3 OR cond4)".
400
401 SCALARREF => sub { ($$el); },
402
403 SCALAR => sub {# top-level arrayref with scalars, recurse in pairs
404 $self->_recurse_where({$el => shift(@clauses)})},
405
406 UNDEF => sub {puke "not supported : UNDEF in arrayref" },
407 });
408
4b7b6026 409 if ($sql) {
410 push @sql_clauses, $sql;
411 push @all_bind, @bind;
412 }
96449e8e 413 }
414
415 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
416}
417
474e3335 418#======================================================================
419# WHERE: top-level ARRAYREFREF
420#======================================================================
96449e8e 421
474e3335 422sub _where_ARRAYREFREF {
423 my ($self, $where) = @_;
424 my ($sql, @bind) = @{${$where}};
425
426 return ($sql, @bind);
427}
96449e8e 428
429#======================================================================
430# WHERE: top-level HASHREF
431#======================================================================
432
433sub _where_HASHREF {
434 my ($self, $where) = @_;
435 my (@sql_clauses, @all_bind);
436
96449e8e 437 for my $k (sort keys %$where) {
438 my $v = $where->{$k};
439
440 # ($k => $v) is either a special op or a regular hashpair
441 my ($sql, @bind) = ($k =~ /^-(.+)/) ? $self->_where_op_in_hash($1, $v)
442 : do {
443 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
444 $self->$method($k, $v);
445 };
446
447 push @sql_clauses, $sql;
448 push @all_bind, @bind;
449 }
450
451 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
452}
453
454
455sub _where_op_in_hash {
59f23b3d 456 my ($self, $op, $v) = @_;
6dae476e 457
59f23b3d 458 # put the operator in canonical form
459 $op =~ s/^-//; # remove initial dash
2463c5e4 460 $op =~ tr/_ \t/ /s; # underscores and whitespace become single spaces
96449e8e 461
96449e8e 462 $self->_debug("OP(-$op) within hashref, recursing...");
463
59f23b3d 464 my $op_entry = first {$op =~ $_->{regex}} @{$self->{unary_ops}};
465 my $handler = $op_entry->{handler};
97a920ef 466 if (! $handler) {
59f23b3d 467 puke "unknown operator: -$op";
97a920ef 468 }
469 elsif (not ref $handler) {
2463c5e4 470 if ($op_entry->{numchk} && ($op =~ s/\s?\d+$//)) {
471 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
472 . "You probably wanted ...-and => [ $op => COND1, $op => COND2 ... ]";
473 }
97a920ef 474 return $self->$handler ($op, $v);
475 }
476 elsif (ref $handler eq 'CODE') {
477 return $handler->($self, $op, $v);
478 }
479 else {
480 puke "Illegal handler for operator $op - expecting a method name or a coderef";
481 }
482}
483
484sub _where_op_ANDOR {
485 my ($self, $op, $v) = @_;
486
487 $self->_SWITCH_refkind($v, {
488 ARRAYREF => sub {
489 return $self->_where_ARRAYREF($v, $op);
490 },
491
492 HASHREF => sub {
59f23b3d 493 return ( $op =~ /^or/i )
97a920ef 494 ? $self->_where_ARRAYREF( [ map { $_ => $v->{$_} } ( sort keys %$v ) ], $op )
495 : $self->_where_HASHREF($v);
496 },
497
498 SCALARREF => sub {
499 puke "-$op => \\\$scalar not supported, use -nest => ...";
500 },
501
502 ARRAYREFREF => sub {
503 puke "-$op => \\[..] not supported, use -nest => ...";
504 },
505
506 SCALAR => sub { # permissively interpreted as SQL
507 puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
508 },
509
510 UNDEF => sub {
511 puke "-$op => undef not supported";
512 },
513 });
514}
515
516sub _where_op_NEST {
517 my ($self, $op, $v) = @_;
518
96449e8e 519 $self->_SWITCH_refkind($v, {
520
521 ARRAYREF => sub {
97a920ef 522 return $self->_where_ARRAYREF($v, '');
96449e8e 523 },
524
525 HASHREF => sub {
97a920ef 526 return $self->_where_HASHREF($v);
96449e8e 527 },
528
529 SCALARREF => sub { # literal SQL
96449e8e 530 return ($$v);
531 },
532
533 ARRAYREFREF => sub { # literal SQL
96449e8e 534 return @{${$v}};
535 },
536
537 SCALAR => sub { # permissively interpreted as SQL
01a01e57 538 belch "literal SQL should be -nest => \\'scalar' "
539 . "instead of -nest => 'scalar' ";
96449e8e 540 return ($v);
541 },
542
543 UNDEF => sub {
544 puke "-$op => undef not supported";
545 },
546 });
547}
548
549
97a920ef 550sub _where_op_BOOL {
551 my ($self, $op, $v) = @_;
552
59f23b3d 553 my $prefix = ($op =~ /\bnot\b/i) ? 'NOT ' : '';
97a920ef 554 $self->_SWITCH_refkind($v, {
555 SCALARREF => sub { # literal SQL
556 return ($prefix . $$v);
557 },
558
559 SCALAR => sub { # interpreted as SQL column
560 return ($prefix . $self->_convert($self->_quote($v)));
561 },
562 });
563}
564
565
96449e8e 566sub _where_hashpair_ARRAYREF {
567 my ($self, $k, $v) = @_;
568
569 if( @$v ) {
570 my @v = @$v; # need copy because of shift below
571 $self->_debug("ARRAY($k) means distribute over elements");
572
573 # put apart first element if it is an operator (-and, -or)
e3cecb45 574 my $op = (
575 (defined $v[0] && $v[0] =~ /^ - (?: AND|OR ) $/ix)
576 ? shift @v
577 : ''
04d940de 578 );
96449e8e 579 my @distributed = map { {$k => $_} } @v;
04d940de 580
581 if ($op) {
582 $self->_debug("OP($op) reinjected into the distributed array");
583 unshift @distributed, $op;
584 }
585
f67591bf 586 my $logic = $op ? substr($op, 1) : '';
96449e8e 587
f67591bf 588 return $self->_recurse_where(\@distributed, $logic);
96449e8e 589 }
590 else {
591 # LDNOTE : not sure of this one. What does "distribute over nothing" mean?
592 $self->_debug("empty ARRAY($k) means 0=1");
593 return ($self->{sqlfalse});
594 }
595}
596
597sub _where_hashpair_HASHREF {
eb49170d 598 my ($self, $k, $v, $logic) = @_;
599 $logic ||= 'and';
96449e8e 600
eb49170d 601 my ($all_sql, @all_bind);
96449e8e 602
603 for my $op (sort keys %$v) {
604 my $val = $v->{$op};
605
606 # put the operator in canonical form
607 $op =~ s/^-//; # remove initial dash
608 $op =~ tr/_/ /; # underscores become spaces
609 $op =~ s/^\s+//; # no initial space
610 $op =~ s/\s+$//; # no final space
611 $op =~ s/\s+/ /; # multiple spaces become one
612
613 my ($sql, @bind);
614
615 # CASE: special operators like -in or -between
616 my $special_op = first {$op =~ $_->{regex}} @{$self->{special_ops}};
617 if ($special_op) {
3a2e1a5e 618 my $handler = $special_op->{handler};
619 if (! $handler) {
620 puke "No handler supplied for special operator matching $special_op->{regex}";
621 }
622 elsif (not ref $handler) {
623 ($sql, @bind) = $self->$handler ($k, $op, $val);
624 }
625 elsif (ref $handler eq 'CODE') {
626 ($sql, @bind) = $handler->($self, $k, $op, $val);
627 }
628 else {
629 puke "Illegal handler for special operator matching $special_op->{regex} - expecting a method name or a coderef";
630 }
96449e8e 631 }
96449e8e 632 else {
cf838930 633 $self->_SWITCH_refkind($val, {
634
635 ARRAYREF => sub { # CASE: col => {op => \@vals}
636 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
637 },
638
fe3ae272 639 SCALARREF => sub { # CASE: col => {op => \$scalar} (literal SQL without bind)
cf838930 640 $sql = join ' ', $self->_convert($self->_quote($k)),
641 $self->_sqlcase($op),
642 $$val;
643 },
644
fe3ae272 645 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]} (literal SQL with bind)
b3be7bd0 646 my ($sub_sql, @sub_bind) = @$$val;
fe3ae272 647 $self->_assert_bindval_matches_bindtype(@sub_bind);
b3be7bd0 648 $sql = join ' ', $self->_convert($self->_quote($k)),
649 $self->_sqlcase($op),
650 $sub_sql;
fe3ae272 651 @bind = @sub_bind;
b3be7bd0 652 },
653
eb49170d 654 HASHREF => sub {
655 ($sql, @bind) = $self->_where_hashpair_HASHREF($k, $val, $op);
656 },
657
cf838930 658 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
659 my $is = ($op =~ $self->{equality_op}) ? 'is' :
660 ($op =~ $self->{inequality_op}) ? 'is not' :
661 puke "unexpected operator '$op' with undef operand";
662 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
663 },
664
665 FALLBACK => sub { # CASE: col => {op => $scalar}
666 $sql = join ' ', $self->_convert($self->_quote($k)),
667 $self->_sqlcase($op),
668 $self->_convert('?');
669 @bind = $self->_bindtype($k, $val);
670 },
671 });
96449e8e 672 }
673
eb49170d 674 ($all_sql) = (defined $all_sql and $all_sql) ? $self->_join_sql_clauses($logic, [$all_sql, $sql], []) : $sql;
96449e8e 675 push @all_bind, @bind;
676 }
eb49170d 677 return ($all_sql, @all_bind);
96449e8e 678}
679
680
681
682sub _where_field_op_ARRAYREF {
683 my ($self, $k, $op, $vals) = @_;
684
ce261791 685 my @vals = @$vals; #always work on a copy
686
687 if(@vals) {
688 $self->_debug("ARRAY($vals) means multiple elements: [ @vals ]");
96449e8e 689
4030915f 690 # see if the first element is an -and/-or op
691 my $logic;
ce261791 692 if ($vals[0] =~ /^ - ( AND|OR ) $/ix) {
4030915f 693 $logic = uc $1;
ce261791 694 shift @vals;
4030915f 695 }
696
ce261791 697 # distribute $op over each remaining member of @vals, append logic if exists
698 return $self->_recurse_where([map { {$k => {$op, $_}} } @vals], $logic);
4030915f 699
f2d5020d 700 # LDNOTE : had planned to change the distribution logic when
96449e8e 701 # $op =~ $self->{inequality_op}, because of Morgan laws :
702 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
703 # WHERE field != 22 OR field != 33 : the user probably means
704 # WHERE field != 22 AND field != 33.
4030915f 705 # To do this, replace the above to roughly :
f2d5020d 706 # my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
ce261791 707 # return $self->_recurse_where([map { {$k => {$op, $_}} } @vals], $logic);
96449e8e 708
96449e8e 709 }
710 else {
711 # try to DWIM on equality operators
712 # LDNOTE : not 100% sure this is the correct thing to do ...
713 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
714 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
715
716 # otherwise
717 puke "operator '$op' applied on an empty array (field '$k')";
718 }
719}
720
721
722sub _where_hashpair_SCALARREF {
723 my ($self, $k, $v) = @_;
724 $self->_debug("SCALAR($k) means literal SQL: $$v");
725 my $sql = $self->_quote($k) . " " . $$v;
726 return ($sql);
727}
728
fe3ae272 729# literal SQL with bind
96449e8e 730sub _where_hashpair_ARRAYREFREF {
731 my ($self, $k, $v) = @_;
732 $self->_debug("REF($k) means literal SQL: @${$v}");
733 my ($sql, @bind) = @${$v};
fe3ae272 734 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 735 $sql = $self->_quote($k) . " " . $sql;
96449e8e 736 return ($sql, @bind );
737}
738
fe3ae272 739# literal SQL without bind
96449e8e 740sub _where_hashpair_SCALAR {
741 my ($self, $k, $v) = @_;
742 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
743 my $sql = join ' ', $self->_convert($self->_quote($k)),
744 $self->_sqlcase($self->{cmp}),
745 $self->_convert('?');
746 my @bind = $self->_bindtype($k, $v);
747 return ( $sql, @bind);
748}
749
750
751sub _where_hashpair_UNDEF {
752 my ($self, $k, $v) = @_;
753 $self->_debug("UNDEF($k) means IS NULL");
754 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
755 return ($sql);
756}
757
758#======================================================================
759# WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
760#======================================================================
761
762
763sub _where_SCALARREF {
764 my ($self, $where) = @_;
765
766 # literal sql
767 $self->_debug("SCALAR(*top) means literal SQL: $$where");
768 return ($$where);
769}
770
771
772sub _where_SCALAR {
773 my ($self, $where) = @_;
774
775 # literal sql
776 $self->_debug("NOREF(*top) means literal SQL: $where");
777 return ($where);
778}
779
780
781sub _where_UNDEF {
782 my ($self) = @_;
783 return ();
784}
785
786
787#======================================================================
788# WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
789#======================================================================
790
791
792sub _where_field_BETWEEN {
793 my ($self, $k, $op, $vals) = @_;
794
cf02fc47 795 (ref $vals eq 'ARRAY' && @$vals == 2) or
796 (ref $vals eq 'REF' && (@$$vals == 1 || @$$vals == 2 || @$$vals == 3))
797 or puke "special op 'between' requires an arrayref of two values (or a scalarref or arrayrefref for literal SQL)";
96449e8e 798
cf02fc47 799 my ($clause, @bind, $label, $and, $placeholder);
800 $label = $self->_convert($self->_quote($k));
801 $and = ' ' . $self->_sqlcase('and') . ' ';
802 $placeholder = $self->_convert('?');
96449e8e 803 $op = $self->_sqlcase($op);
804
cf02fc47 805 if (ref $vals eq 'REF') {
806 ($clause, @bind) = @$$vals;
807 }
808 else {
809 my (@all_sql, @all_bind);
810
811 foreach my $val (@$vals) {
812 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
813 SCALAR => sub {
814 return ($placeholder, ($val));
815 },
816 SCALARREF => sub {
817 return ($self->_convert($$val), ());
818 },
819 });
820 push @all_sql, $sql;
821 push @all_bind, @bind;
822 }
823
824 $clause = (join $and, @all_sql);
825 @bind = $self->_bindtype($k, @all_bind);
826 }
827 my $sql = "( $label $op $clause )";
96449e8e 828 return ($sql, @bind)
829}
830
831
832sub _where_field_IN {
833 my ($self, $k, $op, $vals) = @_;
834
835 # backwards compatibility : if scalar, force into an arrayref
836 $vals = [$vals] if defined $vals && ! ref $vals;
837
96449e8e 838 my ($label) = $self->_convert($self->_quote($k));
839 my ($placeholder) = $self->_convert('?');
96449e8e 840 $op = $self->_sqlcase($op);
841
8a0d798a 842 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
843 ARRAYREF => sub { # list of choices
844 if (@$vals) { # nonempty list
845 my $placeholders = join ", ", (($placeholder) x @$vals);
846 my $sql = "$label $op ( $placeholders )";
847 my @bind = $self->_bindtype($k, @$vals);
96449e8e 848
8a0d798a 849 return ($sql, @bind);
850 }
851 else { # empty list : some databases won't understand "IN ()", so DWIM
852 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
853 return ($sql);
854 }
855 },
856
857 ARRAYREFREF => sub { # literal SQL with bind
858 my ($sql, @bind) = @$$vals;
fe3ae272 859 $self->_assert_bindval_matches_bindtype(@bind);
8a0d798a 860 return ("$label $op ( $sql )", @bind);
861 },
862
863 FALLBACK => sub {
864 puke "special op 'in' requires an arrayref (or arrayref-ref)";
865 },
866 });
867
868 return ($sql, @bind);
96449e8e 869}
870
871
872
873
96449e8e 874#======================================================================
875# ORDER BY
876#======================================================================
877
878sub _order_by {
879 my ($self, $arg) = @_;
880
f267b646 881 my (@sql, @bind);
882 for my $c ($self->_order_by_chunks ($arg) ) {
883 $self->_SWITCH_refkind ($c, {
884 SCALAR => sub { push @sql, $c },
885 ARRAYREF => sub { push @sql, shift @$c; push @bind, @$c },
886 });
887 }
888
889 my $sql = @sql
890 ? sprintf ('%s %s',
891 $self->_sqlcase(' order by'),
892 join (', ', @sql)
893 )
894 : ''
895 ;
896
897 return wantarray ? ($sql, @bind) : $sql;
898}
899
900sub _order_by_chunks {
901 my ($self, $arg) = @_;
902
903 return $self->_SWITCH_refkind($arg, {
96449e8e 904
905 ARRAYREF => sub {
f267b646 906 map { $self->_order_by_chunks ($_ ) } @$arg;
96449e8e 907 },
908
f267b646 909 ARRAYREFREF => sub { [ @$$arg ] },
910
96449e8e 911 SCALAR => sub {$self->_quote($arg)},
f267b646 912
913 UNDEF => sub {return () },
914
96449e8e 915 SCALARREF => sub {$$arg}, # literal SQL, no quoting
96449e8e 916
f267b646 917 HASHREF => sub {
918 # get first pair in hash
919 my ($key, $val) = each %$arg;
96449e8e 920
f267b646 921 return () unless $key;
96449e8e 922
f267b646 923 if ( (keys %$arg) > 1 or not $key =~ /^-(desc|asc)/i ) {
924 puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
925 }
96449e8e 926
f267b646 927 my $direction = $1;
96449e8e 928
e9bd3547 929 my @ret;
f267b646 930 for my $c ($self->_order_by_chunks ($val)) {
e9bd3547 931 my ($sql, @bind);
96449e8e 932
f267b646 933 $self->_SWITCH_refkind ($c, {
934 SCALAR => sub {
e9bd3547 935 $sql = $c;
f267b646 936 },
937 ARRAYREF => sub {
e9bd3547 938 ($sql, @bind) = @$c;
f267b646 939 },
940 });
96449e8e 941
e9bd3547 942 $sql = $sql . ' ' . $self->_sqlcase($direction);
96449e8e 943
e9bd3547 944 push @ret, [ $sql, @bind];
945 }
96449e8e 946
e9bd3547 947 return @ret;
f267b646 948 },
949 });
96449e8e 950}
951
952
96449e8e 953#======================================================================
954# DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
955#======================================================================
956
957sub _table {
958 my $self = shift;
959 my $from = shift;
960 $self->_SWITCH_refkind($from, {
961 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
962 SCALAR => sub {$self->_quote($from)},
963 SCALARREF => sub {$$from},
964 ARRAYREFREF => sub {join ', ', @$from;},
965 });
966}
967
968
969#======================================================================
970# UTILITY FUNCTIONS
971#======================================================================
972
973sub _quote {
974 my $self = shift;
975 my $label = shift;
976
977 $label or puke "can't quote an empty label";
978
979 # left and right quote characters
980 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
981 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
982 ARRAYREF => sub {@{$self->{quote_char}}},
983 UNDEF => sub {()},
984 });
985 not @other
986 or puke "quote_char must be an arrayref of 2 values";
987
988 # no quoting if no quoting chars
989 $ql or return $label;
990
991 # no quoting for literal SQL
992 return $$label if ref($label) eq 'SCALAR';
993
994 # separate table / column (if applicable)
995 my $sep = $self->{name_sep} || '';
996 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
997
998 # do the quoting, except for "*" or for `table`.*
999 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
1000
1001 # reassemble and return.
1002 return join $sep, @quoted;
1003}
1004
1005
1006# Conversion, if applicable
1007sub _convert ($) {
1008 my ($self, $arg) = @_;
1009
1010# LDNOTE : modified the previous implementation below because
1011# it was not consistent : the first "return" is always an array,
1012# the second "return" is context-dependent. Anyway, _convert
1013# seems always used with just a single argument, so make it a
1014# scalar function.
1015# return @_ unless $self->{convert};
1016# my $conv = $self->_sqlcase($self->{convert});
1017# my @ret = map { $conv.'('.$_.')' } @_;
1018# return wantarray ? @ret : $ret[0];
1019 if ($self->{convert}) {
1020 my $conv = $self->_sqlcase($self->{convert});
1021 $arg = $conv.'('.$arg.')';
1022 }
1023 return $arg;
1024}
1025
1026# And bindtype
1027sub _bindtype (@) {
1028 my $self = shift;
1029 my($col, @vals) = @_;
1030
1031 #LDNOTE : changed original implementation below because it did not make
1032 # sense when bindtype eq 'columns' and @vals > 1.
1033# return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
1034
1035 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
1036}
1037
fe3ae272 1038# Dies if any element of @bind is not in [colname => value] format
1039# if bindtype is 'columns'.
1040sub _assert_bindval_matches_bindtype {
1041 my ($self, @bind) = @_;
1042
1043 if ($self->{bindtype} eq 'columns') {
1044 foreach my $val (@bind) {
1045 if (!defined $val || ref($val) ne 'ARRAY' || @$val != 2) {
1046 die "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1047 }
1048 }
1049 }
1050}
1051
96449e8e 1052sub _join_sql_clauses {
1053 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1054
1055 if (@$clauses_aref > 1) {
1056 my $join = " " . $self->_sqlcase($logic) . " ";
1057 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1058 return ($sql, @$bind_aref);
1059 }
1060 elsif (@$clauses_aref) {
1061 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1062 }
1063 else {
1064 return (); # if no SQL, ignore @$bind_aref
1065 }
1066}
1067
1068
1069# Fix SQL case, if so requested
1070sub _sqlcase {
1071 my $self = shift;
1072
1073 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1074 # don't touch the argument ... crooked logic, but let's not change it!
1075 return $self->{case} ? $_[0] : uc($_[0]);
1076}
1077
1078
1079#======================================================================
1080# DISPATCHING FROM REFKIND
1081#======================================================================
1082
1083sub _refkind {
1084 my ($self, $data) = @_;
1085 my $suffix = '';
1086 my $ref;
90aab162 1087 my $n_steps = 0;
96449e8e 1088
96449e8e 1089 while (1) {
90aab162 1090 # blessed objects are treated like scalars
1091 $ref = (blessed $data) ? '' : ref $data;
1092 $n_steps += 1 if $ref;
1093 last if $ref ne 'REF';
96449e8e 1094 $data = $$data;
1095 }
1096
90aab162 1097 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
1098
1099 return $base . ('REF' x $n_steps);
96449e8e 1100}
1101
90aab162 1102
1103
96449e8e 1104sub _try_refkind {
1105 my ($self, $data) = @_;
1106 my @try = ($self->_refkind($data));
1107 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1108 push @try, 'FALLBACK';
1109 return @try;
1110}
1111
1112sub _METHOD_FOR_refkind {
1113 my ($self, $meth_prefix, $data) = @_;
1114 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
1115 $self->_try_refkind($data)
1116 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1117 return $method;
1118}
1119
1120
1121sub _SWITCH_refkind {
1122 my ($self, $data, $dispatch_table) = @_;
1123
1124 my $coderef = first {$_} map {$dispatch_table->{$_}}
1125 $self->_try_refkind($data)
1126 or puke "no dispatch entry for ".$self->_refkind($data);
1127 $coderef->();
1128}
1129
1130
1131
1132
1133#======================================================================
1134# VALUES, GENERATE, AUTOLOAD
1135#======================================================================
1136
1137# LDNOTE: original code from nwiger, didn't touch code in that section
1138# I feel the AUTOLOAD stuff should not be the default, it should
1139# only be activated on explicit demand by user.
1140
1141sub values {
1142 my $self = shift;
1143 my $data = shift || return;
1144 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1145 unless ref $data eq 'HASH';
bab725ce 1146
1147 my @all_bind;
1148 foreach my $k ( sort keys %$data ) {
1149 my $v = $data->{$k};
1150 $self->_SWITCH_refkind($v, {
1151 ARRAYREF => sub {
1152 if ($self->{array_datatypes}) { # array datatype
1153 push @all_bind, $self->_bindtype($k, $v);
1154 }
1155 else { # literal SQL with bind
1156 my ($sql, @bind) = @$v;
1157 $self->_assert_bindval_matches_bindtype(@bind);
1158 push @all_bind, @bind;
1159 }
1160 },
1161 ARRAYREFREF => sub { # literal SQL with bind
1162 my ($sql, @bind) = @${$v};
1163 $self->_assert_bindval_matches_bindtype(@bind);
1164 push @all_bind, @bind;
1165 },
1166 SCALARREF => sub { # literal SQL without bind
1167 },
1168 SCALAR_or_UNDEF => sub {
1169 push @all_bind, $self->_bindtype($k, $v);
1170 },
1171 });
1172 }
1173
1174 return @all_bind;
96449e8e 1175}
1176
1177sub generate {
1178 my $self = shift;
1179
1180 my(@sql, @sqlq, @sqlv);
1181
1182 for (@_) {
1183 my $ref = ref $_;
1184 if ($ref eq 'HASH') {
1185 for my $k (sort keys %$_) {
1186 my $v = $_->{$k};
1187 my $r = ref $v;
1188 my $label = $self->_quote($k);
1189 if ($r eq 'ARRAY') {
fe3ae272 1190 # literal SQL with bind
1191 my ($sql, @bind) = @$v;
1192 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 1193 push @sqlq, "$label = $sql";
fe3ae272 1194 push @sqlv, @bind;
96449e8e 1195 } elsif ($r eq 'SCALAR') {
fe3ae272 1196 # literal SQL without bind
96449e8e 1197 push @sqlq, "$label = $$v";
1198 } else {
1199 push @sqlq, "$label = ?";
1200 push @sqlv, $self->_bindtype($k, $v);
1201 }
1202 }
1203 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1204 } elsif ($ref eq 'ARRAY') {
1205 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1206 for my $v (@$_) {
1207 my $r = ref $v;
fe3ae272 1208 if ($r eq 'ARRAY') { # literal SQL with bind
1209 my ($sql, @bind) = @$v;
1210 $self->_assert_bindval_matches_bindtype(@bind);
1211 push @sqlq, $sql;
1212 push @sqlv, @bind;
1213 } elsif ($r eq 'SCALAR') { # literal SQL without bind
96449e8e 1214 # embedded literal SQL
1215 push @sqlq, $$v;
1216 } else {
1217 push @sqlq, '?';
1218 push @sqlv, $v;
1219 }
1220 }
1221 push @sql, '(' . join(', ', @sqlq) . ')';
1222 } elsif ($ref eq 'SCALAR') {
1223 # literal SQL
1224 push @sql, $$_;
1225 } else {
1226 # strings get case twiddled
1227 push @sql, $self->_sqlcase($_);
1228 }
1229 }
1230
1231 my $sql = join ' ', @sql;
1232
1233 # this is pretty tricky
1234 # if ask for an array, return ($stmt, @bind)
1235 # otherwise, s/?/shift @sqlv/ to put it inline
1236 if (wantarray) {
1237 return ($sql, @sqlv);
1238 } else {
1239 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1240 ref $d ? $d->[1] : $d/e;
1241 return $sql;
1242 }
1243}
1244
1245
1246sub DESTROY { 1 }
1247
1248sub AUTOLOAD {
1249 # This allows us to check for a local, then _form, attr
1250 my $self = shift;
1251 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1252 return $self->generate($name, @_);
1253}
1254
12551;
1256
1257
1258
1259__END__
32eab2da 1260
1261=head1 NAME
1262
1263SQL::Abstract - Generate SQL from Perl data structures
1264
1265=head1 SYNOPSIS
1266
1267 use SQL::Abstract;
1268
1269 my $sql = SQL::Abstract->new;
1270
1271 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1272
1273 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1274
1275 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1276
1277 my($stmt, @bind) = $sql->delete($table, \%where);
1278
1279 # Then, use these in your DBI statements
1280 my $sth = $dbh->prepare($stmt);
1281 $sth->execute(@bind);
1282
1283 # Just generate the WHERE clause
abe72f94 1284 my($stmt, @bind) = $sql->where(\%where, \@order);
32eab2da 1285
1286 # Return values in the same order, for hashed queries
1287 # See PERFORMANCE section for more details
1288 my @bind = $sql->values(\%fieldvals);
1289
1290=head1 DESCRIPTION
1291
1292This module was inspired by the excellent L<DBIx::Abstract>.
1293However, in using that module I found that what I really wanted
1294to do was generate SQL, but still retain complete control over my
1295statement handles and use the DBI interface. So, I set out to
1296create an abstract SQL generation module.
1297
1298While based on the concepts used by L<DBIx::Abstract>, there are
1299several important differences, especially when it comes to WHERE
1300clauses. I have modified the concepts used to make the SQL easier
1301to generate from Perl data structures and, IMO, more intuitive.
1302The underlying idea is for this module to do what you mean, based
1303on the data structures you provide it. The big advantage is that
1304you don't have to modify your code every time your data changes,
1305as this module figures it out.
1306
1307To begin with, an SQL INSERT is as easy as just specifying a hash
1308of C<key=value> pairs:
1309
1310 my %data = (
1311 name => 'Jimbo Bobson',
1312 phone => '123-456-7890',
1313 address => '42 Sister Lane',
1314 city => 'St. Louis',
1315 state => 'Louisiana',
1316 );
1317
1318The SQL can then be generated with this:
1319
1320 my($stmt, @bind) = $sql->insert('people', \%data);
1321
1322Which would give you something like this:
1323
1324 $stmt = "INSERT INTO people
1325 (address, city, name, phone, state)
1326 VALUES (?, ?, ?, ?, ?)";
1327 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1328 '123-456-7890', 'Louisiana');
1329
1330These are then used directly in your DBI code:
1331
1332 my $sth = $dbh->prepare($stmt);
1333 $sth->execute(@bind);
1334
96449e8e 1335=head2 Inserting and Updating Arrays
1336
1337If your database has array types (like for example Postgres),
1338activate the special option C<< array_datatypes => 1 >>
1339when creating the C<SQL::Abstract> object.
1340Then you may use an arrayref to insert and update database array types:
1341
1342 my $sql = SQL::Abstract->new(array_datatypes => 1);
1343 my %data = (
1344 planets => [qw/Mercury Venus Earth Mars/]
1345 );
1346
1347 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1348
1349This results in:
1350
1351 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1352
1353 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1354
1355
1356=head2 Inserting and Updating SQL
1357
1358In order to apply SQL functions to elements of your C<%data> you may
1359specify a reference to an arrayref for the given hash value. For example,
1360if you need to execute the Oracle C<to_date> function on a value, you can
1361say something like this:
32eab2da 1362
1363 my %data = (
1364 name => 'Bill',
96449e8e 1365 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
32eab2da 1366 );
1367
1368The first value in the array is the actual SQL. Any other values are
1369optional and would be included in the bind values array. This gives
1370you:
1371
1372 my($stmt, @bind) = $sql->insert('people', \%data);
1373
1374 $stmt = "INSERT INTO people (name, date_entered)
1375 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1376 @bind = ('Bill', '03/02/2003');
1377
1378An UPDATE is just as easy, all you change is the name of the function:
1379
1380 my($stmt, @bind) = $sql->update('people', \%data);
1381
1382Notice that your C<%data> isn't touched; the module will generate
1383the appropriately quirky SQL for you automatically. Usually you'll
1384want to specify a WHERE clause for your UPDATE, though, which is
1385where handling C<%where> hashes comes in handy...
1386
96449e8e 1387=head2 Complex where statements
1388
32eab2da 1389This module can generate pretty complicated WHERE statements
1390easily. For example, simple C<key=value> pairs are taken to mean
1391equality, and if you want to see if a field is within a set
1392of values, you can use an arrayref. Let's say we wanted to
1393SELECT some data based on this criteria:
1394
1395 my %where = (
1396 requestor => 'inna',
1397 worker => ['nwiger', 'rcwe', 'sfz'],
1398 status => { '!=', 'completed' }
1399 );
1400
1401 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1402
1403The above would give you something like this:
1404
1405 $stmt = "SELECT * FROM tickets WHERE
1406 ( requestor = ? ) AND ( status != ? )
1407 AND ( worker = ? OR worker = ? OR worker = ? )";
1408 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1409
1410Which you could then use in DBI code like so:
1411
1412 my $sth = $dbh->prepare($stmt);
1413 $sth->execute(@bind);
1414
1415Easy, eh?
1416
1417=head1 FUNCTIONS
1418
1419The functions are simple. There's one for each major SQL operation,
1420and a constructor you use first. The arguments are specified in a
1421similar order to each function (table, then fields, then a where
1422clause) to try and simplify things.
1423
83cab70b 1424
83cab70b 1425
32eab2da 1426
1427=head2 new(option => 'value')
1428
1429The C<new()> function takes a list of options and values, and returns
1430a new B<SQL::Abstract> object which can then be used to generate SQL
1431through the methods below. The options accepted are:
1432
1433=over
1434
1435=item case
1436
1437If set to 'lower', then SQL will be generated in all lowercase. By
1438default SQL is generated in "textbook" case meaning something like:
1439
1440 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1441
96449e8e 1442Any setting other than 'lower' is ignored.
1443
32eab2da 1444=item cmp
1445
1446This determines what the default comparison operator is. By default
1447it is C<=>, meaning that a hash like this:
1448
1449 %where = (name => 'nwiger', email => 'nate@wiger.org');
1450
1451Will generate SQL like this:
1452
1453 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1454
1455However, you may want loose comparisons by default, so if you set
1456C<cmp> to C<like> you would get SQL such as:
1457
1458 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1459
1460You can also override the comparsion on an individual basis - see
1461the huge section on L</"WHERE CLAUSES"> at the bottom.
1462
96449e8e 1463=item sqltrue, sqlfalse
1464
1465Expressions for inserting boolean values within SQL statements.
6e0c6552 1466By default these are C<1=1> and C<1=0>. They are used
1467by the special operators C<-in> and C<-not_in> for generating
1468correct SQL even when the argument is an empty array (see below).
96449e8e 1469
32eab2da 1470=item logic
1471
1472This determines the default logical operator for multiple WHERE
7cac25e6 1473statements in arrays or hashes. If absent, the default logic is "or"
1474for arrays, and "and" for hashes. This means that a WHERE
32eab2da 1475array of the form:
1476
1477 @where = (
1478 event_date => {'>=', '2/13/99'},
1479 event_date => {'<=', '4/24/03'},
1480 );
1481
7cac25e6 1482will generate SQL like this:
32eab2da 1483
1484 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1485
1486This is probably not what you want given this query, though (look
1487at the dates). To change the "OR" to an "AND", simply specify:
1488
1489 my $sql = SQL::Abstract->new(logic => 'and');
1490
1491Which will change the above C<WHERE> to:
1492
1493 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1494
96449e8e 1495The logic can also be changed locally by inserting
7cac25e6 1496a modifier in front of an arrayref :
96449e8e 1497
7cac25e6 1498 @where = (-and => [event_date => {'>=', '2/13/99'},
1499 event_date => {'<=', '4/24/03'} ]);
96449e8e 1500
1501See the L</"WHERE CLAUSES"> section for explanations.
1502
32eab2da 1503=item convert
1504
1505This will automatically convert comparisons using the specified SQL
1506function for both column and value. This is mostly used with an argument
1507of C<upper> or C<lower>, so that the SQL will have the effect of
1508case-insensitive "searches". For example, this:
1509
1510 $sql = SQL::Abstract->new(convert => 'upper');
1511 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1512
1513Will turn out the following SQL:
1514
1515 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1516
1517The conversion can be C<upper()>, C<lower()>, or any other SQL function
1518that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1519not validate this option; it will just pass through what you specify verbatim).
1520
1521=item bindtype
1522
1523This is a kludge because many databases suck. For example, you can't
1524just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1525Instead, you have to use C<bind_param()>:
1526
1527 $sth->bind_param(1, 'reg data');
1528 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1529
1530The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1531which loses track of which field each slot refers to. Fear not.
1532
1533If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1534Currently, you can specify either C<normal> (default) or C<columns>. If you
1535specify C<columns>, you will get an array that looks like this:
1536
1537 my $sql = SQL::Abstract->new(bindtype => 'columns');
1538 my($stmt, @bind) = $sql->insert(...);
1539
1540 @bind = (
1541 [ 'column1', 'value1' ],
1542 [ 'column2', 'value2' ],
1543 [ 'column3', 'value3' ],
1544 );
1545
1546You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 1547
32eab2da 1548 $sth->prepare($stmt);
1549 my $i = 1;
1550 for (@bind) {
1551 my($col, $data) = @$_;
1552 if ($col eq 'details' || $col eq 'comments') {
1553 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1554 } elsif ($col eq 'image') {
1555 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1556 } else {
1557 $sth->bind_param($i, $data);
1558 }
1559 $i++;
1560 }
1561 $sth->execute; # execute without @bind now
1562
1563Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1564Basically, the advantage is still that you don't have to care which fields
1565are or are not included. You could wrap that above C<for> loop in a simple
1566sub called C<bind_fields()> or something and reuse it repeatedly. You still
1567get a layer of abstraction over manual SQL specification.
1568
deb148a2 1569Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1570construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1571will expect the bind values in this format.
1572
32eab2da 1573=item quote_char
1574
1575This is the character that a table or column name will be quoted
1576with. By default this is an empty string, but you could set it to
1577the character C<`>, to generate SQL like this:
1578
1579 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1580
96449e8e 1581Alternatively, you can supply an array ref of two items, the first being the left
1582hand quote character, and the second the right hand quote character. For
1583example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1584that generates SQL like this:
1585
1586 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1587
1588Quoting is useful if you have tables or columns names that are reserved
1589words in your database's SQL dialect.
32eab2da 1590
1591=item name_sep
1592
1593This is the character that separates a table and column name. It is
1594necessary to specify this when the C<quote_char> option is selected,
1595so that tables and column names can be individually quoted like this:
1596
1597 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1598
96449e8e 1599=item array_datatypes
32eab2da 1600
96449e8e 1601When this option is true, arrayrefs in INSERT or UPDATE are
1602interpreted as array datatypes and are passed directly
1603to the DBI layer.
1604When this option is false, arrayrefs are interpreted
1605as literal SQL, just like refs to arrayrefs
1606(but this behavior is for backwards compatibility; when writing
1607new queries, use the "reference to arrayref" syntax
1608for literal SQL).
32eab2da 1609
32eab2da 1610
96449e8e 1611=item special_ops
32eab2da 1612
96449e8e 1613Takes a reference to a list of "special operators"
1614to extend the syntax understood by L<SQL::Abstract>.
1615See section L</"SPECIAL OPERATORS"> for details.
32eab2da 1616
59f23b3d 1617=item unary_ops
1618
1619Takes a reference to a list of "unary operators"
1620to extend the syntax understood by L<SQL::Abstract>.
1621See section L</"UNARY OPERATORS"> for details.
1622
32eab2da 1623
32eab2da 1624
96449e8e 1625=back
32eab2da 1626
1627=head2 insert($table, \@values || \%fieldvals)
1628
1629This is the simplest function. You simply give it a table name
1630and either an arrayref of values or hashref of field/value pairs.
1631It returns an SQL INSERT statement and a list of bind values.
96449e8e 1632See the sections on L</"Inserting and Updating Arrays"> and
1633L</"Inserting and Updating SQL"> for information on how to insert
1634with those data types.
32eab2da 1635
1636=head2 update($table, \%fieldvals, \%where)
1637
1638This takes a table, hashref of field/value pairs, and an optional
86298391 1639hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 1640of bind values.
96449e8e 1641See the sections on L</"Inserting and Updating Arrays"> and
1642L</"Inserting and Updating SQL"> for information on how to insert
1643with those data types.
32eab2da 1644
96449e8e 1645=head2 select($source, $fields, $where, $order)
32eab2da 1646
96449e8e 1647This returns a SQL SELECT statement and associated list of bind values, as
1648specified by the arguments :
32eab2da 1649
96449e8e 1650=over
32eab2da 1651
96449e8e 1652=item $source
32eab2da 1653
96449e8e 1654Specification of the 'FROM' part of the statement.
1655The argument can be either a plain scalar (interpreted as a table
1656name, will be quoted), or an arrayref (interpreted as a list
1657of table names, joined by commas, quoted), or a scalarref
1658(literal table name, not quoted), or a ref to an arrayref
1659(list of literal table names, joined by commas, not quoted).
32eab2da 1660
96449e8e 1661=item $fields
32eab2da 1662
96449e8e 1663Specification of the list of fields to retrieve from
1664the source.
1665The argument can be either an arrayref (interpreted as a list
1666of field names, will be joined by commas and quoted), or a
1667plain scalar (literal SQL, not quoted).
1668Please observe that this API is not as flexible as for
e3f9dff4 1669the first argument C<$table>, for backwards compatibility reasons.
32eab2da 1670
96449e8e 1671=item $where
32eab2da 1672
96449e8e 1673Optional argument to specify the WHERE part of the query.
1674The argument is most often a hashref, but can also be
1675an arrayref or plain scalar --
1676see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 1677
96449e8e 1678=item $order
32eab2da 1679
96449e8e 1680Optional argument to specify the ORDER BY part of the query.
1681The argument can be a scalar, a hashref or an arrayref
1682-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1683for details.
32eab2da 1684
96449e8e 1685=back
32eab2da 1686
32eab2da 1687
1688=head2 delete($table, \%where)
1689
86298391 1690This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 1691It returns an SQL DELETE statement and list of bind values.
1692
32eab2da 1693=head2 where(\%where, \@order)
1694
1695This is used to generate just the WHERE clause. For example,
1696if you have an arbitrary data structure and know what the
1697rest of your SQL is going to look like, but want an easy way
1698to produce a WHERE clause, use this. It returns an SQL WHERE
1699clause and list of bind values.
1700
32eab2da 1701
1702=head2 values(\%data)
1703
1704This just returns the values from the hash C<%data>, in the same
1705order that would be returned from any of the other above queries.
1706Using this allows you to markedly speed up your queries if you
1707are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1708
32eab2da 1709=head2 generate($any, 'number', $of, \@data, $struct, \%types)
1710
1711Warning: This is an experimental method and subject to change.
1712
1713This returns arbitrarily generated SQL. It's a really basic shortcut.
1714It will return two different things, depending on return context:
1715
1716 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1717 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1718
1719These would return the following:
1720
1721 # First calling form
1722 $stmt = "CREATE TABLE test (?, ?)";
1723 @bind = (field1, field2);
1724
1725 # Second calling form
1726 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1727
1728Depending on what you're trying to do, it's up to you to choose the correct
1729format. In this example, the second form is what you would want.
1730
1731By the same token:
1732
1733 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1734
1735Might give you:
1736
1737 ALTER SESSION SET nls_date_format = 'MM/YY'
1738
1739You get the idea. Strings get their case twiddled, but everything
1740else remains verbatim.
1741
32eab2da 1742
32eab2da 1743
32eab2da 1744
1745=head1 WHERE CLAUSES
1746
96449e8e 1747=head2 Introduction
1748
32eab2da 1749This module uses a variation on the idea from L<DBIx::Abstract>. It
1750is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1751module is that things in arrays are OR'ed, and things in hashes
1752are AND'ed.>
1753
1754The easiest way to explain is to show lots of examples. After
1755each C<%where> hash shown, it is assumed you used:
1756
1757 my($stmt, @bind) = $sql->where(\%where);
1758
1759However, note that the C<%where> hash can be used directly in any
1760of the other functions as well, as described above.
1761
96449e8e 1762=head2 Key-value pairs
1763
32eab2da 1764So, let's get started. To begin, a simple hash:
1765
1766 my %where = (
1767 user => 'nwiger',
1768 status => 'completed'
1769 );
1770
1771Is converted to SQL C<key = val> statements:
1772
1773 $stmt = "WHERE user = ? AND status = ?";
1774 @bind = ('nwiger', 'completed');
1775
1776One common thing I end up doing is having a list of values that
1777a field can be in. To do this, simply specify a list inside of
1778an arrayref:
1779
1780 my %where = (
1781 user => 'nwiger',
1782 status => ['assigned', 'in-progress', 'pending'];
1783 );
1784
1785This simple code will create the following:
1786
1787 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1788 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1789
7cac25e6 1790A field associated to an empty arrayref will be considered a
1791logical false and will generate 0=1.
8a68b5be 1792
6e0c6552 1793=head2 Specific comparison operators
96449e8e 1794
32eab2da 1795If you want to specify a different type of operator for your comparison,
1796you can use a hashref for a given column:
1797
1798 my %where = (
1799 user => 'nwiger',
1800 status => { '!=', 'completed' }
1801 );
1802
1803Which would generate:
1804
1805 $stmt = "WHERE user = ? AND status != ?";
1806 @bind = ('nwiger', 'completed');
1807
1808To test against multiple values, just enclose the values in an arrayref:
1809
96449e8e 1810 status => { '=', ['assigned', 'in-progress', 'pending'] };
1811
f2d5020d 1812Which would give you:
96449e8e 1813
1814 "WHERE status = ? OR status = ? OR status = ?"
1815
1816
1817The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 1818into an C<AND> of its elements:
1819
1820 my %where = (
1821 user => 'nwiger',
1822 status => { '!=', 'completed', -not_like => 'pending%' }
1823 );
1824
1825 # Or more dynamically, like from a form
1826 $where{user} = 'nwiger';
1827 $where{status}{'!='} = 'completed';
1828 $where{status}{'-not_like'} = 'pending%';
1829
1830 # Both generate this
1831 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1832 @bind = ('nwiger', 'completed', 'pending%');
1833
96449e8e 1834
32eab2da 1835To get an OR instead, you can combine it with the arrayref idea:
1836
1837 my %where => (
1838 user => 'nwiger',
1839 priority => [ {'=', 2}, {'!=', 1} ]
1840 );
1841
1842Which would generate:
1843
1844 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1845 @bind = ('nwiger', '2', '1');
1846
44b9e502 1847If you want to include literal SQL (with or without bind values), just use a
1848scalar reference or array reference as the value:
1849
1850 my %where = (
1851 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1852 date_expires => { '<' => \"now()" }
1853 );
1854
1855Which would generate:
1856
1857 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1858 @bind = ('11/26/2008');
1859
96449e8e 1860
1861=head2 Logic and nesting operators
1862
1863In the example above,
1864there is a subtle trap if you want to say something like
32eab2da 1865this (notice the C<AND>):
1866
1867 WHERE priority != ? AND priority != ?
1868
1869Because, in Perl you I<can't> do this:
1870
1871 priority => { '!=', 2, '!=', 1 }
1872
1873As the second C<!=> key will obliterate the first. The solution
1874is to use the special C<-modifier> form inside an arrayref:
1875
96449e8e 1876 priority => [ -and => {'!=', 2},
1877 {'!=', 1} ]
1878
32eab2da 1879
1880Normally, these would be joined by C<OR>, but the modifier tells it
1881to use C<AND> instead. (Hint: You can use this in conjunction with the
1882C<logic> option to C<new()> in order to change the way your queries
1883work by default.) B<Important:> Note that the C<-modifier> goes
1884B<INSIDE> the arrayref, as an extra first element. This will
1885B<NOT> do what you think it might:
1886
1887 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1888
1889Here is a quick list of equivalencies, since there is some overlap:
1890
1891 # Same
1892 status => {'!=', 'completed', 'not like', 'pending%' }
1893 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1894
1895 # Same
1896 status => {'=', ['assigned', 'in-progress']}
1897 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1898 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1899
e3f9dff4 1900
1901
96449e8e 1902=head2 Special operators : IN, BETWEEN, etc.
1903
32eab2da 1904You can also use the hashref format to compare a list of fields using the
1905C<IN> comparison operator, by specifying the list as an arrayref:
1906
1907 my %where = (
1908 status => 'completed',
1909 reportid => { -in => [567, 2335, 2] }
1910 );
1911
1912Which would generate:
1913
1914 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1915 @bind = ('completed', '567', '2335', '2');
1916
96449e8e 1917The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1918the same way.
1919
6e0c6552 1920If the argument to C<-in> is an empty array, 'sqlfalse' is generated
1921(by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
1922'sqltrue' (by default : C<1=1>).
1923
1924
1925
96449e8e 1926Another pair of operators is C<-between> and C<-not_between>,
1927used with an arrayref of two values:
32eab2da 1928
1929 my %where = (
1930 user => 'nwiger',
1931 completion_date => {
1932 -not_between => ['2002-10-01', '2003-02-06']
1933 }
1934 );
1935
1936Would give you:
1937
1938 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1939
96449e8e 1940These are the two builtin "special operators"; but the
1941list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1942
59f23b3d 1943=head2 Unary operators: bool
97a920ef 1944
1945If you wish to test against boolean columns or functions within your
1946database you can use the C<-bool> and C<-not_bool> operators. For
1947example to test the column C<is_user> being true and the column
1948<is_enabled> being false you would use:-
1949
1950 my %where = (
1951 -bool => 'is_user',
1952 -not_bool => 'is_enabled',
1953 );
1954
1955Would give you:
1956
1957 WHERE is_user AND NOT is_enabledmv
1958
1959
1960
107b72f1 1961=head2 Nested conditions, -and/-or prefixes
96449e8e 1962
32eab2da 1963So far, we've seen how multiple conditions are joined with a top-level
1964C<AND>. We can change this by putting the different conditions we want in
1965hashes and then putting those hashes in an array. For example:
1966
1967 my @where = (
1968 {
1969 user => 'nwiger',
1970 status => { -like => ['pending%', 'dispatched'] },
1971 },
1972 {
1973 user => 'robot',
1974 status => 'unassigned',
1975 }
1976 );
1977
1978This data structure would create the following:
1979
1980 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1981 OR ( user = ? AND status = ? ) )";
1982 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1983
107b72f1 1984
01a01e57 1985There is also a special C<-nest>
107b72f1 1986operator which adds an additional set of parens, to create a subquery.
1987For example, to get something like this:
1988
1989 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
1990 @bind = ('nwiger', '20', 'ASIA');
1991
1992You would do:
1993
1994 my %where = (
1995 user => 'nwiger',
01a01e57 1996 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
107b72f1 1997 );
1998
1999
2000Finally, clauses in hashrefs or arrayrefs can be
7cac25e6 2001prefixed with an C<-and> or C<-or> to change the logic
2002inside :
32eab2da 2003
2004 my @where = (
2005 -and => [
2006 user => 'nwiger',
01a01e57 2007 -nest => [
7cac25e6 2008 -and => [workhrs => {'>', 20}, geo => 'ASIA' ],
2009 -and => [workhrs => {'<', 50}, geo => 'EURO' ]
32eab2da 2010 ],
2011 ],
2012 );
2013
2014That would yield:
2015
2016 WHERE ( user = ? AND
2017 ( ( workhrs > ? AND geo = ? )
2018 OR ( workhrs < ? AND geo = ? ) ) )
2019
107b72f1 2020
2021=head2 Algebraic inconsistency, for historical reasons
2022
7cac25e6 2023C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2024operator goes C<outside> of the nested structure; whereas when connecting
2025several constraints on one column, the C<-and> operator goes
2026C<inside> the arrayref. Here is an example combining both features :
2027
2028 my @where = (
2029 -and => [a => 1, b => 2],
2030 -or => [c => 3, d => 4],
2031 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2032 )
2033
2034yielding
2035
2036 WHERE ( ( ( a = ? AND b = ? )
2037 OR ( c = ? OR d = ? )
2038 OR ( e LIKE ? AND e LIKE ? ) ) )
2039
107b72f1 2040This difference in syntax is unfortunate but must be preserved for
2041historical reasons. So be careful : the two examples below would
2042seem algebraically equivalent, but they are not
2043
2044 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
2045 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
2046
2047 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
2048 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
2049
7cac25e6 2050
96449e8e 2051=head2 Literal SQL
2052
32eab2da 2053Finally, sometimes only literal SQL will do. If you want to include
2054literal SQL verbatim, you can specify it as a scalar reference, namely:
2055
2056 my $inn = 'is Not Null';
2057 my %where = (
2058 priority => { '<', 2 },
2059 requestor => \$inn
2060 );
2061
2062This would create:
2063
2064 $stmt = "WHERE priority < ? AND requestor is Not Null";
2065 @bind = ('2');
2066
2067Note that in this example, you only get one bind parameter back, since
2068the verbatim SQL is passed as part of the statement.
2069
2070Of course, just to prove a point, the above can also be accomplished
2071with this:
2072
2073 my %where = (
2074 priority => { '<', 2 },
2075 requestor => { '!=', undef },
2076 );
2077
96449e8e 2078
32eab2da 2079TMTOWTDI.
2080
96449e8e 2081Conditions on boolean columns can be expressed in the
2082same way, passing a reference to an empty string :
2083
2084 my %where = (
2085 priority => { '<', 2 },
2086 is_ready => \"";
2087 );
2088
2089which yields
2090
2091 $stmt = "WHERE priority < ? AND is_ready";
2092 @bind = ('2');
2093
2094
2095=head2 Literal SQL with placeholders and bind values (subqueries)
2096
2097If the literal SQL to be inserted has placeholders and bind values,
2098use a reference to an arrayref (yes this is a double reference --
2099not so common, but perfectly legal Perl). For example, to find a date
2100in Postgres you can use something like this:
2101
2102 my %where = (
2103 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
2104 )
2105
2106This would create:
2107
d2a8fe1a 2108 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 2109 @bind = ('10');
2110
deb148a2 2111Note that you must pass the bind values in the same format as they are returned
62552e7d 2112by L</where>. That means that if you set L</bindtype> to C<columns>, you must
26f2dca5 2113provide the bind values in the C<< [ column_meta => value ] >> format, where
2114C<column_meta> is an opaque scalar value; most commonly the column name, but
62552e7d 2115you can use any scalar value (including references and blessed references),
2116L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
2117to C<columns> the above example will look like:
deb148a2 2118
2119 my %where = (
2120 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
2121 )
96449e8e 2122
2123Literal SQL is especially useful for nesting parenthesized clauses in the
2124main SQL query. Here is a first example :
2125
2126 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2127 100, "foo%");
2128 my %where = (
2129 foo => 1234,
2130 bar => \["IN ($sub_stmt)" => @sub_bind],
2131 );
2132
2133This yields :
2134
2135 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2136 WHERE c2 < ? AND c3 LIKE ?))";
2137 @bind = (1234, 100, "foo%");
2138
2139Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2140are expressed in the same way. Of course the C<$sub_stmt> and
2141its associated bind values can be generated through a former call
2142to C<select()> :
2143
2144 my ($sub_stmt, @sub_bind)
2145 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2146 c3 => {-like => "foo%"}});
2147 my %where = (
2148 foo => 1234,
2149 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2150 );
2151
2152In the examples above, the subquery was used as an operator on a column;
2153but the same principle also applies for a clause within the main C<%where>
2154hash, like an EXISTS subquery :
2155
2156 my ($sub_stmt, @sub_bind)
2157 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2158 my %where = (
2159 foo => 1234,
01a01e57 2160 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
96449e8e 2161 );
2162
2163which yields
2164
2165 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2166 WHERE c1 = ? AND c2 > t0.c0))";
2167 @bind = (1234, 1);
2168
2169
2170Observe that the condition on C<c2> in the subquery refers to
2171column C<t0.c0> of the main query : this is I<not> a bind
2172value, so we have to express it through a scalar ref.
2173Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2174C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2175what we wanted here.
2176
2177Another use of the subquery technique is when some SQL clauses need
2178parentheses, as it often occurs with some proprietary SQL extensions
2179like for example fulltext expressions, geospatial expressions,
2180NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
2181
2182 my %where = (
01a01e57 2183 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
96449e8e 2184 );
2185
2186Finally, here is an example where a subquery is used
2187for expressing unary negation:
2188
2189 my ($sub_stmt, @sub_bind)
2190 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2191 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2192 my %where = (
2193 lname => {like => '%son%'},
01a01e57 2194 -nest => \["NOT ($sub_stmt)" => @sub_bind],
96449e8e 2195 );
2196
2197This yields
2198
2199 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2200 @bind = ('%son%', 10, 20)
2201
2202
2203
2204=head2 Conclusion
2205
32eab2da 2206These pages could go on for a while, since the nesting of the data
2207structures this module can handle are pretty much unlimited (the
2208module implements the C<WHERE> expansion as a recursive function
2209internally). Your best bet is to "play around" with the module a
2210little to see how the data structures behave, and choose the best
2211format for your data based on that.
2212
2213And of course, all the values above will probably be replaced with
2214variables gotten from forms or the command line. After all, if you
2215knew everything ahead of time, you wouldn't have to worry about
2216dynamically-generating SQL and could just hardwire it into your
2217script.
2218
96449e8e 2219
2220
2221
86298391 2222=head1 ORDER BY CLAUSES
2223
2224Some functions take an order by clause. This can either be a scalar (just a
2225column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1cfa1db3 2226or an array of either of the two previous forms. Examples:
2227
952f9e2d 2228 Given | Will Generate
1cfa1db3 2229 ----------------------------------------------------------
952f9e2d 2230 |
2231 \'colA DESC' | ORDER BY colA DESC
2232 |
2233 'colA' | ORDER BY colA
2234 |
2235 [qw/colA colB/] | ORDER BY colA, colB
2236 |
2237 {-asc => 'colA'} | ORDER BY colA ASC
2238 |
2239 {-desc => 'colB'} | ORDER BY colB DESC
2240 |
2241 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2242 |
2243 { -asc => [qw/colA colB] } | ORDER BY colA ASC, colB ASC
2244 |
2245 [ |
2246 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
2247 { -desc => [qw/colB/], | colC ASC, colD ASC
2248 { -asc => [qw/colC colD/],|
2249 ] |
2250 ===========================================================
86298391 2251
96449e8e 2252
2253
2254=head1 SPECIAL OPERATORS
2255
e3f9dff4 2256 my $sqlmaker = SQL::Abstract->new(special_ops => [
3a2e1a5e 2257 {
2258 regex => qr/.../,
e3f9dff4 2259 handler => sub {
2260 my ($self, $field, $op, $arg) = @_;
2261 ...
3a2e1a5e 2262 },
2263 },
2264 {
2265 regex => qr/.../,
2266 handler => 'method_name',
e3f9dff4 2267 },
2268 ]);
2269
2270A "special operator" is a SQL syntactic clause that can be
2271applied to a field, instead of a usual binary operator.
2272For example :
2273
2274 WHERE field IN (?, ?, ?)
2275 WHERE field BETWEEN ? AND ?
2276 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 2277
e3f9dff4 2278Special operators IN and BETWEEN are fairly standard and therefore
3a2e1a5e 2279are builtin within C<SQL::Abstract> (as the overridable methods
2280C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2281like the MATCH .. AGAINST example above which is specific to MySQL,
2282you can write your own operator handlers - supply a C<special_ops>
2283argument to the C<new> method. That argument takes an arrayref of
2284operator definitions; each operator definition is a hashref with two
2285entries:
96449e8e 2286
e3f9dff4 2287=over
2288
2289=item regex
2290
2291the regular expression to match the operator
96449e8e 2292
e3f9dff4 2293=item handler
2294
3a2e1a5e 2295Either a coderef or a plain scalar method name. In both cases
2296the expected return is C<< ($sql, @bind) >>.
2297
2298When supplied with a method name, it is simply called on the
2299L<SQL::Abstract/> object as:
2300
2301 $self->$method_name ($field, $op, $arg)
2302
2303 Where:
2304
2305 $op is the part that matched the handler regex
2306 $field is the LHS of the operator
2307 $arg is the RHS
2308
2309When supplied with a coderef, it is called as:
2310
2311 $coderef->($self, $field, $op, $arg)
2312
e3f9dff4 2313
2314=back
2315
2316For example, here is an implementation
2317of the MATCH .. AGAINST syntax for MySQL
2318
2319 my $sqlmaker = SQL::Abstract->new(special_ops => [
2320
2321 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2322 {regex => qr/^match$/i,
2323 handler => sub {
2324 my ($self, $field, $op, $arg) = @_;
2325 $arg = [$arg] if not ref $arg;
2326 my $label = $self->_quote($field);
2327 my ($placeholder) = $self->_convert('?');
2328 my $placeholders = join ", ", (($placeholder) x @$arg);
2329 my $sql = $self->_sqlcase('match') . " ($label) "
2330 . $self->_sqlcase('against') . " ($placeholders) ";
2331 my @bind = $self->_bindtype($field, @$arg);
2332 return ($sql, @bind);
2333 }
2334 },
2335
2336 ]);
96449e8e 2337
2338
59f23b3d 2339=head1 UNARY OPERATORS
2340
112b5232 2341 my $sqlmaker = SQL::Abstract->new(unary_ops => [
59f23b3d 2342 {
2343 regex => qr/.../,
2344 handler => sub {
2345 my ($self, $op, $arg) = @_;
2346 ...
2347 },
2348 },
2349 {
2350 regex => qr/.../,
2351 handler => 'method_name',
2352 },
2353 ]);
2354
2355A "unary operator" is a SQL syntactic clause that can be
2356applied to a field - the operator goes before the field
2357
2358You can write your own operator handlers - supply a C<unary_ops>
2359argument to the C<new> method. That argument takes an arrayref of
2360operator definitions; each operator definition is a hashref with two
2361entries:
2362
2363=over
2364
2365=item regex
2366
2367the regular expression to match the operator
2368
2369=item handler
2370
2371Either a coderef or a plain scalar method name. In both cases
2372the expected return is C<< $sql >>.
2373
2374When supplied with a method name, it is simply called on the
2375L<SQL::Abstract/> object as:
2376
2377 $self->$method_name ($op, $arg)
2378
2379 Where:
2380
2381 $op is the part that matched the handler regex
2382 $arg is the RHS or argument of the operator
2383
2384When supplied with a coderef, it is called as:
2385
2386 $coderef->($self, $op, $arg)
2387
2388
2389=back
2390
2391
32eab2da 2392=head1 PERFORMANCE
2393
2394Thanks to some benchmarking by Mark Stosberg, it turns out that
2395this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2396I must admit this wasn't an intentional design issue, but it's a
2397byproduct of the fact that you get to control your C<DBI> handles
2398yourself.
2399
2400To maximize performance, use a code snippet like the following:
2401
2402 # prepare a statement handle using the first row
2403 # and then reuse it for the rest of the rows
2404 my($sth, $stmt);
2405 for my $href (@array_of_hashrefs) {
2406 $stmt ||= $sql->insert('table', $href);
2407 $sth ||= $dbh->prepare($stmt);
2408 $sth->execute($sql->values($href));
2409 }
2410
2411The reason this works is because the keys in your C<$href> are sorted
2412internally by B<SQL::Abstract>. Thus, as long as your data retains
2413the same structure, you only have to generate the SQL the first time
2414around. On subsequent queries, simply use the C<values> function provided
2415by this module to return your values in the correct order.
2416
96449e8e 2417
32eab2da 2418=head1 FORMBUILDER
2419
2420If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2421really like this part (I do, at least). Building up a complex query
2422can be as simple as the following:
2423
2424 #!/usr/bin/perl
2425
2426 use CGI::FormBuilder;
2427 use SQL::Abstract;
2428
2429 my $form = CGI::FormBuilder->new(...);
2430 my $sql = SQL::Abstract->new;
2431
2432 if ($form->submitted) {
2433 my $field = $form->field;
2434 my $id = delete $field->{id};
2435 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2436 }
2437
2438Of course, you would still have to connect using C<DBI> to run the
2439query, but the point is that if you make your form look like your
2440table, the actual query script can be extremely simplistic.
2441
2442If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2443a fast interface to returning and formatting data. I frequently
2444use these three modules together to write complex database query
2445apps in under 50 lines.
2446
32eab2da 2447
96449e8e 2448=head1 CHANGES
2449
2450Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2451Great care has been taken to preserve the I<published> behavior
2452documented in previous versions in the 1.* family; however,
2453some features that were previously undocumented, or behaved
2454differently from the documentation, had to be changed in order
2455to clarify the semantics. Hence, client code that was relying
2456on some dark areas of C<SQL::Abstract> v1.*
2457B<might behave differently> in v1.50.
32eab2da 2458
d2a8fe1a 2459The main changes are :
2460
96449e8e 2461=over
32eab2da 2462
96449e8e 2463=item *
32eab2da 2464
96449e8e 2465support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2466
2467=item *
2468
145fbfc8 2469support for the { operator => \"..." } construct (to embed literal SQL)
2470
2471=item *
2472
9c37b9c0 2473support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2474
2475=item *
2476
96449e8e 2477optional support for L<array datatypes|/"Inserting and Updating Arrays">
2478
2479=item *
2480
2481defensive programming : check arguments
2482
2483=item *
2484
2485fixed bug with global logic, which was previously implemented
7cac25e6 2486through global variables yielding side-effects. Prior versions would
96449e8e 2487interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2488as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2489Now this is interpreted
2490as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2491
96449e8e 2492
2493=item *
2494
2495fixed semantics of _bindtype on array args
2496
2497=item *
2498
2499dropped the C<_anoncopy> of the %where tree. No longer necessary,
2500we just avoid shifting arrays within that tree.
2501
2502=item *
2503
2504dropped the C<_modlogic> function
2505
2506=back
32eab2da 2507
32eab2da 2508
32eab2da 2509
2510=head1 ACKNOWLEDGEMENTS
2511
2512There are a number of individuals that have really helped out with
2513this module. Unfortunately, most of them submitted bugs via CPAN
2514so I have no idea who they are! But the people I do know are:
2515
86298391 2516 Ash Berlin (order_by hash term support)
b643abe1 2517 Matt Trout (DBIx::Class support)
32eab2da 2518 Mark Stosberg (benchmarking)
2519 Chas Owens (initial "IN" operator support)
2520 Philip Collins (per-field SQL functions)
2521 Eric Kolve (hashref "AND" support)
2522 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2523 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 2524 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
01a01e57 2525 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
dbdf7648 2526 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
e96c510a 2527 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
32eab2da 2528
2529Thanks!
2530
32eab2da 2531=head1 SEE ALSO
2532
86298391 2533L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 2534
32eab2da 2535=head1 AUTHOR
2536
b643abe1 2537Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2538
2539This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 2540
abe72f94 2541For support, your best bet is to try the C<DBIx::Class> users mailing list.
2542While not an official support venue, C<DBIx::Class> makes heavy use of
2543C<SQL::Abstract>, and as such list members there are very familiar with
2544how to create queries.
2545
0d067ded 2546=head1 LICENSE
2547
32eab2da 2548This module is free software; you may copy this under the terms of
2549the GNU General Public License, or the Artistic License, copies of
2550which should have accompanied your Perl kit.
2551
2552=cut
2553