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.51';
20 # This would confuse some packagers
21 #$VERSION = eval $VERSION; # numify for warning-free dev releases
25 # special operators (-in, -between). May be extended/overridden by user.
26 # See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
27 my @BUILTIN_SPECIAL_OPS = (
28 {regex => qr/^(not )?between$/i, handler => \&_where_field_BETWEEN},
29 {regex => qr/^(not )?in$/i, handler => \&_where_field_IN},
32 #======================================================================
33 # DEBUGGING AND ERROR REPORTING
34 #======================================================================
37 return unless $_[0]->{debug}; shift; # a little faster
38 my $func = (caller(1))[3];
39 warn "[$func] ", @_, "\n";
43 my($func) = (caller(1))[3];
44 carp "[$func] Warning: ", @_;
48 my($func) = (caller(1))[3];
49 croak "[$func] Fatal: ", @_;
53 #======================================================================
55 #======================================================================
59 my $class = ref($self) || $self;
60 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
62 # choose our case by keeping an option around
63 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
65 # default logic for interpreting arrayrefs
66 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
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';
73 # default comparison is "=", but can be overridden
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;
82 $opt{sqltrue} ||= '1=1';
83 $opt{sqlfalse} ||= '0=1';
86 $opt{special_ops} ||= [];
87 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
89 return bless \%opt, $class;
94 #======================================================================
96 #======================================================================
100 my $table = $self->_table(shift);
101 my $data = shift || return;
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;
109 sub _insert_HASHREF { # explicit list of fields and then values
110 my ($self, $data) = @_;
112 my @fields = sort keys %$data;
114 my ($sql, @bind) = $self->_insert_values($data);
117 $_ = $self->_quote($_) foreach @fields;
118 $sql = "( ".join(", ", @fields).") ".$sql;
120 return ($sql, @bind);
123 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
124 my ($self, $data) = @_;
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";
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 };
136 return $self->_insert_values($data_in_hash);
139 sub _insert_ARRAYREFREF { # literal SQL with bind
140 my ($self, $data) = @_;
142 my ($sql, @bind) = @${$data};
143 $self->_assert_bindval_matches_bindtype(@bind);
145 return ($sql, @bind);
149 sub _insert_SCALARREF { # literal SQL without bind
150 my ($self, $data) = @_;
156 my ($self, $data) = @_;
158 my (@values, @all_bind);
159 foreach my $column (sort keys %$data) {
160 my $v = $data->{$column};
162 $self->_SWITCH_refkind($v, {
165 if ($self->{array_datatypes}) { # if array datatype are activated
167 push @all_bind, $self->_bindtype($column, $v);
169 else { # else literal SQL with bind
170 my ($sql, @bind) = @$v;
171 $self->_assert_bindval_matches_bindtype(@bind);
173 push @all_bind, @bind;
177 ARRAYREFREF => sub { # literal SQL with bind
178 my ($sql, @bind) = @${$v};
179 $self->_assert_bindval_matches_bindtype(@bind);
181 push @all_bind, @bind;
184 # THINK : anything useful to do with a HASHREF ?
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";
189 push @all_bind, $self->_bindtype($column, $v);
192 SCALARREF => sub { # literal SQL without bind
196 SCALAR_or_UNDEF => sub {
198 push @all_bind, $self->_bindtype($column, $v);
205 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
206 return ($sql, @all_bind);
211 #======================================================================
213 #======================================================================
218 my $table = $self->_table(shift);
219 my $data = shift || return;
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';
227 for my $k (sort keys %$data) {
230 my $label = $self->_quote($k);
232 $self->_SWITCH_refkind($v, {
234 if ($self->{array_datatypes}) { # array datatype
235 push @set, "$label = ?";
236 push @all_bind, $self->_bindtype($k, $v);
238 else { # literal SQL with bind
239 my ($sql, @bind) = @$v;
240 $self->_assert_bindval_matches_bindtype(@bind);
241 push @set, "$label = $sql";
242 push @all_bind, @bind;
245 ARRAYREFREF => sub { # literal SQL with bind
246 my ($sql, @bind) = @${$v};
247 $self->_assert_bindval_matches_bindtype(@bind);
248 push @set, "$label = $sql";
249 push @all_bind, @bind;
251 SCALARREF => sub { # literal SQL without bind
252 push @set, "$label = $$v";
254 SCALAR_or_UNDEF => sub {
255 push @set, "$label = ?";
256 push @all_bind, $self->_bindtype($k, $v);
262 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ')
266 my($where_sql, @where_bind) = $self->where($where);
268 push @all_bind, @where_bind;
271 return wantarray ? ($sql, @all_bind) : $sql;
277 #======================================================================
279 #======================================================================
284 my $table = $self->_table(shift);
285 my $fields = shift || '*';
289 my($where_sql, @bind) = $self->where($where, $order);
291 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields
293 my $sql = join(' ', $self->_sqlcase('select'), $f,
294 $self->_sqlcase('from'), $table)
297 return wantarray ? ($sql, @bind) : $sql;
300 #======================================================================
302 #======================================================================
307 my $table = $self->_table(shift);
311 my($where_sql, @bind) = $self->where($where);
312 my $sql = $self->_sqlcase('delete from') . " $table" . $where_sql;
314 return wantarray ? ($sql, @bind) : $sql;
318 #======================================================================
320 #======================================================================
324 # Finally, a separate routine just to handle WHERE clauses
326 my ($self, $where, $order) = @_;
329 my ($sql, @bind) = $self->_recurse_where($where);
330 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
334 $sql .= $self->_order_by($order);
337 return wantarray ? ($sql, @bind) : $sql;
342 my ($self, $where, $logic) = @_;
344 # dispatch on appropriate method according to refkind of $where
345 my $method = $self->_METHOD_FOR_refkind("_where", $where);
348 my ($sql, @bind) = $self->$method($where, $logic);
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;
357 #======================================================================
358 # WHERE: top-level ARRAYREF
359 #======================================================================
362 sub _where_ARRAYREF {
363 my ($self, $where, $logic) = @_;
365 $logic = uc($logic || $self->{logic});
366 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
368 my @clauses = @$where;
370 my (@sql_clauses, @all_bind);
371 # need to use while() so can shift() for pairs
372 while (my $el = shift @clauses) {
374 # switch according to kind of $el and get corresponding ($sql, @bind)
375 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
377 # skip empty elements, otherwise get invalid trailing AND stuff
378 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
380 ARRAYREFREF => sub { @{${$el}} if @{${$el}}},
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)".
389 SCALARREF => sub { ($$el); },
391 SCALAR => sub {# top-level arrayref with scalars, recurse in pairs
392 $self->_recurse_where({$el => shift(@clauses)})},
394 UNDEF => sub {puke "not supported : UNDEF in arrayref" },
398 push @sql_clauses, $sql;
399 push @all_bind, @bind;
403 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
406 #======================================================================
407 # WHERE: top-level ARRAYREFREF
408 #======================================================================
410 sub _where_ARRAYREFREF {
411 my ($self, $where) = @_;
412 my ($sql, @bind) = @{${$where}};
414 return ($sql, @bind);
417 #======================================================================
418 # WHERE: top-level HASHREF
419 #======================================================================
422 my ($self, $where) = @_;
423 my (@sql_clauses, @all_bind);
425 # LDNOTE : don't really know why we need to sort keys
426 for my $k (sort keys %$where) {
427 my $v = $where->{$k};
429 # ($k => $v) is either a special op or a regular hashpair
430 my ($sql, @bind) = ($k =~ /^-(.+)/) ? $self->_where_op_in_hash($1, $v)
432 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
433 $self->$method($k, $v);
436 push @sql_clauses, $sql;
437 push @all_bind, @bind;
440 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
444 sub _where_op_in_hash {
445 my ($self, $op_str, $v) = @_;
447 $op_str =~ /^ (AND|OR|NEST) ( \_? \d* ) $/xi
448 or puke "unknown operator: -$op_str";
450 my $op = uc($1); # uppercase, remove trailing digits
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 ... ]";
456 $self->_debug("OP(-$op) within hashref, recursing...");
458 $self->_SWITCH_refkind($v, {
461 return $self->_where_ARRAYREF($v, $op eq 'NEST' ? '' : $op);
466 return $self->_where_ARRAYREF([%$v], 'OR');
469 return $self->_where_HASHREF($v);
473 SCALARREF => sub { # literal SQL
475 or puke "-$op => \\\$scalar not supported, use -nest => ...";
479 ARRAYREFREF => sub { # literal SQL
481 or puke "-$op => \\[..] not supported, use -nest => ...";
485 SCALAR => sub { # permissively interpreted as SQL
487 or puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
488 belch "literal SQL should be -nest => \\'scalar' "
489 . "instead of -nest => 'scalar' ";
494 puke "-$op => undef not supported";
500 sub _where_hashpair_ARRAYREF {
501 my ($self, $k, $v) = @_;
504 my @v = @$v; # need copy because of shift below
505 $self->_debug("ARRAY($k) means distribute over elements");
507 # put apart first element if it is an operator (-and, -or)
508 my $op = ($v[0] =~ /^ - (?: AND|OR ) $/ix
512 my @distributed = map { {$k => $_} } @v;
515 $self->_debug("OP($op) reinjected into the distributed array");
516 unshift @distributed, $op;
519 my $logic = $op ? substr($op, 1) : '';
521 return $self->_recurse_where(\@distributed, $logic);
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});
530 sub _where_hashpair_HASHREF {
531 my ($self, $k, $v, $logic) = @_;
534 my ($all_sql, @all_bind);
536 for my $op (sort keys %$v) {
539 # put the operator in canonical form
540 $op =~ s/^-//; # remove initial dash
541 $op =~ tr/_/ /; # underscores become spaces
542 $op =~ s/^\s+//; # no initial space
543 $op =~ s/\s+$//; # no final space
544 $op =~ s/\s+/ /; # multiple spaces become one
548 # CASE: special operators like -in or -between
549 my $special_op = first {$op =~ $_->{regex}} @{$self->{special_ops}};
551 ($sql, @bind) = $special_op->{handler}->($self, $k, $op, $val);
554 $self->_SWITCH_refkind($val, {
556 ARRAYREF => sub { # CASE: col => {op => \@vals}
557 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
560 SCALARREF => sub { # CASE: col => {op => \$scalar} (literal SQL without bind)
561 $sql = join ' ', $self->_convert($self->_quote($k)),
562 $self->_sqlcase($op),
566 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]} (literal SQL with bind)
567 my ($sub_sql, @sub_bind) = @$$val;
568 $self->_assert_bindval_matches_bindtype(@sub_bind);
569 $sql = join ' ', $self->_convert($self->_quote($k)),
570 $self->_sqlcase($op),
576 ($sql, @bind) = $self->_where_hashpair_HASHREF($k, $val, $op);
579 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
580 my $is = ($op =~ $self->{equality_op}) ? 'is' :
581 ($op =~ $self->{inequality_op}) ? 'is not' :
582 puke "unexpected operator '$op' with undef operand";
583 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
586 FALLBACK => sub { # CASE: col => {op => $scalar}
587 $sql = join ' ', $self->_convert($self->_quote($k)),
588 $self->_sqlcase($op),
589 $self->_convert('?');
590 @bind = $self->_bindtype($k, $val);
595 ($all_sql) = (defined $all_sql and $all_sql) ? $self->_join_sql_clauses($logic, [$all_sql, $sql], []) : $sql;
596 push @all_bind, @bind;
598 return ($all_sql, @all_bind);
603 sub _where_field_op_ARRAYREF {
604 my ($self, $k, $op, $vals) = @_;
607 $self->_debug("ARRAY($vals) means multiple elements: [ @$vals ]");
609 # LDNOTE : had planned to change the distribution logic when
610 # $op =~ $self->{inequality_op}, because of Morgan laws :
611 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
612 # WHERE field != 22 OR field != 33 : the user probably means
613 # WHERE field != 22 AND field != 33.
614 # To do this, replace the line below by :
615 # my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
616 # return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
618 # distribute $op over each member of @$vals
619 return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals]);
622 # try to DWIM on equality operators
623 # LDNOTE : not 100% sure this is the correct thing to do ...
624 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
625 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
628 puke "operator '$op' applied on an empty array (field '$k')";
633 sub _where_hashpair_SCALARREF {
634 my ($self, $k, $v) = @_;
635 $self->_debug("SCALAR($k) means literal SQL: $$v");
636 my $sql = $self->_quote($k) . " " . $$v;
640 # literal SQL with bind
641 sub _where_hashpair_ARRAYREFREF {
642 my ($self, $k, $v) = @_;
643 $self->_debug("REF($k) means literal SQL: @${$v}");
644 my ($sql, @bind) = @${$v};
645 $self->_assert_bindval_matches_bindtype(@bind);
646 $sql = $self->_quote($k) . " " . $sql;
647 return ($sql, @bind );
650 # literal SQL without bind
651 sub _where_hashpair_SCALAR {
652 my ($self, $k, $v) = @_;
653 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
654 my $sql = join ' ', $self->_convert($self->_quote($k)),
655 $self->_sqlcase($self->{cmp}),
656 $self->_convert('?');
657 my @bind = $self->_bindtype($k, $v);
658 return ( $sql, @bind);
662 sub _where_hashpair_UNDEF {
663 my ($self, $k, $v) = @_;
664 $self->_debug("UNDEF($k) means IS NULL");
665 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
669 #======================================================================
670 # WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
671 #======================================================================
674 sub _where_SCALARREF {
675 my ($self, $where) = @_;
678 $self->_debug("SCALAR(*top) means literal SQL: $$where");
684 my ($self, $where) = @_;
687 $self->_debug("NOREF(*top) means literal SQL: $where");
698 #======================================================================
699 # WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
700 #======================================================================
703 sub _where_field_BETWEEN {
704 my ($self, $k, $op, $vals) = @_;
706 (ref $vals eq 'ARRAY' && @$vals == 2) or
707 (ref $vals eq 'REF' && (@$$vals == 1 || @$$vals == 2 || @$$vals == 3))
708 or puke "special op 'between' requires an arrayref of two values (or a scalarref or arrayrefref for literal SQL)";
710 my ($clause, @bind, $label, $and, $placeholder);
711 $label = $self->_convert($self->_quote($k));
712 $and = ' ' . $self->_sqlcase('and') . ' ';
713 $placeholder = $self->_convert('?');
714 $op = $self->_sqlcase($op);
716 if (ref $vals eq 'REF') {
717 ($clause, @bind) = @$$vals;
720 my (@all_sql, @all_bind);
722 foreach my $val (@$vals) {
723 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
725 return ($placeholder, ($val));
728 return ($self->_convert($$val), ());
732 push @all_bind, @bind;
735 $clause = (join $and, @all_sql);
736 @bind = $self->_bindtype($k, @all_bind);
738 my $sql = "( $label $op $clause )";
743 sub _where_field_IN {
744 my ($self, $k, $op, $vals) = @_;
746 # backwards compatibility : if scalar, force into an arrayref
747 $vals = [$vals] if defined $vals && ! ref $vals;
749 my ($label) = $self->_convert($self->_quote($k));
750 my ($placeholder) = $self->_convert('?');
751 $op = $self->_sqlcase($op);
753 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
754 ARRAYREF => sub { # list of choices
755 if (@$vals) { # nonempty list
756 my $placeholders = join ", ", (($placeholder) x @$vals);
757 my $sql = "$label $op ( $placeholders )";
758 my @bind = $self->_bindtype($k, @$vals);
760 return ($sql, @bind);
762 else { # empty list : some databases won't understand "IN ()", so DWIM
763 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
768 ARRAYREFREF => sub { # literal SQL with bind
769 my ($sql, @bind) = @$$vals;
770 $self->_assert_bindval_matches_bindtype(@bind);
771 return ("$label $op ( $sql )", @bind);
775 puke "special op 'in' requires an arrayref (or arrayref-ref)";
779 return ($sql, @bind);
787 #======================================================================
789 #======================================================================
792 my ($self, $arg) = @_;
794 # construct list of ordering instructions
795 my @order = $self->_SWITCH_refkind($arg, {
798 map {$self->_SWITCH_refkind($_, {
799 SCALAR => sub {$self->_quote($_)},
801 SCALARREF => sub {$$_}, # literal SQL, no quoting
802 HASHREF => sub {$self->_order_by_hash($_)}
806 SCALAR => sub {$self->_quote($arg)},
808 SCALARREF => sub {$$arg}, # literal SQL, no quoting
809 HASHREF => sub {$self->_order_by_hash($arg)},
814 my $order = join ', ', @order;
815 return $order ? $self->_sqlcase(' order by')." $order" : '';
820 my ($self, $hash) = @_;
822 # get first pair in hash
823 my ($key, $val) = each %$hash;
825 # check if one pair was found and no other pair in hash
826 $key && !(each %$hash)
827 or puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
829 my ($order) = ($key =~ /^-(desc|asc)/i)
830 or puke "invalid key in _order_by hash : $key";
832 $val = ref $val eq 'ARRAY' ? $val : [$val];
833 return join ', ', map { $self->_quote($_) . ' ' . $self->_sqlcase($order) } @$val;
838 #======================================================================
839 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
840 #======================================================================
845 $self->_SWITCH_refkind($from, {
846 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
847 SCALAR => sub {$self->_quote($from)},
848 SCALARREF => sub {$$from},
849 ARRAYREFREF => sub {join ', ', @$from;},
854 #======================================================================
856 #======================================================================
862 $label or puke "can't quote an empty label";
864 # left and right quote characters
865 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
866 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
867 ARRAYREF => sub {@{$self->{quote_char}}},
871 or puke "quote_char must be an arrayref of 2 values";
873 # no quoting if no quoting chars
874 $ql or return $label;
876 # no quoting for literal SQL
877 return $$label if ref($label) eq 'SCALAR';
879 # separate table / column (if applicable)
880 my $sep = $self->{name_sep} || '';
881 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
883 # do the quoting, except for "*" or for `table`.*
884 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
886 # reassemble and return.
887 return join $sep, @quoted;
891 # Conversion, if applicable
893 my ($self, $arg) = @_;
895 # LDNOTE : modified the previous implementation below because
896 # it was not consistent : the first "return" is always an array,
897 # the second "return" is context-dependent. Anyway, _convert
898 # seems always used with just a single argument, so make it a
900 # return @_ unless $self->{convert};
901 # my $conv = $self->_sqlcase($self->{convert});
902 # my @ret = map { $conv.'('.$_.')' } @_;
903 # return wantarray ? @ret : $ret[0];
904 if ($self->{convert}) {
905 my $conv = $self->_sqlcase($self->{convert});
906 $arg = $conv.'('.$arg.')';
914 my($col, @vals) = @_;
916 #LDNOTE : changed original implementation below because it did not make
917 # sense when bindtype eq 'columns' and @vals > 1.
918 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
920 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
923 # Dies if any element of @bind is not in [colname => value] format
924 # if bindtype is 'columns'.
925 sub _assert_bindval_matches_bindtype {
926 my ($self, @bind) = @_;
928 if ($self->{bindtype} eq 'columns') {
929 foreach my $val (@bind) {
930 if (!defined $val || ref($val) ne 'ARRAY' || @$val != 2) {
931 die "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
937 sub _join_sql_clauses {
938 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
940 if (@$clauses_aref > 1) {
941 my $join = " " . $self->_sqlcase($logic) . " ";
942 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
943 return ($sql, @$bind_aref);
945 elsif (@$clauses_aref) {
946 return ($clauses_aref->[0], @$bind_aref); # no parentheses
949 return (); # if no SQL, ignore @$bind_aref
954 # Fix SQL case, if so requested
958 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
959 # don't touch the argument ... crooked logic, but let's not change it!
960 return $self->{case} ? $_[0] : uc($_[0]);
964 #======================================================================
965 # DISPATCHING FROM REFKIND
966 #======================================================================
969 my ($self, $data) = @_;
975 # blessed objects are treated like scalars
976 $ref = (blessed $data) ? '' : ref $data;
977 $n_steps += 1 if $ref;
978 last if $ref ne 'REF';
982 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
984 return $base . ('REF' x $n_steps);
990 my ($self, $data) = @_;
991 my @try = ($self->_refkind($data));
992 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
993 push @try, 'FALLBACK';
997 sub _METHOD_FOR_refkind {
998 my ($self, $meth_prefix, $data) = @_;
999 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
1000 $self->_try_refkind($data)
1001 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1006 sub _SWITCH_refkind {
1007 my ($self, $data, $dispatch_table) = @_;
1009 my $coderef = first {$_} map {$dispatch_table->{$_}}
1010 $self->_try_refkind($data)
1011 or puke "no dispatch entry for ".$self->_refkind($data);
1018 #======================================================================
1019 # VALUES, GENERATE, AUTOLOAD
1020 #======================================================================
1022 # LDNOTE: original code from nwiger, didn't touch code in that section
1023 # I feel the AUTOLOAD stuff should not be the default, it should
1024 # only be activated on explicit demand by user.
1028 my $data = shift || return;
1029 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1030 unless ref $data eq 'HASH';
1033 foreach my $k ( sort keys %$data ) {
1034 my $v = $data->{$k};
1035 $self->_SWITCH_refkind($v, {
1037 if ($self->{array_datatypes}) { # array datatype
1038 push @all_bind, $self->_bindtype($k, $v);
1040 else { # literal SQL with bind
1041 my ($sql, @bind) = @$v;
1042 $self->_assert_bindval_matches_bindtype(@bind);
1043 push @all_bind, @bind;
1046 ARRAYREFREF => sub { # literal SQL with bind
1047 my ($sql, @bind) = @${$v};
1048 $self->_assert_bindval_matches_bindtype(@bind);
1049 push @all_bind, @bind;
1051 SCALARREF => sub { # literal SQL without bind
1053 SCALAR_or_UNDEF => sub {
1054 push @all_bind, $self->_bindtype($k, $v);
1065 my(@sql, @sqlq, @sqlv);
1069 if ($ref eq 'HASH') {
1070 for my $k (sort keys %$_) {
1073 my $label = $self->_quote($k);
1074 if ($r eq 'ARRAY') {
1075 # literal SQL with bind
1076 my ($sql, @bind) = @$v;
1077 $self->_assert_bindval_matches_bindtype(@bind);
1078 push @sqlq, "$label = $sql";
1080 } elsif ($r eq 'SCALAR') {
1081 # literal SQL without bind
1082 push @sqlq, "$label = $$v";
1084 push @sqlq, "$label = ?";
1085 push @sqlv, $self->_bindtype($k, $v);
1088 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1089 } elsif ($ref eq 'ARRAY') {
1090 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1093 if ($r eq 'ARRAY') { # literal SQL with bind
1094 my ($sql, @bind) = @$v;
1095 $self->_assert_bindval_matches_bindtype(@bind);
1098 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1099 # embedded literal SQL
1106 push @sql, '(' . join(', ', @sqlq) . ')';
1107 } elsif ($ref eq 'SCALAR') {
1111 # strings get case twiddled
1112 push @sql, $self->_sqlcase($_);
1116 my $sql = join ' ', @sql;
1118 # this is pretty tricky
1119 # if ask for an array, return ($stmt, @bind)
1120 # otherwise, s/?/shift @sqlv/ to put it inline
1122 return ($sql, @sqlv);
1124 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1125 ref $d ? $d->[1] : $d/e;
1134 # This allows us to check for a local, then _form, attr
1136 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1137 return $self->generate($name, @_);
1148 SQL::Abstract - Generate SQL from Perl data structures
1154 my $sql = SQL::Abstract->new;
1156 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1158 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1160 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1162 my($stmt, @bind) = $sql->delete($table, \%where);
1164 # Then, use these in your DBI statements
1165 my $sth = $dbh->prepare($stmt);
1166 $sth->execute(@bind);
1168 # Just generate the WHERE clause
1169 my($stmt, @bind) = $sql->where(\%where, \@order);
1171 # Return values in the same order, for hashed queries
1172 # See PERFORMANCE section for more details
1173 my @bind = $sql->values(\%fieldvals);
1177 This module was inspired by the excellent L<DBIx::Abstract>.
1178 However, in using that module I found that what I really wanted
1179 to do was generate SQL, but still retain complete control over my
1180 statement handles and use the DBI interface. So, I set out to
1181 create an abstract SQL generation module.
1183 While based on the concepts used by L<DBIx::Abstract>, there are
1184 several important differences, especially when it comes to WHERE
1185 clauses. I have modified the concepts used to make the SQL easier
1186 to generate from Perl data structures and, IMO, more intuitive.
1187 The underlying idea is for this module to do what you mean, based
1188 on the data structures you provide it. The big advantage is that
1189 you don't have to modify your code every time your data changes,
1190 as this module figures it out.
1192 To begin with, an SQL INSERT is as easy as just specifying a hash
1193 of C<key=value> pairs:
1196 name => 'Jimbo Bobson',
1197 phone => '123-456-7890',
1198 address => '42 Sister Lane',
1199 city => 'St. Louis',
1200 state => 'Louisiana',
1203 The SQL can then be generated with this:
1205 my($stmt, @bind) = $sql->insert('people', \%data);
1207 Which would give you something like this:
1209 $stmt = "INSERT INTO people
1210 (address, city, name, phone, state)
1211 VALUES (?, ?, ?, ?, ?)";
1212 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1213 '123-456-7890', 'Louisiana');
1215 These are then used directly in your DBI code:
1217 my $sth = $dbh->prepare($stmt);
1218 $sth->execute(@bind);
1220 =head2 Inserting and Updating Arrays
1222 If your database has array types (like for example Postgres),
1223 activate the special option C<< array_datatypes => 1 >>
1224 when creating the C<SQL::Abstract> object.
1225 Then you may use an arrayref to insert and update database array types:
1227 my $sql = SQL::Abstract->new(array_datatypes => 1);
1229 planets => [qw/Mercury Venus Earth Mars/]
1232 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1236 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1238 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1241 =head2 Inserting and Updating SQL
1243 In order to apply SQL functions to elements of your C<%data> you may
1244 specify a reference to an arrayref for the given hash value. For example,
1245 if you need to execute the Oracle C<to_date> function on a value, you can
1246 say something like this:
1250 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
1253 The first value in the array is the actual SQL. Any other values are
1254 optional and would be included in the bind values array. This gives
1257 my($stmt, @bind) = $sql->insert('people', \%data);
1259 $stmt = "INSERT INTO people (name, date_entered)
1260 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1261 @bind = ('Bill', '03/02/2003');
1263 An UPDATE is just as easy, all you change is the name of the function:
1265 my($stmt, @bind) = $sql->update('people', \%data);
1267 Notice that your C<%data> isn't touched; the module will generate
1268 the appropriately quirky SQL for you automatically. Usually you'll
1269 want to specify a WHERE clause for your UPDATE, though, which is
1270 where handling C<%where> hashes comes in handy...
1272 =head2 Complex where statements
1274 This module can generate pretty complicated WHERE statements
1275 easily. For example, simple C<key=value> pairs are taken to mean
1276 equality, and if you want to see if a field is within a set
1277 of values, you can use an arrayref. Let's say we wanted to
1278 SELECT some data based on this criteria:
1281 requestor => 'inna',
1282 worker => ['nwiger', 'rcwe', 'sfz'],
1283 status => { '!=', 'completed' }
1286 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1288 The above would give you something like this:
1290 $stmt = "SELECT * FROM tickets WHERE
1291 ( requestor = ? ) AND ( status != ? )
1292 AND ( worker = ? OR worker = ? OR worker = ? )";
1293 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1295 Which you could then use in DBI code like so:
1297 my $sth = $dbh->prepare($stmt);
1298 $sth->execute(@bind);
1304 The functions are simple. There's one for each major SQL operation,
1305 and a constructor you use first. The arguments are specified in a
1306 similar order to each function (table, then fields, then a where
1307 clause) to try and simplify things.
1312 =head2 new(option => 'value')
1314 The C<new()> function takes a list of options and values, and returns
1315 a new B<SQL::Abstract> object which can then be used to generate SQL
1316 through the methods below. The options accepted are:
1322 If set to 'lower', then SQL will be generated in all lowercase. By
1323 default SQL is generated in "textbook" case meaning something like:
1325 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1327 Any setting other than 'lower' is ignored.
1331 This determines what the default comparison operator is. By default
1332 it is C<=>, meaning that a hash like this:
1334 %where = (name => 'nwiger', email => 'nate@wiger.org');
1336 Will generate SQL like this:
1338 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1340 However, you may want loose comparisons by default, so if you set
1341 C<cmp> to C<like> you would get SQL such as:
1343 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1345 You can also override the comparsion on an individual basis - see
1346 the huge section on L</"WHERE CLAUSES"> at the bottom.
1348 =item sqltrue, sqlfalse
1350 Expressions for inserting boolean values within SQL statements.
1351 By default these are C<1=1> and C<1=0>. They are used
1352 by the special operators C<-in> and C<-not_in> for generating
1353 correct SQL even when the argument is an empty array (see below).
1357 This determines the default logical operator for multiple WHERE
1358 statements in arrays or hashes. If absent, the default logic is "or"
1359 for arrays, and "and" for hashes. This means that a WHERE
1363 event_date => {'>=', '2/13/99'},
1364 event_date => {'<=', '4/24/03'},
1367 will generate SQL like this:
1369 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1371 This is probably not what you want given this query, though (look
1372 at the dates). To change the "OR" to an "AND", simply specify:
1374 my $sql = SQL::Abstract->new(logic => 'and');
1376 Which will change the above C<WHERE> to:
1378 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1380 The logic can also be changed locally by inserting
1381 a modifier in front of an arrayref :
1383 @where = (-and => [event_date => {'>=', '2/13/99'},
1384 event_date => {'<=', '4/24/03'} ]);
1386 See the L</"WHERE CLAUSES"> section for explanations.
1390 This will automatically convert comparisons using the specified SQL
1391 function for both column and value. This is mostly used with an argument
1392 of C<upper> or C<lower>, so that the SQL will have the effect of
1393 case-insensitive "searches". For example, this:
1395 $sql = SQL::Abstract->new(convert => 'upper');
1396 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1398 Will turn out the following SQL:
1400 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1402 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1403 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1404 not validate this option; it will just pass through what you specify verbatim).
1408 This is a kludge because many databases suck. For example, you can't
1409 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1410 Instead, you have to use C<bind_param()>:
1412 $sth->bind_param(1, 'reg data');
1413 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1415 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1416 which loses track of which field each slot refers to. Fear not.
1418 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1419 Currently, you can specify either C<normal> (default) or C<columns>. If you
1420 specify C<columns>, you will get an array that looks like this:
1422 my $sql = SQL::Abstract->new(bindtype => 'columns');
1423 my($stmt, @bind) = $sql->insert(...);
1426 [ 'column1', 'value1' ],
1427 [ 'column2', 'value2' ],
1428 [ 'column3', 'value3' ],
1431 You can then iterate through this manually, using DBI's C<bind_param()>.
1433 $sth->prepare($stmt);
1436 my($col, $data) = @$_;
1437 if ($col eq 'details' || $col eq 'comments') {
1438 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1439 } elsif ($col eq 'image') {
1440 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1442 $sth->bind_param($i, $data);
1446 $sth->execute; # execute without @bind now
1448 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1449 Basically, the advantage is still that you don't have to care which fields
1450 are or are not included. You could wrap that above C<for> loop in a simple
1451 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1452 get a layer of abstraction over manual SQL specification.
1454 Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1455 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1456 will expect the bind values in this format.
1460 This is the character that a table or column name will be quoted
1461 with. By default this is an empty string, but you could set it to
1462 the character C<`>, to generate SQL like this:
1464 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1466 Alternatively, you can supply an array ref of two items, the first being the left
1467 hand quote character, and the second the right hand quote character. For
1468 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1469 that generates SQL like this:
1471 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1473 Quoting is useful if you have tables or columns names that are reserved
1474 words in your database's SQL dialect.
1478 This is the character that separates a table and column name. It is
1479 necessary to specify this when the C<quote_char> option is selected,
1480 so that tables and column names can be individually quoted like this:
1482 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1484 =item array_datatypes
1486 When this option is true, arrayrefs in INSERT or UPDATE are
1487 interpreted as array datatypes and are passed directly
1489 When this option is false, arrayrefs are interpreted
1490 as literal SQL, just like refs to arrayrefs
1491 (but this behavior is for backwards compatibility; when writing
1492 new queries, use the "reference to arrayref" syntax
1498 Takes a reference to a list of "special operators"
1499 to extend the syntax understood by L<SQL::Abstract>.
1500 See section L</"SPECIAL OPERATORS"> for details.
1506 =head2 insert($table, \@values || \%fieldvals)
1508 This is the simplest function. You simply give it a table name
1509 and either an arrayref of values or hashref of field/value pairs.
1510 It returns an SQL INSERT statement and a list of bind values.
1511 See the sections on L</"Inserting and Updating Arrays"> and
1512 L</"Inserting and Updating SQL"> for information on how to insert
1513 with those data types.
1515 =head2 update($table, \%fieldvals, \%where)
1517 This takes a table, hashref of field/value pairs, and an optional
1518 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1520 See the sections on L</"Inserting and Updating Arrays"> and
1521 L</"Inserting and Updating SQL"> for information on how to insert
1522 with those data types.
1524 =head2 select($source, $fields, $where, $order)
1526 This returns a SQL SELECT statement and associated list of bind values, as
1527 specified by the arguments :
1533 Specification of the 'FROM' part of the statement.
1534 The argument can be either a plain scalar (interpreted as a table
1535 name, will be quoted), or an arrayref (interpreted as a list
1536 of table names, joined by commas, quoted), or a scalarref
1537 (literal table name, not quoted), or a ref to an arrayref
1538 (list of literal table names, joined by commas, not quoted).
1542 Specification of the list of fields to retrieve from
1544 The argument can be either an arrayref (interpreted as a list
1545 of field names, will be joined by commas and quoted), or a
1546 plain scalar (literal SQL, not quoted).
1547 Please observe that this API is not as flexible as for
1548 the first argument C<$table>, for backwards compatibility reasons.
1552 Optional argument to specify the WHERE part of the query.
1553 The argument is most often a hashref, but can also be
1554 an arrayref or plain scalar --
1555 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1559 Optional argument to specify the ORDER BY part of the query.
1560 The argument can be a scalar, a hashref or an arrayref
1561 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1567 =head2 delete($table, \%where)
1569 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1570 It returns an SQL DELETE statement and list of bind values.
1572 =head2 where(\%where, \@order)
1574 This is used to generate just the WHERE clause. For example,
1575 if you have an arbitrary data structure and know what the
1576 rest of your SQL is going to look like, but want an easy way
1577 to produce a WHERE clause, use this. It returns an SQL WHERE
1578 clause and list of bind values.
1581 =head2 values(\%data)
1583 This just returns the values from the hash C<%data>, in the same
1584 order that would be returned from any of the other above queries.
1585 Using this allows you to markedly speed up your queries if you
1586 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1588 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1590 Warning: This is an experimental method and subject to change.
1592 This returns arbitrarily generated SQL. It's a really basic shortcut.
1593 It will return two different things, depending on return context:
1595 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1596 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1598 These would return the following:
1600 # First calling form
1601 $stmt = "CREATE TABLE test (?, ?)";
1602 @bind = (field1, field2);
1604 # Second calling form
1605 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1607 Depending on what you're trying to do, it's up to you to choose the correct
1608 format. In this example, the second form is what you would want.
1612 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1616 ALTER SESSION SET nls_date_format = 'MM/YY'
1618 You get the idea. Strings get their case twiddled, but everything
1619 else remains verbatim.
1624 =head1 WHERE CLAUSES
1628 This module uses a variation on the idea from L<DBIx::Abstract>. It
1629 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1630 module is that things in arrays are OR'ed, and things in hashes
1633 The easiest way to explain is to show lots of examples. After
1634 each C<%where> hash shown, it is assumed you used:
1636 my($stmt, @bind) = $sql->where(\%where);
1638 However, note that the C<%where> hash can be used directly in any
1639 of the other functions as well, as described above.
1641 =head2 Key-value pairs
1643 So, let's get started. To begin, a simple hash:
1647 status => 'completed'
1650 Is converted to SQL C<key = val> statements:
1652 $stmt = "WHERE user = ? AND status = ?";
1653 @bind = ('nwiger', 'completed');
1655 One common thing I end up doing is having a list of values that
1656 a field can be in. To do this, simply specify a list inside of
1661 status => ['assigned', 'in-progress', 'pending'];
1664 This simple code will create the following:
1666 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1667 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1669 A field associated to an empty arrayref will be considered a
1670 logical false and will generate 0=1.
1672 =head2 Specific comparison operators
1674 If you want to specify a different type of operator for your comparison,
1675 you can use a hashref for a given column:
1679 status => { '!=', 'completed' }
1682 Which would generate:
1684 $stmt = "WHERE user = ? AND status != ?";
1685 @bind = ('nwiger', 'completed');
1687 To test against multiple values, just enclose the values in an arrayref:
1689 status => { '=', ['assigned', 'in-progress', 'pending'] };
1691 Which would give you:
1693 "WHERE status = ? OR status = ? OR status = ?"
1696 The hashref can also contain multiple pairs, in which case it is expanded
1697 into an C<AND> of its elements:
1701 status => { '!=', 'completed', -not_like => 'pending%' }
1704 # Or more dynamically, like from a form
1705 $where{user} = 'nwiger';
1706 $where{status}{'!='} = 'completed';
1707 $where{status}{'-not_like'} = 'pending%';
1709 # Both generate this
1710 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1711 @bind = ('nwiger', 'completed', 'pending%');
1714 To get an OR instead, you can combine it with the arrayref idea:
1718 priority => [ {'=', 2}, {'!=', 1} ]
1721 Which would generate:
1723 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1724 @bind = ('nwiger', '2', '1');
1726 If you want to include literal SQL (with or without bind values), just use a
1727 scalar reference or array reference as the value:
1730 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1731 date_expires => { '<' => \"now()" }
1734 Which would generate:
1736 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1737 @bind = ('11/26/2008');
1740 =head2 Logic and nesting operators
1742 In the example above,
1743 there is a subtle trap if you want to say something like
1744 this (notice the C<AND>):
1746 WHERE priority != ? AND priority != ?
1748 Because, in Perl you I<can't> do this:
1750 priority => { '!=', 2, '!=', 1 }
1752 As the second C<!=> key will obliterate the first. The solution
1753 is to use the special C<-modifier> form inside an arrayref:
1755 priority => [ -and => {'!=', 2},
1759 Normally, these would be joined by C<OR>, but the modifier tells it
1760 to use C<AND> instead. (Hint: You can use this in conjunction with the
1761 C<logic> option to C<new()> in order to change the way your queries
1762 work by default.) B<Important:> Note that the C<-modifier> goes
1763 B<INSIDE> the arrayref, as an extra first element. This will
1764 B<NOT> do what you think it might:
1766 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1768 Here is a quick list of equivalencies, since there is some overlap:
1771 status => {'!=', 'completed', 'not like', 'pending%' }
1772 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1775 status => {'=', ['assigned', 'in-progress']}
1776 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1777 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1781 =head2 Special operators : IN, BETWEEN, etc.
1783 You can also use the hashref format to compare a list of fields using the
1784 C<IN> comparison operator, by specifying the list as an arrayref:
1787 status => 'completed',
1788 reportid => { -in => [567, 2335, 2] }
1791 Which would generate:
1793 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1794 @bind = ('completed', '567', '2335', '2');
1796 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1799 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
1800 (by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
1801 'sqltrue' (by default : C<1=1>).
1805 Another pair of operators is C<-between> and C<-not_between>,
1806 used with an arrayref of two values:
1810 completion_date => {
1811 -not_between => ['2002-10-01', '2003-02-06']
1817 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1819 These are the two builtin "special operators"; but the
1820 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1822 =head2 Nested conditions, -and/-or prefixes
1824 So far, we've seen how multiple conditions are joined with a top-level
1825 C<AND>. We can change this by putting the different conditions we want in
1826 hashes and then putting those hashes in an array. For example:
1831 status => { -like => ['pending%', 'dispatched'] },
1835 status => 'unassigned',
1839 This data structure would create the following:
1841 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1842 OR ( user = ? AND status = ? ) )";
1843 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1846 There is also a special C<-nest>
1847 operator which adds an additional set of parens, to create a subquery.
1848 For example, to get something like this:
1850 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
1851 @bind = ('nwiger', '20', 'ASIA');
1857 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1861 Finally, clauses in hashrefs or arrayrefs can be
1862 prefixed with an C<-and> or C<-or> to change the logic
1869 -and => [workhrs => {'>', 20}, geo => 'ASIA' ],
1870 -and => [workhrs => {'<', 50}, geo => 'EURO' ]
1877 WHERE ( user = ? AND
1878 ( ( workhrs > ? AND geo = ? )
1879 OR ( workhrs < ? AND geo = ? ) ) )
1882 =head2 Algebraic inconsistency, for historical reasons
1884 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
1885 operator goes C<outside> of the nested structure; whereas when connecting
1886 several constraints on one column, the C<-and> operator goes
1887 C<inside> the arrayref. Here is an example combining both features :
1890 -and => [a => 1, b => 2],
1891 -or => [c => 3, d => 4],
1892 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
1897 WHERE ( ( ( a = ? AND b = ? )
1898 OR ( c = ? OR d = ? )
1899 OR ( e LIKE ? AND e LIKE ? ) ) )
1901 This difference in syntax is unfortunate but must be preserved for
1902 historical reasons. So be careful : the two examples below would
1903 seem algebraically equivalent, but they are not
1905 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
1906 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
1908 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
1909 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
1914 Finally, sometimes only literal SQL will do. If you want to include
1915 literal SQL verbatim, you can specify it as a scalar reference, namely:
1917 my $inn = 'is Not Null';
1919 priority => { '<', 2 },
1925 $stmt = "WHERE priority < ? AND requestor is Not Null";
1928 Note that in this example, you only get one bind parameter back, since
1929 the verbatim SQL is passed as part of the statement.
1931 Of course, just to prove a point, the above can also be accomplished
1935 priority => { '<', 2 },
1936 requestor => { '!=', undef },
1942 Conditions on boolean columns can be expressed in the
1943 same way, passing a reference to an empty string :
1946 priority => { '<', 2 },
1952 $stmt = "WHERE priority < ? AND is_ready";
1956 =head2 Literal SQL with placeholders and bind values (subqueries)
1958 If the literal SQL to be inserted has placeholders and bind values,
1959 use a reference to an arrayref (yes this is a double reference --
1960 not so common, but perfectly legal Perl). For example, to find a date
1961 in Postgres you can use something like this:
1964 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1969 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
1972 Note that you must pass the bind values in the same format as they are returned
1973 by L</where>. That means that if you set L</bindtype> to C<columns>, you must
1974 provide the bind values in the C<< [ column_meta => value ] >> format, where
1975 C<column_meta> is an opaque scalar value; most commonly the column name, but
1976 you can use any scalar value (including references and blessed references),
1977 L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
1978 to C<columns> the above example will look like:
1981 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
1984 Literal SQL is especially useful for nesting parenthesized clauses in the
1985 main SQL query. Here is a first example :
1987 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1991 bar => \["IN ($sub_stmt)" => @sub_bind],
1996 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
1997 WHERE c2 < ? AND c3 LIKE ?))";
1998 @bind = (1234, 100, "foo%");
2000 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2001 are expressed in the same way. Of course the C<$sub_stmt> and
2002 its associated bind values can be generated through a former call
2005 my ($sub_stmt, @sub_bind)
2006 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2007 c3 => {-like => "foo%"}});
2010 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2013 In the examples above, the subquery was used as an operator on a column;
2014 but the same principle also applies for a clause within the main C<%where>
2015 hash, like an EXISTS subquery :
2017 my ($sub_stmt, @sub_bind)
2018 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2021 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
2026 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2027 WHERE c1 = ? AND c2 > t0.c0))";
2031 Observe that the condition on C<c2> in the subquery refers to
2032 column C<t0.c0> of the main query : this is I<not> a bind
2033 value, so we have to express it through a scalar ref.
2034 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2035 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2036 what we wanted here.
2038 Another use of the subquery technique is when some SQL clauses need
2039 parentheses, as it often occurs with some proprietary SQL extensions
2040 like for example fulltext expressions, geospatial expressions,
2041 NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
2044 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
2047 Finally, here is an example where a subquery is used
2048 for expressing unary negation:
2050 my ($sub_stmt, @sub_bind)
2051 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2052 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2054 lname => {like => '%son%'},
2055 -nest => \["NOT ($sub_stmt)" => @sub_bind],
2060 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2061 @bind = ('%son%', 10, 20)
2067 These pages could go on for a while, since the nesting of the data
2068 structures this module can handle are pretty much unlimited (the
2069 module implements the C<WHERE> expansion as a recursive function
2070 internally). Your best bet is to "play around" with the module a
2071 little to see how the data structures behave, and choose the best
2072 format for your data based on that.
2074 And of course, all the values above will probably be replaced with
2075 variables gotten from forms or the command line. After all, if you
2076 knew everything ahead of time, you wouldn't have to worry about
2077 dynamically-generating SQL and could just hardwire it into your
2083 =head1 ORDER BY CLAUSES
2085 Some functions take an order by clause. This can either be a scalar (just a
2086 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
2087 or an array of either of the two previous forms. Examples:
2089 Given | Will Generate
2090 ----------------------------------------------------------
2091 \'colA DESC' | ORDER BY colA DESC
2092 'colA' | ORDER BY colA
2093 [qw/colA colB/] | ORDER BY colA, colB
2094 {-asc => 'colA'} | ORDER BY colA ASC
2095 {-desc => 'colB'} | ORDER BY colB DESC
2097 {-asc => 'colA'}, | ORDER BY colA ASC, colB DESC
2100 [colA => {-asc => 'colB'}] | ORDER BY colA, colB ASC
2101 { -asc => [qw/colA colB] } | ORDER BY colA ASC, colB ASC
2102 { -asc => [qw/colA colB] },|
2103 -desc => [qw/colC colD] } | ORDER BY colA ASC, colB ASC, colC DESC, colD DESC
2104 ==========================================================
2108 =head1 SPECIAL OPERATORS
2110 my $sqlmaker = SQL::Abstract->new(special_ops => [
2113 my ($self, $field, $op, $arg) = @_;
2119 A "special operator" is a SQL syntactic clause that can be
2120 applied to a field, instead of a usual binary operator.
2123 WHERE field IN (?, ?, ?)
2124 WHERE field BETWEEN ? AND ?
2125 WHERE MATCH(field) AGAINST (?, ?)
2127 Special operators IN and BETWEEN are fairly standard and therefore
2128 are builtin within C<SQL::Abstract>. For other operators,
2129 like the MATCH .. AGAINST example above which is
2130 specific to MySQL, you can write your own operator handlers :
2131 supply a C<special_ops> argument to the C<new> method.
2132 That argument takes an arrayref of operator definitions;
2133 each operator definition is a hashref with two entries
2139 the regular expression to match the operator
2143 coderef that will be called when meeting that operator
2144 in the input tree. The coderef will be called with
2145 arguments C<< ($self, $field, $op, $arg) >>, and
2146 should return a C<< ($sql, @bind) >> structure.
2150 For example, here is an implementation
2151 of the MATCH .. AGAINST syntax for MySQL
2153 my $sqlmaker = SQL::Abstract->new(special_ops => [
2155 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2156 {regex => qr/^match$/i,
2158 my ($self, $field, $op, $arg) = @_;
2159 $arg = [$arg] if not ref $arg;
2160 my $label = $self->_quote($field);
2161 my ($placeholder) = $self->_convert('?');
2162 my $placeholders = join ", ", (($placeholder) x @$arg);
2163 my $sql = $self->_sqlcase('match') . " ($label) "
2164 . $self->_sqlcase('against') . " ($placeholders) ";
2165 my @bind = $self->_bindtype($field, @$arg);
2166 return ($sql, @bind);
2175 Thanks to some benchmarking by Mark Stosberg, it turns out that
2176 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2177 I must admit this wasn't an intentional design issue, but it's a
2178 byproduct of the fact that you get to control your C<DBI> handles
2181 To maximize performance, use a code snippet like the following:
2183 # prepare a statement handle using the first row
2184 # and then reuse it for the rest of the rows
2186 for my $href (@array_of_hashrefs) {
2187 $stmt ||= $sql->insert('table', $href);
2188 $sth ||= $dbh->prepare($stmt);
2189 $sth->execute($sql->values($href));
2192 The reason this works is because the keys in your C<$href> are sorted
2193 internally by B<SQL::Abstract>. Thus, as long as your data retains
2194 the same structure, you only have to generate the SQL the first time
2195 around. On subsequent queries, simply use the C<values> function provided
2196 by this module to return your values in the correct order.
2201 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2202 really like this part (I do, at least). Building up a complex query
2203 can be as simple as the following:
2207 use CGI::FormBuilder;
2210 my $form = CGI::FormBuilder->new(...);
2211 my $sql = SQL::Abstract->new;
2213 if ($form->submitted) {
2214 my $field = $form->field;
2215 my $id = delete $field->{id};
2216 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2219 Of course, you would still have to connect using C<DBI> to run the
2220 query, but the point is that if you make your form look like your
2221 table, the actual query script can be extremely simplistic.
2223 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2224 a fast interface to returning and formatting data. I frequently
2225 use these three modules together to write complex database query
2226 apps in under 50 lines.
2231 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2232 Great care has been taken to preserve the I<published> behavior
2233 documented in previous versions in the 1.* family; however,
2234 some features that were previously undocumented, or behaved
2235 differently from the documentation, had to be changed in order
2236 to clarify the semantics. Hence, client code that was relying
2237 on some dark areas of C<SQL::Abstract> v1.*
2238 B<might behave differently> in v1.50.
2240 The main changes are :
2246 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2250 support for the { operator => \"..." } construct (to embed literal SQL)
2254 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2258 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2262 defensive programming : check arguments
2266 fixed bug with global logic, which was previously implemented
2267 through global variables yielding side-effects. Prior versions would
2268 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2269 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2270 Now this is interpreted
2271 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2276 fixed semantics of _bindtype on array args
2280 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2281 we just avoid shifting arrays within that tree.
2285 dropped the C<_modlogic> function
2291 =head1 ACKNOWLEDGEMENTS
2293 There are a number of individuals that have really helped out with
2294 this module. Unfortunately, most of them submitted bugs via CPAN
2295 so I have no idea who they are! But the people I do know are:
2297 Ash Berlin (order_by hash term support)
2298 Matt Trout (DBIx::Class support)
2299 Mark Stosberg (benchmarking)
2300 Chas Owens (initial "IN" operator support)
2301 Philip Collins (per-field SQL functions)
2302 Eric Kolve (hashref "AND" support)
2303 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2304 Dan Kubb (support for "quote_char" and "name_sep")
2305 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2306 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
2307 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2313 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2317 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2319 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
2321 For support, your best bet is to try the C<DBIx::Class> users mailing list.
2322 While not an official support venue, C<DBIx::Class> makes heavy use of
2323 C<SQL::Abstract>, and as such list members there are very familiar with
2324 how to create queries.
2326 This module is free software; you may copy this under the terms of
2327 the GNU General Public License, or the Artistic License, copies of
2328 which should have accompanied your Perl kit.