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