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