1 package SQL::Abstract; # see doc at end of file
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)
11 use List::Util qw/first/;
12 use Scalar::Util qw/blessed/;
14 #======================================================================
16 #======================================================================
18 our $VERSION = '1.49_01';
19 $VERSION = eval $VERSION; # numify for warning-free dev releases
24 # special operators (-in, -between). May be extended/overridden by user.
25 # See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
26 my @BUILTIN_SPECIAL_OPS = (
27 {regex => qr/^(not )?between$/i, handler => \&_where_field_BETWEEN},
28 {regex => qr/^(not )?in$/i, handler => \&_where_field_IN},
31 #======================================================================
32 # DEBUGGING AND ERROR REPORTING
33 #======================================================================
36 return unless $_[0]->{debug}; shift; # a little faster
37 my $func = (caller(1))[3];
38 warn "[$func] ", @_, "\n";
42 my($func) = (caller(1))[3];
43 carp "[$func] Warning: ", @_;
47 my($func) = (caller(1))[3];
48 croak "[$func] Fatal: ", @_;
52 #======================================================================
54 #======================================================================
58 my $class = ref($self) || $self;
59 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
61 # choose our case by keeping an option around
62 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
64 # default logic for interpreting arrayrefs
65 $opt{logic} = uc $opt{logic} || 'OR';
67 # how to return bind vars
68 # LDNOTE: changed nwiger code : why this 'delete' ??
69 # $opt{bindtype} ||= delete($opt{bind_type}) || 'normal';
70 $opt{bindtype} ||= 'normal';
72 # default comparison is "=", but can be overridden
75 # try to recognize which are the 'equality' and 'unequality' ops
76 # (temporary quickfix, should go through a more seasoned API)
77 $opt{equality_op} = qr/^(\Q$opt{cmp}\E|is|(is\s+)?like)$/i;
78 $opt{inequality_op} = qr/^(!=|<>|(is\s+)?not(\s+like)?)$/i;
81 $opt{sqltrue} ||= '1=1';
82 $opt{sqlfalse} ||= '0=1';
85 $opt{special_ops} ||= [];
86 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
88 return bless \%opt, $class;
93 #======================================================================
95 #======================================================================
99 my $table = $self->_table(shift);
100 my $data = shift || return;
102 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
103 my ($sql, @bind) = $self->$method($data);
104 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
105 return wantarray ? ($sql, @bind) : $sql;
108 sub _insert_HASHREF { # explicit list of fields and then values
109 my ($self, $data) = @_;
111 my @fields = sort keys %$data;
114 { # get values (need temporary override of bindtype to avoid an error)
115 local $self->{bindtype} = 'normal';
116 ($sql, @bind) = $self->_insert_ARRAYREF([@{$data}{@fields}]);
119 # if necessary, transform values according to 'bindtype'
120 if ($self->{bindtype} eq 'columns') {
121 for my $i (0 .. $#fields) {
122 ($bind[$i]) = $self->_bindtype($fields[$i], $bind[$i]);
127 $_ = $self->_quote($_) foreach @fields;
128 $sql = "( ".join(", ", @fields).") ".$sql;
130 return ($sql, @bind);
133 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
134 my ($self, $data) = @_;
136 # no names (arrayref) so can't generate bindtype
137 $self->{bindtype} ne 'columns'
138 or belch "can't do 'columns' bindtype when called with arrayref";
140 my (@values, @all_bind);
143 $self->_SWITCH_refkind($v, {
146 if ($self->{array_datatypes}) { # if array datatype are activated
150 else { # else literal SQL with bind
151 my ($sql, @bind) = @$v;
153 push @all_bind, @bind;
157 ARRAYREFREF => sub { # literal SQL with bind
158 my ($sql, @bind) = @${$v};
160 push @all_bind, @bind;
163 # THINK : anything useful to do with a HASHREF ?
165 SCALARREF => sub { # literal SQL without bind
169 SCALAR_or_UNDEF => sub {
178 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
179 return ($sql, @all_bind);
183 sub _insert_ARRAYREFREF { # literal SQL with bind
184 my ($self, $data) = @_;
189 sub _insert_SCALARREF { # literal SQL without bind
190 my ($self, $data) = @_;
197 #======================================================================
199 #======================================================================
204 my $table = $self->_table(shift);
205 my $data = shift || return;
208 # first build the 'SET' part of the sql statement
209 my (@set, @all_bind);
210 puke "Unsupported data type specified to \$sql->update"
211 unless ref $data eq 'HASH';
213 for my $k (sort keys %$data) {
216 my $label = $self->_quote($k);
218 $self->_SWITCH_refkind($v, {
220 if ($self->{array_datatypes}) { # array datatype
221 push @set, "$label = ?";
222 push @all_bind, $self->_bindtype($k, $v);
224 else { # literal SQL with bind
225 my ($sql, @bind) = @$v;
226 push @set, "$label = $sql";
227 push @all_bind, $self->_bindtype($k, @bind);
230 ARRAYREFREF => sub { # literal SQL with bind
231 my ($sql, @bind) = @${$v};
232 push @set, "$label = $sql";
233 push @all_bind, $self->_bindtype($k, @bind);
235 SCALARREF => sub { # literal SQL without bind
236 push @set, "$label = $$v";
238 SCALAR_or_UNDEF => sub {
239 push @set, "$label = ?";
240 push @all_bind, $self->_bindtype($k, $v);
246 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ')
250 my($where_sql, @where_bind) = $self->where($where);
252 push @all_bind, @where_bind;
255 return wantarray ? ($sql, @all_bind) : $sql;
261 #======================================================================
263 #======================================================================
268 my $table = $self->_table(shift);
269 my $fields = shift || '*';
273 my($where_sql, @bind) = $self->where($where, $order);
275 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields
277 my $sql = join(' ', $self->_sqlcase('select'), $f,
278 $self->_sqlcase('from'), $table)
281 return wantarray ? ($sql, @bind) : $sql;
284 #======================================================================
286 #======================================================================
291 my $table = $self->_table(shift);
295 my($where_sql, @bind) = $self->where($where);
296 my $sql = $self->_sqlcase('delete from') . " $table" . $where_sql;
298 return wantarray ? ($sql, @bind) : $sql;
302 #======================================================================
304 #======================================================================
308 # Finally, a separate routine just to handle WHERE clauses
310 my ($self, $where, $order) = @_;
313 my ($sql, @bind) = $self->_recurse_where($where);
314 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
318 $sql .= $self->_order_by($order);
321 return wantarray ? ($sql, @bind) : $sql;
326 my ($self, $where, $logic) = @_;
328 # dispatch on appropriate method according to refkind of $where
329 my $method = $self->_METHOD_FOR_refkind("_where", $where);
332 my ($sql, @bind) = $self->$method($where, $logic);
334 # DBIx::Class directly calls _recurse_where in scalar context, so
335 # we must implement it, even if not in the official API
336 return wantarray ? ($sql, @bind) : $sql;
341 #======================================================================
342 # WHERE: top-level ARRAYREF
343 #======================================================================
346 sub _where_ARRAYREF {
347 my ($self, $where, $logic) = @_;
349 $logic = uc($logic || $self->{logic});
350 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
352 my @clauses = @$where;
354 # if the array starts with [-and|or => ...], recurse with that logic
355 my $first = $clauses[0] || '';
356 if ($first =~ /^-(and|or)/i) {
359 return $self->_where_ARRAYREF(\@clauses, $logic);
363 my (@sql_clauses, @all_bind);
365 # need to use while() so can shift() for pairs
366 while (my $el = shift @clauses) {
368 # switch according to kind of $el and get corresponding ($sql, @bind)
369 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
371 # skip empty elements, otherwise get invalid trailing AND stuff
372 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
374 HASHREF => sub {$self->_recurse_where($el, 'and') if %$el},
375 # LDNOTE : previous SQLA code for hashrefs was creating a dirty
376 # side-effect: the first hashref within an array would change
377 # the global logic to 'AND'. So [ {cond1, cond2}, [cond3, cond4] ]
378 # was interpreted as "(cond1 AND cond2) OR (cond3 AND cond4)",
379 # whereas it should be "(cond1 AND cond2) OR (cond3 OR cond4)".
381 SCALARREF => sub { ($$el); },
383 SCALAR => sub {# top-level arrayref with scalars, recurse in pairs
384 $self->_recurse_where({$el => shift(@clauses)})},
386 UNDEF => sub {puke "not supported : UNDEF in arrayref" },
390 push @sql_clauses, $sql;
391 push @all_bind, @bind;
395 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
400 #======================================================================
401 # WHERE: top-level HASHREF
402 #======================================================================
405 my ($self, $where) = @_;
406 my (@sql_clauses, @all_bind);
408 # LDNOTE : don't really know why we need to sort keys
409 for my $k (sort keys %$where) {
410 my $v = $where->{$k};
412 # ($k => $v) is either a special op or a regular hashpair
413 my ($sql, @bind) = ($k =~ /^-(.+)/) ? $self->_where_op_in_hash($1, $v)
415 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
416 $self->$method($k, $v);
419 push @sql_clauses, $sql;
420 push @all_bind, @bind;
423 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
427 sub _where_op_in_hash {
428 my ($self, $op, $v) = @_;
430 $op =~ /^(AND|OR|NEST)[_\d]*/i
431 or puke "unknown operator: -$op";
432 $op = uc($1); # uppercase, remove trailing digits
433 $self->_debug("OP(-$op) within hashref, recursing...");
435 $self->_SWITCH_refkind($v, {
438 # LDNOTE : should deprecate {-or => [...]} and {-and => [...]}
439 # because they are misleading; the only proper way would be
440 # -nest => [-or => ...], -nest => [-and ...]
441 return $self->_where_ARRAYREF($v, $op eq 'NEST' ? '' : $op);
446 belch "-or => {...} should be -nest => [...]";
447 return $self->_where_ARRAYREF([%$v], 'OR');
450 return $self->_where_HASHREF($v);
454 SCALARREF => sub { # literal SQL
456 or puke "-$op => \\\$scalar not supported, use -nest => ...";
460 ARRAYREFREF => sub { # literal SQL
462 or puke "-$op => \\[..] not supported, use -nest => ...";
466 SCALAR => sub { # permissively interpreted as SQL
468 or puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
469 belch "literal SQL should be -nest => \\'scalar' "
470 . "instead of -nest => 'scalar' ";
475 puke "-$op => undef not supported";
481 sub _where_hashpair_ARRAYREF {
482 my ($self, $k, $v) = @_;
485 my @v = @$v; # need copy because of shift below
486 $self->_debug("ARRAY($k) means distribute over elements");
488 # put apart first element if it is an operator (-and, -or)
489 my $op = $v[0] =~ /^-/ ? shift @v : undef;
490 $self->_debug("OP($op) reinjected into the distributed array") if $op;
492 my @distributed = map { {$k => $_} } @v;
493 unshift @distributed, $op if $op;
495 return $self->_recurse_where(\@distributed);
498 # LDNOTE : not sure of this one. What does "distribute over nothing" mean?
499 $self->_debug("empty ARRAY($k) means 0=1");
500 return ($self->{sqlfalse});
504 sub _where_hashpair_HASHREF {
505 my ($self, $k, $v) = @_;
507 my (@all_sql, @all_bind);
509 for my $op (sort keys %$v) {
512 # put the operator in canonical form
513 $op =~ s/^-//; # remove initial dash
514 $op =~ tr/_/ /; # underscores become spaces
515 $op =~ s/^\s+//; # no initial space
516 $op =~ s/\s+$//; # no final space
517 $op =~ s/\s+/ /; # multiple spaces become one
521 # CASE: special operators like -in or -between
522 my $special_op = first {$op =~ $_->{regex}} @{$self->{special_ops}};
524 ($sql, @bind) = $special_op->{handler}->($self, $k, $op, $val);
527 $self->_SWITCH_refkind($val, {
529 ARRAYREF => sub { # CASE: col => {op => \@vals}
530 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
533 SCALARREF => sub { # CASE: col => {op => \$scalar}
534 $sql = join ' ', $self->_convert($self->_quote($k)),
535 $self->_sqlcase($op),
539 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]}
540 my ($sub_sql, @sub_bind) = @$$val;
541 $sql = join ' ', $self->_convert($self->_quote($k)),
542 $self->_sqlcase($op),
547 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
548 my $is = ($op =~ $self->{equality_op}) ? 'is' :
549 ($op =~ $self->{inequality_op}) ? 'is not' :
550 puke "unexpected operator '$op' with undef operand";
551 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
554 FALLBACK => sub { # CASE: col => {op => $scalar}
555 $sql = join ' ', $self->_convert($self->_quote($k)),
556 $self->_sqlcase($op),
557 $self->_convert('?');
558 @bind = $self->_bindtype($k, $val);
564 push @all_bind, @bind;
567 return $self->_join_sql_clauses('and', \@all_sql, \@all_bind);
572 sub _where_field_op_ARRAYREF {
573 my ($self, $k, $op, $vals) = @_;
576 $self->_debug("ARRAY($vals) means multiple elements: [ @$vals ]");
580 # LDNOTE : change the distribution logic when
581 # $op =~ $self->{inequality_op}, because of Morgan laws :
582 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
583 # WHERE field != 22 OR field != 33 : the user probably means
584 # WHERE field != 22 AND field != 33.
585 my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
587 # distribute $op over each member of @$vals
588 return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
592 # try to DWIM on equality operators
593 # LDNOTE : not 100% sure this is the correct thing to do ...
594 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
595 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
598 puke "operator '$op' applied on an empty array (field '$k')";
603 sub _where_hashpair_SCALARREF {
604 my ($self, $k, $v) = @_;
605 $self->_debug("SCALAR($k) means literal SQL: $$v");
606 my $sql = $self->_quote($k) . " " . $$v;
610 sub _where_hashpair_ARRAYREFREF {
611 my ($self, $k, $v) = @_;
612 $self->_debug("REF($k) means literal SQL: @${$v}");
613 my ($sql, @bind) = @${$v};
614 $sql = $self->_quote($k) . " " . $sql;
615 @bind = $self->_bindtype($k, @bind);
616 return ($sql, @bind );
619 sub _where_hashpair_SCALAR {
620 my ($self, $k, $v) = @_;
621 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
622 my $sql = join ' ', $self->_convert($self->_quote($k)),
623 $self->_sqlcase($self->{cmp}),
624 $self->_convert('?');
625 my @bind = $self->_bindtype($k, $v);
626 return ( $sql, @bind);
630 sub _where_hashpair_UNDEF {
631 my ($self, $k, $v) = @_;
632 $self->_debug("UNDEF($k) means IS NULL");
633 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
637 #======================================================================
638 # WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
639 #======================================================================
642 sub _where_SCALARREF {
643 my ($self, $where) = @_;
646 $self->_debug("SCALAR(*top) means literal SQL: $$where");
652 my ($self, $where) = @_;
655 $self->_debug("NOREF(*top) means literal SQL: $where");
666 #======================================================================
667 # WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
668 #======================================================================
671 sub _where_field_BETWEEN {
672 my ($self, $k, $op, $vals) = @_;
674 ref $vals eq 'ARRAY' && @$vals == 2
675 or puke "special op 'between' requires an arrayref of two values";
677 my ($label) = $self->_convert($self->_quote($k));
678 my ($placeholder) = $self->_convert('?');
679 my $and = $self->_sqlcase('and');
680 $op = $self->_sqlcase($op);
682 my $sql = "( $label $op $placeholder $and $placeholder )";
683 my @bind = $self->_bindtype($k, @$vals);
688 sub _where_field_IN {
689 my ($self, $k, $op, $vals) = @_;
691 # backwards compatibility : if scalar, force into an arrayref
692 $vals = [$vals] if defined $vals && ! ref $vals;
695 or puke "special op 'in' requires an arrayref";
697 my ($label) = $self->_convert($self->_quote($k));
698 my ($placeholder) = $self->_convert('?');
699 my $and = $self->_sqlcase('and');
700 $op = $self->_sqlcase($op);
702 if (@$vals) { # nonempty list
703 my $placeholders = join ", ", (($placeholder) x @$vals);
704 my $sql = "$label $op ( $placeholders )";
705 my @bind = $self->_bindtype($k, @$vals);
707 return ($sql, @bind);
709 else { # empty list : some databases won't understand "IN ()", so DWIM
710 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
720 #======================================================================
722 #======================================================================
725 my ($self, $arg) = @_;
727 # construct list of ordering instructions
728 my @order = $self->_SWITCH_refkind($arg, {
731 map {$self->_SWITCH_refkind($_, {
732 SCALAR => sub {$self->_quote($_)},
734 SCALARREF => sub {$$_}, # literal SQL, no quoting
735 HASHREF => sub {$self->_order_by_hash($_)}
739 SCALAR => sub {$self->_quote($arg)},
741 SCALARREF => sub {$$arg}, # literal SQL, no quoting
742 HASHREF => sub {$self->_order_by_hash($arg)},
747 my $order = join ', ', @order;
748 return $order ? $self->_sqlcase(' order by')." $order" : '';
753 my ($self, $hash) = @_;
755 # get first pair in hash
756 my ($key, $val) = each %$hash;
758 # check if one pair was found and no other pair in hash
759 $key && !(each %$hash)
760 or puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
762 my ($order) = ($key =~ /^-(desc|asc)/i)
763 or puke "invalid key in _order_by hash : $key";
765 return $self->_quote($val) ." ". $self->_sqlcase($order);
770 #======================================================================
771 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
772 #======================================================================
777 $self->_SWITCH_refkind($from, {
778 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
779 SCALAR => sub {$self->_quote($from)},
780 SCALARREF => sub {$$from},
781 ARRAYREFREF => sub {join ', ', @$from;},
786 #======================================================================
788 #======================================================================
794 $label or puke "can't quote an empty label";
796 # left and right quote characters
797 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
798 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
799 ARRAYREF => sub {@{$self->{quote_char}}},
803 or puke "quote_char must be an arrayref of 2 values";
805 # no quoting if no quoting chars
806 $ql or return $label;
808 # no quoting for literal SQL
809 return $$label if ref($label) eq 'SCALAR';
811 # separate table / column (if applicable)
812 my $sep = $self->{name_sep} || '';
813 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
815 # do the quoting, except for "*" or for `table`.*
816 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
818 # reassemble and return.
819 return join $sep, @quoted;
823 # Conversion, if applicable
825 my ($self, $arg) = @_;
827 # LDNOTE : modified the previous implementation below because
828 # it was not consistent : the first "return" is always an array,
829 # the second "return" is context-dependent. Anyway, _convert
830 # seems always used with just a single argument, so make it a
832 # return @_ unless $self->{convert};
833 # my $conv = $self->_sqlcase($self->{convert});
834 # my @ret = map { $conv.'('.$_.')' } @_;
835 # return wantarray ? @ret : $ret[0];
836 if ($self->{convert}) {
837 my $conv = $self->_sqlcase($self->{convert});
838 $arg = $conv.'('.$arg.')';
846 my($col, @vals) = @_;
848 #LDNOTE : changed original implementation below because it did not make
849 # sense when bindtype eq 'columns' and @vals > 1.
850 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
852 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
855 sub _join_sql_clauses {
856 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
858 if (@$clauses_aref > 1) {
859 my $join = " " . $self->_sqlcase($logic) . " ";
860 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
861 return ($sql, @$bind_aref);
863 elsif (@$clauses_aref) {
864 return ($clauses_aref->[0], @$bind_aref); # no parentheses
867 return (); # if no SQL, ignore @$bind_aref
872 # Fix SQL case, if so requested
876 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
877 # don't touch the argument ... crooked logic, but let's not change it!
878 return $self->{case} ? $_[0] : uc($_[0]);
882 #======================================================================
883 # DISPATCHING FROM REFKIND
884 #======================================================================
887 my ($self, $data) = @_;
893 # blessed objects are treated like scalars
894 $ref = (blessed $data) ? '' : ref $data;
895 $n_steps += 1 if $ref;
896 last if $ref ne 'REF';
900 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
902 return $base . ('REF' x $n_steps);
908 my ($self, $data) = @_;
909 my @try = ($self->_refkind($data));
910 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
911 push @try, 'FALLBACK';
915 sub _METHOD_FOR_refkind {
916 my ($self, $meth_prefix, $data) = @_;
917 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
918 $self->_try_refkind($data)
919 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
924 sub _SWITCH_refkind {
925 my ($self, $data, $dispatch_table) = @_;
927 my $coderef = first {$_} map {$dispatch_table->{$_}}
928 $self->_try_refkind($data)
929 or puke "no dispatch entry for ".$self->_refkind($data);
936 #======================================================================
937 # VALUES, GENERATE, AUTOLOAD
938 #======================================================================
940 # LDNOTE: original code from nwiger, didn't touch code in that section
941 # I feel the AUTOLOAD stuff should not be the default, it should
942 # only be activated on explicit demand by user.
946 my $data = shift || return;
947 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
948 unless ref $data eq 'HASH';
949 return map { $self->_bindtype($_, $data->{$_}) } sort keys %$data;
955 my(@sql, @sqlq, @sqlv);
959 if ($ref eq 'HASH') {
960 for my $k (sort keys %$_) {
963 my $label = $self->_quote($k);
965 # SQL included for values
967 my $sql = shift @bind;
968 push @sqlq, "$label = $sql";
969 push @sqlv, $self->_bindtype($k, @bind);
970 } elsif ($r eq 'SCALAR') {
971 # embedded literal SQL
972 push @sqlq, "$label = $$v";
974 push @sqlq, "$label = ?";
975 push @sqlv, $self->_bindtype($k, $v);
978 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
979 } elsif ($ref eq 'ARRAY') {
980 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
985 push @sqlq, shift @val;
987 } elsif ($r eq 'SCALAR') {
988 # embedded literal SQL
995 push @sql, '(' . join(', ', @sqlq) . ')';
996 } elsif ($ref eq 'SCALAR') {
1000 # strings get case twiddled
1001 push @sql, $self->_sqlcase($_);
1005 my $sql = join ' ', @sql;
1007 # this is pretty tricky
1008 # if ask for an array, return ($stmt, @bind)
1009 # otherwise, s/?/shift @sqlv/ to put it inline
1011 return ($sql, @sqlv);
1013 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1014 ref $d ? $d->[1] : $d/e;
1023 # This allows us to check for a local, then _form, attr
1025 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1026 return $self->generate($name, @_);
1037 SQL::Abstract - Generate SQL from Perl data structures
1043 my $sql = SQL::Abstract->new;
1045 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1047 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1049 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1051 my($stmt, @bind) = $sql->delete($table, \%where);
1053 # Then, use these in your DBI statements
1054 my $sth = $dbh->prepare($stmt);
1055 $sth->execute(@bind);
1057 # Just generate the WHERE clause
1058 my($stmt, @bind) = $sql->where(\%where, \@order);
1060 # Return values in the same order, for hashed queries
1061 # See PERFORMANCE section for more details
1062 my @bind = $sql->values(\%fieldvals);
1066 This module was inspired by the excellent L<DBIx::Abstract>.
1067 However, in using that module I found that what I really wanted
1068 to do was generate SQL, but still retain complete control over my
1069 statement handles and use the DBI interface. So, I set out to
1070 create an abstract SQL generation module.
1072 While based on the concepts used by L<DBIx::Abstract>, there are
1073 several important differences, especially when it comes to WHERE
1074 clauses. I have modified the concepts used to make the SQL easier
1075 to generate from Perl data structures and, IMO, more intuitive.
1076 The underlying idea is for this module to do what you mean, based
1077 on the data structures you provide it. The big advantage is that
1078 you don't have to modify your code every time your data changes,
1079 as this module figures it out.
1081 To begin with, an SQL INSERT is as easy as just specifying a hash
1082 of C<key=value> pairs:
1085 name => 'Jimbo Bobson',
1086 phone => '123-456-7890',
1087 address => '42 Sister Lane',
1088 city => 'St. Louis',
1089 state => 'Louisiana',
1092 The SQL can then be generated with this:
1094 my($stmt, @bind) = $sql->insert('people', \%data);
1096 Which would give you something like this:
1098 $stmt = "INSERT INTO people
1099 (address, city, name, phone, state)
1100 VALUES (?, ?, ?, ?, ?)";
1101 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1102 '123-456-7890', 'Louisiana');
1104 These are then used directly in your DBI code:
1106 my $sth = $dbh->prepare($stmt);
1107 $sth->execute(@bind);
1109 =head2 Inserting and Updating Arrays
1111 If your database has array types (like for example Postgres),
1112 activate the special option C<< array_datatypes => 1 >>
1113 when creating the C<SQL::Abstract> object.
1114 Then you may use an arrayref to insert and update database array types:
1116 my $sql = SQL::Abstract->new(array_datatypes => 1);
1118 planets => [qw/Mercury Venus Earth Mars/]
1121 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1125 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1127 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1130 =head2 Inserting and Updating SQL
1132 In order to apply SQL functions to elements of your C<%data> you may
1133 specify a reference to an arrayref for the given hash value. For example,
1134 if you need to execute the Oracle C<to_date> function on a value, you can
1135 say something like this:
1139 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
1142 The first value in the array is the actual SQL. Any other values are
1143 optional and would be included in the bind values array. This gives
1146 my($stmt, @bind) = $sql->insert('people', \%data);
1148 $stmt = "INSERT INTO people (name, date_entered)
1149 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1150 @bind = ('Bill', '03/02/2003');
1152 An UPDATE is just as easy, all you change is the name of the function:
1154 my($stmt, @bind) = $sql->update('people', \%data);
1156 Notice that your C<%data> isn't touched; the module will generate
1157 the appropriately quirky SQL for you automatically. Usually you'll
1158 want to specify a WHERE clause for your UPDATE, though, which is
1159 where handling C<%where> hashes comes in handy...
1161 =head2 Complex where statements
1163 This module can generate pretty complicated WHERE statements
1164 easily. For example, simple C<key=value> pairs are taken to mean
1165 equality, and if you want to see if a field is within a set
1166 of values, you can use an arrayref. Let's say we wanted to
1167 SELECT some data based on this criteria:
1170 requestor => 'inna',
1171 worker => ['nwiger', 'rcwe', 'sfz'],
1172 status => { '!=', 'completed' }
1175 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1177 The above would give you something like this:
1179 $stmt = "SELECT * FROM tickets WHERE
1180 ( requestor = ? ) AND ( status != ? )
1181 AND ( worker = ? OR worker = ? OR worker = ? )";
1182 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1184 Which you could then use in DBI code like so:
1186 my $sth = $dbh->prepare($stmt);
1187 $sth->execute(@bind);
1193 The functions are simple. There's one for each major SQL operation,
1194 and a constructor you use first. The arguments are specified in a
1195 similar order to each function (table, then fields, then a where
1196 clause) to try and simplify things.
1201 =head2 new(option => 'value')
1203 The C<new()> function takes a list of options and values, and returns
1204 a new B<SQL::Abstract> object which can then be used to generate SQL
1205 through the methods below. The options accepted are:
1211 If set to 'lower', then SQL will be generated in all lowercase. By
1212 default SQL is generated in "textbook" case meaning something like:
1214 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1216 Any setting other than 'lower' is ignored.
1220 This determines what the default comparison operator is. By default
1221 it is C<=>, meaning that a hash like this:
1223 %where = (name => 'nwiger', email => 'nate@wiger.org');
1225 Will generate SQL like this:
1227 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1229 However, you may want loose comparisons by default, so if you set
1230 C<cmp> to C<like> you would get SQL such as:
1232 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1234 You can also override the comparsion on an individual basis - see
1235 the huge section on L</"WHERE CLAUSES"> at the bottom.
1237 =item sqltrue, sqlfalse
1239 Expressions for inserting boolean values within SQL statements.
1240 By default these are C<1=1> and C<1=0>.
1244 This determines the default logical operator for multiple WHERE
1245 statements in arrays. By default it is "or", meaning that a WHERE
1249 event_date => {'>=', '2/13/99'},
1250 event_date => {'<=', '4/24/03'},
1253 Will generate SQL like this:
1255 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1257 This is probably not what you want given this query, though (look
1258 at the dates). To change the "OR" to an "AND", simply specify:
1260 my $sql = SQL::Abstract->new(logic => 'and');
1262 Which will change the above C<WHERE> to:
1264 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1266 The logic can also be changed locally by inserting
1267 an extra first element in the array :
1269 @where = (-and => event_date => {'>=', '2/13/99'},
1270 event_date => {'<=', '4/24/03'} );
1272 See the L</"WHERE CLAUSES"> section for explanations.
1276 This will automatically convert comparisons using the specified SQL
1277 function for both column and value. This is mostly used with an argument
1278 of C<upper> or C<lower>, so that the SQL will have the effect of
1279 case-insensitive "searches". For example, this:
1281 $sql = SQL::Abstract->new(convert => 'upper');
1282 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1284 Will turn out the following SQL:
1286 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1288 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1289 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1290 not validate this option; it will just pass through what you specify verbatim).
1294 This is a kludge because many databases suck. For example, you can't
1295 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1296 Instead, you have to use C<bind_param()>:
1298 $sth->bind_param(1, 'reg data');
1299 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1301 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1302 which loses track of which field each slot refers to. Fear not.
1304 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1305 Currently, you can specify either C<normal> (default) or C<columns>. If you
1306 specify C<columns>, you will get an array that looks like this:
1308 my $sql = SQL::Abstract->new(bindtype => 'columns');
1309 my($stmt, @bind) = $sql->insert(...);
1312 [ 'column1', 'value1' ],
1313 [ 'column2', 'value2' ],
1314 [ 'column3', 'value3' ],
1317 You can then iterate through this manually, using DBI's C<bind_param()>.
1319 $sth->prepare($stmt);
1322 my($col, $data) = @$_;
1323 if ($col eq 'details' || $col eq 'comments') {
1324 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1325 } elsif ($col eq 'image') {
1326 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1328 $sth->bind_param($i, $data);
1332 $sth->execute; # execute without @bind now
1334 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1335 Basically, the advantage is still that you don't have to care which fields
1336 are or are not included. You could wrap that above C<for> loop in a simple
1337 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1338 get a layer of abstraction over manual SQL specification.
1342 This is the character that a table or column name will be quoted
1343 with. By default this is an empty string, but you could set it to
1344 the character C<`>, to generate SQL like this:
1346 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1348 Alternatively, you can supply an array ref of two items, the first being the left
1349 hand quote character, and the second the right hand quote character. For
1350 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1351 that generates SQL like this:
1353 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1355 Quoting is useful if you have tables or columns names that are reserved
1356 words in your database's SQL dialect.
1360 This is the character that separates a table and column name. It is
1361 necessary to specify this when the C<quote_char> option is selected,
1362 so that tables and column names can be individually quoted like this:
1364 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1366 =item array_datatypes
1368 When this option is true, arrayrefs in INSERT or UPDATE are
1369 interpreted as array datatypes and are passed directly
1371 When this option is false, arrayrefs are interpreted
1372 as literal SQL, just like refs to arrayrefs
1373 (but this behavior is for backwards compatibility; when writing
1374 new queries, use the "reference to arrayref" syntax
1380 Takes a reference to a list of "special operators"
1381 to extend the syntax understood by L<SQL::Abstract>.
1382 See section L</"SPECIAL OPERATORS"> for details.
1388 =head2 insert($table, \@values || \%fieldvals)
1390 This is the simplest function. You simply give it a table name
1391 and either an arrayref of values or hashref of field/value pairs.
1392 It returns an SQL INSERT statement and a list of bind values.
1393 See the sections on L</"Inserting and Updating Arrays"> and
1394 L</"Inserting and Updating SQL"> for information on how to insert
1395 with those data types.
1397 =head2 update($table, \%fieldvals, \%where)
1399 This takes a table, hashref of field/value pairs, and an optional
1400 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1402 See the sections on L</"Inserting and Updating Arrays"> and
1403 L</"Inserting and Updating SQL"> for information on how to insert
1404 with those data types.
1406 =head2 select($source, $fields, $where, $order)
1408 This returns a SQL SELECT statement and associated list of bind values, as
1409 specified by the arguments :
1415 Specification of the 'FROM' part of the statement.
1416 The argument can be either a plain scalar (interpreted as a table
1417 name, will be quoted), or an arrayref (interpreted as a list
1418 of table names, joined by commas, quoted), or a scalarref
1419 (literal table name, not quoted), or a ref to an arrayref
1420 (list of literal table names, joined by commas, not quoted).
1424 Specification of the list of fields to retrieve from
1426 The argument can be either an arrayref (interpreted as a list
1427 of field names, will be joined by commas and quoted), or a
1428 plain scalar (literal SQL, not quoted).
1429 Please observe that this API is not as flexible as for
1430 the first argument C<$table>, for backwards compatibility reasons.
1434 Optional argument to specify the WHERE part of the query.
1435 The argument is most often a hashref, but can also be
1436 an arrayref or plain scalar --
1437 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1441 Optional argument to specify the ORDER BY part of the query.
1442 The argument can be a scalar, a hashref or an arrayref
1443 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1449 =head2 delete($table, \%where)
1451 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1452 It returns an SQL DELETE statement and list of bind values.
1454 =head2 where(\%where, \@order)
1456 This is used to generate just the WHERE clause. For example,
1457 if you have an arbitrary data structure and know what the
1458 rest of your SQL is going to look like, but want an easy way
1459 to produce a WHERE clause, use this. It returns an SQL WHERE
1460 clause and list of bind values.
1463 =head2 values(\%data)
1465 This just returns the values from the hash C<%data>, in the same
1466 order that would be returned from any of the other above queries.
1467 Using this allows you to markedly speed up your queries if you
1468 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1470 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1472 Warning: This is an experimental method and subject to change.
1474 This returns arbitrarily generated SQL. It's a really basic shortcut.
1475 It will return two different things, depending on return context:
1477 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1478 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1480 These would return the following:
1482 # First calling form
1483 $stmt = "CREATE TABLE test (?, ?)";
1484 @bind = (field1, field2);
1486 # Second calling form
1487 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1489 Depending on what you're trying to do, it's up to you to choose the correct
1490 format. In this example, the second form is what you would want.
1494 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1498 ALTER SESSION SET nls_date_format = 'MM/YY'
1500 You get the idea. Strings get their case twiddled, but everything
1501 else remains verbatim.
1506 =head1 WHERE CLAUSES
1510 This module uses a variation on the idea from L<DBIx::Abstract>. It
1511 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1512 module is that things in arrays are OR'ed, and things in hashes
1515 The easiest way to explain is to show lots of examples. After
1516 each C<%where> hash shown, it is assumed you used:
1518 my($stmt, @bind) = $sql->where(\%where);
1520 However, note that the C<%where> hash can be used directly in any
1521 of the other functions as well, as described above.
1523 =head2 Key-value pairs
1525 So, let's get started. To begin, a simple hash:
1529 status => 'completed'
1532 Is converted to SQL C<key = val> statements:
1534 $stmt = "WHERE user = ? AND status = ?";
1535 @bind = ('nwiger', 'completed');
1537 One common thing I end up doing is having a list of values that
1538 a field can be in. To do this, simply specify a list inside of
1543 status => ['assigned', 'in-progress', 'pending'];
1546 This simple code will create the following:
1548 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1549 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1551 An empty arrayref will be considered a logical false and
1554 =head2 Key-value pairs
1556 If you want to specify a different type of operator for your comparison,
1557 you can use a hashref for a given column:
1561 status => { '!=', 'completed' }
1564 Which would generate:
1566 $stmt = "WHERE user = ? AND status != ?";
1567 @bind = ('nwiger', 'completed');
1569 To test against multiple values, just enclose the values in an arrayref:
1571 status => { '!=', ['assigned', 'in-progress', 'pending'] };
1573 Which would give you:
1575 "WHERE status != ? AND status != ? AND status != ?"
1577 Notice that since the operator was recognized as being a 'negative'
1578 operator, the arrayref was interpreted with 'AND' logic (because
1579 of Morgan's laws). By contrast, the reverse
1581 status => { '=', ['assigned', 'in-progress', 'pending'] };
1585 "WHERE status = ? OR status = ? OR status = ?"
1588 The hashref can also contain multiple pairs, in which case it is expanded
1589 into an C<AND> of its elements:
1593 status => { '!=', 'completed', -not_like => 'pending%' }
1596 # Or more dynamically, like from a form
1597 $where{user} = 'nwiger';
1598 $where{status}{'!='} = 'completed';
1599 $where{status}{'-not_like'} = 'pending%';
1601 # Both generate this
1602 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1603 @bind = ('nwiger', 'completed', 'pending%');
1606 To get an OR instead, you can combine it with the arrayref idea:
1610 priority => [ {'=', 2}, {'!=', 1} ]
1613 Which would generate:
1615 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1616 @bind = ('nwiger', '2', '1');
1618 If you want to include literal SQL (with or without bind values), just use a
1619 scalar reference or array reference as the value:
1622 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1623 date_expires => { '<' => \"now()" }
1626 Which would generate:
1628 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1629 @bind = ('11/26/2008');
1632 =head2 Logic and nesting operators
1634 In the example above,
1635 there is a subtle trap if you want to say something like
1636 this (notice the C<AND>):
1638 WHERE priority != ? AND priority != ?
1640 Because, in Perl you I<can't> do this:
1642 priority => { '!=', 2, '!=', 1 }
1644 As the second C<!=> key will obliterate the first. The solution
1645 is to use the special C<-modifier> form inside an arrayref:
1647 priority => [ -and => {'!=', 2},
1651 Normally, these would be joined by C<OR>, but the modifier tells it
1652 to use C<AND> instead. (Hint: You can use this in conjunction with the
1653 C<logic> option to C<new()> in order to change the way your queries
1654 work by default.) B<Important:> Note that the C<-modifier> goes
1655 B<INSIDE> the arrayref, as an extra first element. This will
1656 B<NOT> do what you think it might:
1658 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1660 Here is a quick list of equivalencies, since there is some overlap:
1663 status => {'!=', 'completed', 'not like', 'pending%' }
1664 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1667 status => {'=', ['assigned', 'in-progress']}
1668 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1669 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1671 In addition to C<-and> and C<-or>, there is also a special C<-nest>
1672 operator which adds an additional set of parens, to create a subquery.
1673 For example, to get something like this:
1675 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
1676 @bind = ('nwiger', '20', 'ASIA');
1682 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1685 If you need several nested subexpressions, you can number
1686 the C<-nest> branches :
1696 =head2 Special operators : IN, BETWEEN, etc.
1698 You can also use the hashref format to compare a list of fields using the
1699 C<IN> comparison operator, by specifying the list as an arrayref:
1702 status => 'completed',
1703 reportid => { -in => [567, 2335, 2] }
1706 Which would generate:
1708 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1709 @bind = ('completed', '567', '2335', '2');
1711 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1714 Another pair of operators is C<-between> and C<-not_between>,
1715 used with an arrayref of two values:
1719 completion_date => {
1720 -not_between => ['2002-10-01', '2003-02-06']
1726 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1728 These are the two builtin "special operators"; but the
1729 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1731 =head2 Nested conditions
1733 So far, we've seen how multiple conditions are joined with a top-level
1734 C<AND>. We can change this by putting the different conditions we want in
1735 hashes and then putting those hashes in an array. For example:
1740 status => { -like => ['pending%', 'dispatched'] },
1744 status => 'unassigned',
1748 This data structure would create the following:
1750 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1751 OR ( user = ? AND status = ? ) )";
1752 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1754 This can be combined with the C<-nest> operator to properly group
1761 ["-and", workhrs => {'>', 20}, geo => 'ASIA' ],
1762 ["-and", workhrs => {'<', 50}, geo => 'EURO' ]
1769 WHERE ( user = ? AND
1770 ( ( workhrs > ? AND geo = ? )
1771 OR ( workhrs < ? AND geo = ? ) ) )
1775 Finally, sometimes only literal SQL will do. If you want to include
1776 literal SQL verbatim, you can specify it as a scalar reference, namely:
1778 my $inn = 'is Not Null';
1780 priority => { '<', 2 },
1786 $stmt = "WHERE priority < ? AND requestor is Not Null";
1789 Note that in this example, you only get one bind parameter back, since
1790 the verbatim SQL is passed as part of the statement.
1792 Of course, just to prove a point, the above can also be accomplished
1796 priority => { '<', 2 },
1797 requestor => { '!=', undef },
1803 Conditions on boolean columns can be expressed in the
1804 same way, passing a reference to an empty string :
1807 priority => { '<', 2 },
1813 $stmt = "WHERE priority < ? AND is_ready";
1817 =head2 Literal SQL with placeholders and bind values (subqueries)
1819 If the literal SQL to be inserted has placeholders and bind values,
1820 use a reference to an arrayref (yes this is a double reference --
1821 not so common, but perfectly legal Perl). For example, to find a date
1822 in Postgres you can use something like this:
1825 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1830 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
1834 Literal SQL is especially useful for nesting parenthesized clauses in the
1835 main SQL query. Here is a first example :
1837 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1841 bar => \["IN ($sub_stmt)" => @sub_bind],
1846 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
1847 WHERE c2 < ? AND c3 LIKE ?))";
1848 @bind = (1234, 100, "foo%");
1850 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
1851 are expressed in the same way. Of course the C<$sub_stmt> and
1852 its associated bind values can be generated through a former call
1855 my ($sub_stmt, @sub_bind)
1856 = $sql->select("t1", "c1", {c2 => {"<" => 100},
1857 c3 => {-like => "foo%"}});
1860 bar => \["> ALL ($sub_stmt)" => @sub_bind],
1863 In the examples above, the subquery was used as an operator on a column;
1864 but the same principle also applies for a clause within the main C<%where>
1865 hash, like an EXISTS subquery :
1867 my ($sub_stmt, @sub_bind)
1868 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
1871 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
1876 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
1877 WHERE c1 = ? AND c2 > t0.c0))";
1881 Observe that the condition on C<c2> in the subquery refers to
1882 column C<t0.c0> of the main query : this is I<not> a bind
1883 value, so we have to express it through a scalar ref.
1884 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
1885 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
1886 what we wanted here.
1888 Another use of the subquery technique is when some SQL clauses need
1889 parentheses, as it often occurs with some proprietary SQL extensions
1890 like for example fulltext expressions, geospatial expressions,
1891 NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
1894 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
1897 Finally, here is an example where a subquery is used
1898 for expressing unary negation:
1900 my ($sub_stmt, @sub_bind)
1901 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
1902 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
1904 lname => {like => '%son%'},
1905 -nest => \["NOT ($sub_stmt)" => @sub_bind],
1910 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
1911 @bind = ('%son%', 10, 20)
1917 These pages could go on for a while, since the nesting of the data
1918 structures this module can handle are pretty much unlimited (the
1919 module implements the C<WHERE> expansion as a recursive function
1920 internally). Your best bet is to "play around" with the module a
1921 little to see how the data structures behave, and choose the best
1922 format for your data based on that.
1924 And of course, all the values above will probably be replaced with
1925 variables gotten from forms or the command line. After all, if you
1926 knew everything ahead of time, you wouldn't have to worry about
1927 dynamically-generating SQL and could just hardwire it into your
1933 =head1 ORDER BY CLAUSES
1935 Some functions take an order by clause. This can either be a scalar (just a
1936 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1937 or an array of either of the two previous forms. Examples:
1939 Given | Will Generate
1940 ----------------------------------------------------------
1941 \'colA DESC' | ORDER BY colA DESC
1942 'colA' | ORDER BY colA
1943 [qw/colA colB/] | ORDER BY colA, colB
1944 {-asc => 'colA'} | ORDER BY colA ASC
1945 {-desc => 'colB'} | ORDER BY colB DESC
1947 {-asc => 'colA'}, | ORDER BY colA ASC, colB DESC
1950 [colA => {-asc => 'colB'}] | ORDER BY colA, colB ASC
1951 ==========================================================
1955 =head1 SPECIAL OPERATORS
1957 my $sqlmaker = SQL::Abstract->new(special_ops => [
1960 my ($self, $field, $op, $arg) = @_;
1966 A "special operator" is a SQL syntactic clause that can be
1967 applied to a field, instead of a usual binary operator.
1970 WHERE field IN (?, ?, ?)
1971 WHERE field BETWEEN ? AND ?
1972 WHERE MATCH(field) AGAINST (?, ?)
1974 Special operators IN and BETWEEN are fairly standard and therefore
1975 are builtin within C<SQL::Abstract>. For other operators,
1976 like the MATCH .. AGAINST example above which is
1977 specific to MySQL, you can write your own operator handlers :
1978 supply a C<special_ops> argument to the C<new> method.
1979 That argument takes an arrayref of operator definitions;
1980 each operator definition is a hashref with two entries
1986 the regular expression to match the operator
1990 coderef that will be called when meeting that operator
1991 in the input tree. The coderef will be called with
1992 arguments C<< ($self, $field, $op, $arg) >>, and
1993 should return a C<< ($sql, @bind) >> structure.
1997 For example, here is an implementation
1998 of the MATCH .. AGAINST syntax for MySQL
2000 my $sqlmaker = SQL::Abstract->new(special_ops => [
2002 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2003 {regex => qr/^match$/i,
2005 my ($self, $field, $op, $arg) = @_;
2006 $arg = [$arg] if not ref $arg;
2007 my $label = $self->_quote($field);
2008 my ($placeholder) = $self->_convert('?');
2009 my $placeholders = join ", ", (($placeholder) x @$arg);
2010 my $sql = $self->_sqlcase('match') . " ($label) "
2011 . $self->_sqlcase('against') . " ($placeholders) ";
2012 my @bind = $self->_bindtype($field, @$arg);
2013 return ($sql, @bind);
2022 Thanks to some benchmarking by Mark Stosberg, it turns out that
2023 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2024 I must admit this wasn't an intentional design issue, but it's a
2025 byproduct of the fact that you get to control your C<DBI> handles
2028 To maximize performance, use a code snippet like the following:
2030 # prepare a statement handle using the first row
2031 # and then reuse it for the rest of the rows
2033 for my $href (@array_of_hashrefs) {
2034 $stmt ||= $sql->insert('table', $href);
2035 $sth ||= $dbh->prepare($stmt);
2036 $sth->execute($sql->values($href));
2039 The reason this works is because the keys in your C<$href> are sorted
2040 internally by B<SQL::Abstract>. Thus, as long as your data retains
2041 the same structure, you only have to generate the SQL the first time
2042 around. On subsequent queries, simply use the C<values> function provided
2043 by this module to return your values in the correct order.
2048 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2049 really like this part (I do, at least). Building up a complex query
2050 can be as simple as the following:
2054 use CGI::FormBuilder;
2057 my $form = CGI::FormBuilder->new(...);
2058 my $sql = SQL::Abstract->new;
2060 if ($form->submitted) {
2061 my $field = $form->field;
2062 my $id = delete $field->{id};
2063 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2066 Of course, you would still have to connect using C<DBI> to run the
2067 query, but the point is that if you make your form look like your
2068 table, the actual query script can be extremely simplistic.
2070 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2071 a fast interface to returning and formatting data. I frequently
2072 use these three modules together to write complex database query
2073 apps in under 50 lines.
2078 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2079 Great care has been taken to preserve the I<published> behavior
2080 documented in previous versions in the 1.* family; however,
2081 some features that were previously undocumented, or behaved
2082 differently from the documentation, had to be changed in order
2083 to clarify the semantics. Hence, client code that was relying
2084 on some dark areas of C<SQL::Abstract> v1.*
2085 B<might behave differently> in v1.50.
2087 The main changes are :
2093 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2097 support for the { operator => \"..." } construct (to embed literal SQL)
2101 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2105 added -nest1, -nest2 or -nest_1, -nest_2, ...
2109 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2113 defensive programming : check arguments
2117 fixed bug with global logic, which was previously implemented
2118 through global variables yielding side-effects. Prior versons would
2119 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2120 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2121 Now this is interpreted
2122 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2126 C<-and> / C<-or> operators are no longer accepted
2127 in the middle of an arrayref : they are
2128 only admitted if in first position.
2132 changed logic for distributing an op over arrayrefs
2136 fixed semantics of _bindtype on array args
2140 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2141 we just avoid shifting arrays within that tree.
2145 dropped the C<_modlogic> function
2151 =head1 ACKNOWLEDGEMENTS
2153 There are a number of individuals that have really helped out with
2154 this module. Unfortunately, most of them submitted bugs via CPAN
2155 so I have no idea who they are! But the people I do know are:
2157 Ash Berlin (order_by hash term support)
2158 Matt Trout (DBIx::Class support)
2159 Mark Stosberg (benchmarking)
2160 Chas Owens (initial "IN" operator support)
2161 Philip Collins (per-field SQL functions)
2162 Eric Kolve (hashref "AND" support)
2163 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2164 Dan Kubb (support for "quote_char" and "name_sep")
2165 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2166 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
2172 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2176 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2178 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
2180 For support, your best bet is to try the C<DBIx::Class> users mailing list.
2181 While not an official support venue, C<DBIx::Class> makes heavy use of
2182 C<SQL::Abstract>, and as such list members there are very familiar with
2183 how to create queries.
2185 This module is free software; you may copy this under the terms of
2186 the GNU General Public License, or the Artistic License, copies of
2187 which should have accompanied your Perl kit.