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