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.52';
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 for my $k (sort keys %$where) {
426 my $v = $where->{$k};
428 # ($k => $v) is either a special op or a regular hashpair
429 my ($sql, @bind) = ($k =~ /^-(.+)/) ? $self->_where_op_in_hash($1, $v)
431 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
432 $self->$method($k, $v);
435 push @sql_clauses, $sql;
436 push @all_bind, @bind;
439 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
443 sub _where_op_in_hash {
444 my ($self, $op_str, $v) = @_;
446 $op_str =~ /^ (AND|OR|NEST) ( \_? \d* ) $/xi
447 or puke "unknown operator: -$op_str";
449 my $op = uc($1); # uppercase, remove trailing digits
451 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
452 . "You probably wanted ...-and => [ $op_str => COND1, $op_str => COND2 ... ]";
455 $self->_debug("OP(-$op) within hashref, recursing...");
457 $self->_SWITCH_refkind($v, {
460 return $self->_where_ARRAYREF($v, $op eq 'NEST' ? '' : $op);
465 return $self->_where_ARRAYREF([ map { $_ => $v->{$_} } (sort keys %$v) ], 'OR');
468 return $self->_where_HASHREF($v);
472 SCALARREF => sub { # literal SQL
474 or puke "-$op => \\\$scalar not supported, use -nest => ...";
478 ARRAYREFREF => sub { # literal SQL
480 or puke "-$op => \\[..] not supported, use -nest => ...";
484 SCALAR => sub { # permissively interpreted as SQL
486 or puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
487 belch "literal SQL should be -nest => \\'scalar' "
488 . "instead of -nest => 'scalar' ";
493 puke "-$op => undef not supported";
499 sub _where_hashpair_ARRAYREF {
500 my ($self, $k, $v) = @_;
503 my @v = @$v; # need copy because of shift below
504 $self->_debug("ARRAY($k) means distribute over elements");
506 # put apart first element if it is an operator (-and, -or)
508 (defined $v[0] && $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 # see if the first element is an -and/-or op
611 if ($vals->[0] =~ /^ - ( AND|OR ) $/ix) {
616 # distribute $op over each remaining member of @$vals, append logic if exists
617 return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
619 # LDNOTE : had planned to change the distribution logic when
620 # $op =~ $self->{inequality_op}, because of Morgan laws :
621 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
622 # WHERE field != 22 OR field != 33 : the user probably means
623 # WHERE field != 22 AND field != 33.
624 # To do this, replace the above to roughly :
625 # my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
626 # return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
630 # try to DWIM on equality operators
631 # LDNOTE : not 100% sure this is the correct thing to do ...
632 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
633 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
636 puke "operator '$op' applied on an empty array (field '$k')";
641 sub _where_hashpair_SCALARREF {
642 my ($self, $k, $v) = @_;
643 $self->_debug("SCALAR($k) means literal SQL: $$v");
644 my $sql = $self->_quote($k) . " " . $$v;
648 # literal SQL with bind
649 sub _where_hashpair_ARRAYREFREF {
650 my ($self, $k, $v) = @_;
651 $self->_debug("REF($k) means literal SQL: @${$v}");
652 my ($sql, @bind) = @${$v};
653 $self->_assert_bindval_matches_bindtype(@bind);
654 $sql = $self->_quote($k) . " " . $sql;
655 return ($sql, @bind );
658 # literal SQL without bind
659 sub _where_hashpair_SCALAR {
660 my ($self, $k, $v) = @_;
661 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
662 my $sql = join ' ', $self->_convert($self->_quote($k)),
663 $self->_sqlcase($self->{cmp}),
664 $self->_convert('?');
665 my @bind = $self->_bindtype($k, $v);
666 return ( $sql, @bind);
670 sub _where_hashpair_UNDEF {
671 my ($self, $k, $v) = @_;
672 $self->_debug("UNDEF($k) means IS NULL");
673 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
677 #======================================================================
678 # WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
679 #======================================================================
682 sub _where_SCALARREF {
683 my ($self, $where) = @_;
686 $self->_debug("SCALAR(*top) means literal SQL: $$where");
692 my ($self, $where) = @_;
695 $self->_debug("NOREF(*top) means literal SQL: $where");
706 #======================================================================
707 # WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
708 #======================================================================
711 sub _where_field_BETWEEN {
712 my ($self, $k, $op, $vals) = @_;
714 (ref $vals eq 'ARRAY' && @$vals == 2) or
715 (ref $vals eq 'REF' && (@$$vals == 1 || @$$vals == 2 || @$$vals == 3))
716 or puke "special op 'between' requires an arrayref of two values (or a scalarref or arrayrefref for literal SQL)";
718 my ($clause, @bind, $label, $and, $placeholder);
719 $label = $self->_convert($self->_quote($k));
720 $and = ' ' . $self->_sqlcase('and') . ' ';
721 $placeholder = $self->_convert('?');
722 $op = $self->_sqlcase($op);
724 if (ref $vals eq 'REF') {
725 ($clause, @bind) = @$$vals;
728 my (@all_sql, @all_bind);
730 foreach my $val (@$vals) {
731 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
733 return ($placeholder, ($val));
736 return ($self->_convert($$val), ());
740 push @all_bind, @bind;
743 $clause = (join $and, @all_sql);
744 @bind = $self->_bindtype($k, @all_bind);
746 my $sql = "( $label $op $clause )";
751 sub _where_field_IN {
752 my ($self, $k, $op, $vals) = @_;
754 # backwards compatibility : if scalar, force into an arrayref
755 $vals = [$vals] if defined $vals && ! ref $vals;
757 my ($label) = $self->_convert($self->_quote($k));
758 my ($placeholder) = $self->_convert('?');
759 $op = $self->_sqlcase($op);
761 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
762 ARRAYREF => sub { # list of choices
763 if (@$vals) { # nonempty list
764 my $placeholders = join ", ", (($placeholder) x @$vals);
765 my $sql = "$label $op ( $placeholders )";
766 my @bind = $self->_bindtype($k, @$vals);
768 return ($sql, @bind);
770 else { # empty list : some databases won't understand "IN ()", so DWIM
771 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
776 ARRAYREFREF => sub { # literal SQL with bind
777 my ($sql, @bind) = @$$vals;
778 $self->_assert_bindval_matches_bindtype(@bind);
779 return ("$label $op ( $sql )", @bind);
783 puke "special op 'in' requires an arrayref (or arrayref-ref)";
787 return ($sql, @bind);
795 #======================================================================
797 #======================================================================
800 my ($self, $arg) = @_;
802 # construct list of ordering instructions
803 my @order = $self->_SWITCH_refkind($arg, {
806 map {$self->_SWITCH_refkind($_, {
807 SCALAR => sub {$self->_quote($_)},
809 SCALARREF => sub {$$_}, # literal SQL, no quoting
810 HASHREF => sub {$self->_order_by_hash($_)}
814 SCALAR => sub {$self->_quote($arg)},
816 SCALARREF => sub {$$arg}, # literal SQL, no quoting
817 HASHREF => sub {$self->_order_by_hash($arg)},
822 my $order = join ', ', @order;
823 return $order ? $self->_sqlcase(' order by')." $order" : '';
828 my ($self, $hash) = @_;
830 # get first pair in hash
831 my ($key, $val) = each %$hash;
833 # check if one pair was found and no other pair in hash
834 $key && !(each %$hash)
835 or puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
837 my ($order) = ($key =~ /^-(desc|asc)/i)
838 or puke "invalid key in _order_by hash : $key";
840 $val = ref $val eq 'ARRAY' ? $val : [$val];
841 return join ', ', map { $self->_quote($_) . ' ' . $self->_sqlcase($order) } @$val;
846 #======================================================================
847 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
848 #======================================================================
853 $self->_SWITCH_refkind($from, {
854 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
855 SCALAR => sub {$self->_quote($from)},
856 SCALARREF => sub {$$from},
857 ARRAYREFREF => sub {join ', ', @$from;},
862 #======================================================================
864 #======================================================================
870 $label or puke "can't quote an empty label";
872 # left and right quote characters
873 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
874 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
875 ARRAYREF => sub {@{$self->{quote_char}}},
879 or puke "quote_char must be an arrayref of 2 values";
881 # no quoting if no quoting chars
882 $ql or return $label;
884 # no quoting for literal SQL
885 return $$label if ref($label) eq 'SCALAR';
887 # separate table / column (if applicable)
888 my $sep = $self->{name_sep} || '';
889 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
891 # do the quoting, except for "*" or for `table`.*
892 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
894 # reassemble and return.
895 return join $sep, @quoted;
899 # Conversion, if applicable
901 my ($self, $arg) = @_;
903 # LDNOTE : modified the previous implementation below because
904 # it was not consistent : the first "return" is always an array,
905 # the second "return" is context-dependent. Anyway, _convert
906 # seems always used with just a single argument, so make it a
908 # return @_ unless $self->{convert};
909 # my $conv = $self->_sqlcase($self->{convert});
910 # my @ret = map { $conv.'('.$_.')' } @_;
911 # return wantarray ? @ret : $ret[0];
912 if ($self->{convert}) {
913 my $conv = $self->_sqlcase($self->{convert});
914 $arg = $conv.'('.$arg.')';
922 my($col, @vals) = @_;
924 #LDNOTE : changed original implementation below because it did not make
925 # sense when bindtype eq 'columns' and @vals > 1.
926 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
928 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
931 # Dies if any element of @bind is not in [colname => value] format
932 # if bindtype is 'columns'.
933 sub _assert_bindval_matches_bindtype {
934 my ($self, @bind) = @_;
936 if ($self->{bindtype} eq 'columns') {
937 foreach my $val (@bind) {
938 if (!defined $val || ref($val) ne 'ARRAY' || @$val != 2) {
939 die "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
945 sub _join_sql_clauses {
946 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
948 if (@$clauses_aref > 1) {
949 my $join = " " . $self->_sqlcase($logic) . " ";
950 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
951 return ($sql, @$bind_aref);
953 elsif (@$clauses_aref) {
954 return ($clauses_aref->[0], @$bind_aref); # no parentheses
957 return (); # if no SQL, ignore @$bind_aref
962 # Fix SQL case, if so requested
966 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
967 # don't touch the argument ... crooked logic, but let's not change it!
968 return $self->{case} ? $_[0] : uc($_[0]);
972 #======================================================================
973 # DISPATCHING FROM REFKIND
974 #======================================================================
977 my ($self, $data) = @_;
983 # blessed objects are treated like scalars
984 $ref = (blessed $data) ? '' : ref $data;
985 $n_steps += 1 if $ref;
986 last if $ref ne 'REF';
990 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
992 return $base . ('REF' x $n_steps);
998 my ($self, $data) = @_;
999 my @try = ($self->_refkind($data));
1000 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1001 push @try, 'FALLBACK';
1005 sub _METHOD_FOR_refkind {
1006 my ($self, $meth_prefix, $data) = @_;
1007 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
1008 $self->_try_refkind($data)
1009 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1014 sub _SWITCH_refkind {
1015 my ($self, $data, $dispatch_table) = @_;
1017 my $coderef = first {$_} map {$dispatch_table->{$_}}
1018 $self->_try_refkind($data)
1019 or puke "no dispatch entry for ".$self->_refkind($data);
1026 #======================================================================
1027 # VALUES, GENERATE, AUTOLOAD
1028 #======================================================================
1030 # LDNOTE: original code from nwiger, didn't touch code in that section
1031 # I feel the AUTOLOAD stuff should not be the default, it should
1032 # only be activated on explicit demand by user.
1036 my $data = shift || return;
1037 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1038 unless ref $data eq 'HASH';
1041 foreach my $k ( sort keys %$data ) {
1042 my $v = $data->{$k};
1043 $self->_SWITCH_refkind($v, {
1045 if ($self->{array_datatypes}) { # array datatype
1046 push @all_bind, $self->_bindtype($k, $v);
1048 else { # literal SQL with bind
1049 my ($sql, @bind) = @$v;
1050 $self->_assert_bindval_matches_bindtype(@bind);
1051 push @all_bind, @bind;
1054 ARRAYREFREF => sub { # literal SQL with bind
1055 my ($sql, @bind) = @${$v};
1056 $self->_assert_bindval_matches_bindtype(@bind);
1057 push @all_bind, @bind;
1059 SCALARREF => sub { # literal SQL without bind
1061 SCALAR_or_UNDEF => sub {
1062 push @all_bind, $self->_bindtype($k, $v);
1073 my(@sql, @sqlq, @sqlv);
1077 if ($ref eq 'HASH') {
1078 for my $k (sort keys %$_) {
1081 my $label = $self->_quote($k);
1082 if ($r eq 'ARRAY') {
1083 # literal SQL with bind
1084 my ($sql, @bind) = @$v;
1085 $self->_assert_bindval_matches_bindtype(@bind);
1086 push @sqlq, "$label = $sql";
1088 } elsif ($r eq 'SCALAR') {
1089 # literal SQL without bind
1090 push @sqlq, "$label = $$v";
1092 push @sqlq, "$label = ?";
1093 push @sqlv, $self->_bindtype($k, $v);
1096 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1097 } elsif ($ref eq 'ARRAY') {
1098 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1101 if ($r eq 'ARRAY') { # literal SQL with bind
1102 my ($sql, @bind) = @$v;
1103 $self->_assert_bindval_matches_bindtype(@bind);
1106 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1107 # embedded literal SQL
1114 push @sql, '(' . join(', ', @sqlq) . ')';
1115 } elsif ($ref eq 'SCALAR') {
1119 # strings get case twiddled
1120 push @sql, $self->_sqlcase($_);
1124 my $sql = join ' ', @sql;
1126 # this is pretty tricky
1127 # if ask for an array, return ($stmt, @bind)
1128 # otherwise, s/?/shift @sqlv/ to put it inline
1130 return ($sql, @sqlv);
1132 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1133 ref $d ? $d->[1] : $d/e;
1142 # This allows us to check for a local, then _form, attr
1144 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1145 return $self->generate($name, @_);
1156 SQL::Abstract - Generate SQL from Perl data structures
1162 my $sql = SQL::Abstract->new;
1164 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1166 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1168 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1170 my($stmt, @bind) = $sql->delete($table, \%where);
1172 # Then, use these in your DBI statements
1173 my $sth = $dbh->prepare($stmt);
1174 $sth->execute(@bind);
1176 # Just generate the WHERE clause
1177 my($stmt, @bind) = $sql->where(\%where, \@order);
1179 # Return values in the same order, for hashed queries
1180 # See PERFORMANCE section for more details
1181 my @bind = $sql->values(\%fieldvals);
1185 This module was inspired by the excellent L<DBIx::Abstract>.
1186 However, in using that module I found that what I really wanted
1187 to do was generate SQL, but still retain complete control over my
1188 statement handles and use the DBI interface. So, I set out to
1189 create an abstract SQL generation module.
1191 While based on the concepts used by L<DBIx::Abstract>, there are
1192 several important differences, especially when it comes to WHERE
1193 clauses. I have modified the concepts used to make the SQL easier
1194 to generate from Perl data structures and, IMO, more intuitive.
1195 The underlying idea is for this module to do what you mean, based
1196 on the data structures you provide it. The big advantage is that
1197 you don't have to modify your code every time your data changes,
1198 as this module figures it out.
1200 To begin with, an SQL INSERT is as easy as just specifying a hash
1201 of C<key=value> pairs:
1204 name => 'Jimbo Bobson',
1205 phone => '123-456-7890',
1206 address => '42 Sister Lane',
1207 city => 'St. Louis',
1208 state => 'Louisiana',
1211 The SQL can then be generated with this:
1213 my($stmt, @bind) = $sql->insert('people', \%data);
1215 Which would give you something like this:
1217 $stmt = "INSERT INTO people
1218 (address, city, name, phone, state)
1219 VALUES (?, ?, ?, ?, ?)";
1220 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1221 '123-456-7890', 'Louisiana');
1223 These are then used directly in your DBI code:
1225 my $sth = $dbh->prepare($stmt);
1226 $sth->execute(@bind);
1228 =head2 Inserting and Updating Arrays
1230 If your database has array types (like for example Postgres),
1231 activate the special option C<< array_datatypes => 1 >>
1232 when creating the C<SQL::Abstract> object.
1233 Then you may use an arrayref to insert and update database array types:
1235 my $sql = SQL::Abstract->new(array_datatypes => 1);
1237 planets => [qw/Mercury Venus Earth Mars/]
1240 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1244 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1246 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1249 =head2 Inserting and Updating SQL
1251 In order to apply SQL functions to elements of your C<%data> you may
1252 specify a reference to an arrayref for the given hash value. For example,
1253 if you need to execute the Oracle C<to_date> function on a value, you can
1254 say something like this:
1258 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
1261 The first value in the array is the actual SQL. Any other values are
1262 optional and would be included in the bind values array. This gives
1265 my($stmt, @bind) = $sql->insert('people', \%data);
1267 $stmt = "INSERT INTO people (name, date_entered)
1268 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1269 @bind = ('Bill', '03/02/2003');
1271 An UPDATE is just as easy, all you change is the name of the function:
1273 my($stmt, @bind) = $sql->update('people', \%data);
1275 Notice that your C<%data> isn't touched; the module will generate
1276 the appropriately quirky SQL for you automatically. Usually you'll
1277 want to specify a WHERE clause for your UPDATE, though, which is
1278 where handling C<%where> hashes comes in handy...
1280 =head2 Complex where statements
1282 This module can generate pretty complicated WHERE statements
1283 easily. For example, simple C<key=value> pairs are taken to mean
1284 equality, and if you want to see if a field is within a set
1285 of values, you can use an arrayref. Let's say we wanted to
1286 SELECT some data based on this criteria:
1289 requestor => 'inna',
1290 worker => ['nwiger', 'rcwe', 'sfz'],
1291 status => { '!=', 'completed' }
1294 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1296 The above would give you something like this:
1298 $stmt = "SELECT * FROM tickets WHERE
1299 ( requestor = ? ) AND ( status != ? )
1300 AND ( worker = ? OR worker = ? OR worker = ? )";
1301 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1303 Which you could then use in DBI code like so:
1305 my $sth = $dbh->prepare($stmt);
1306 $sth->execute(@bind);
1312 The functions are simple. There's one for each major SQL operation,
1313 and a constructor you use first. The arguments are specified in a
1314 similar order to each function (table, then fields, then a where
1315 clause) to try and simplify things.
1320 =head2 new(option => 'value')
1322 The C<new()> function takes a list of options and values, and returns
1323 a new B<SQL::Abstract> object which can then be used to generate SQL
1324 through the methods below. The options accepted are:
1330 If set to 'lower', then SQL will be generated in all lowercase. By
1331 default SQL is generated in "textbook" case meaning something like:
1333 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1335 Any setting other than 'lower' is ignored.
1339 This determines what the default comparison operator is. By default
1340 it is C<=>, meaning that a hash like this:
1342 %where = (name => 'nwiger', email => 'nate@wiger.org');
1344 Will generate SQL like this:
1346 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1348 However, you may want loose comparisons by default, so if you set
1349 C<cmp> to C<like> you would get SQL such as:
1351 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1353 You can also override the comparsion on an individual basis - see
1354 the huge section on L</"WHERE CLAUSES"> at the bottom.
1356 =item sqltrue, sqlfalse
1358 Expressions for inserting boolean values within SQL statements.
1359 By default these are C<1=1> and C<1=0>. They are used
1360 by the special operators C<-in> and C<-not_in> for generating
1361 correct SQL even when the argument is an empty array (see below).
1365 This determines the default logical operator for multiple WHERE
1366 statements in arrays or hashes. If absent, the default logic is "or"
1367 for arrays, and "and" for hashes. This means that a WHERE
1371 event_date => {'>=', '2/13/99'},
1372 event_date => {'<=', '4/24/03'},
1375 will generate SQL like this:
1377 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1379 This is probably not what you want given this query, though (look
1380 at the dates). To change the "OR" to an "AND", simply specify:
1382 my $sql = SQL::Abstract->new(logic => 'and');
1384 Which will change the above C<WHERE> to:
1386 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1388 The logic can also be changed locally by inserting
1389 a modifier in front of an arrayref :
1391 @where = (-and => [event_date => {'>=', '2/13/99'},
1392 event_date => {'<=', '4/24/03'} ]);
1394 See the L</"WHERE CLAUSES"> section for explanations.
1398 This will automatically convert comparisons using the specified SQL
1399 function for both column and value. This is mostly used with an argument
1400 of C<upper> or C<lower>, so that the SQL will have the effect of
1401 case-insensitive "searches". For example, this:
1403 $sql = SQL::Abstract->new(convert => 'upper');
1404 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1406 Will turn out the following SQL:
1408 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1410 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1411 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1412 not validate this option; it will just pass through what you specify verbatim).
1416 This is a kludge because many databases suck. For example, you can't
1417 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1418 Instead, you have to use C<bind_param()>:
1420 $sth->bind_param(1, 'reg data');
1421 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1423 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1424 which loses track of which field each slot refers to. Fear not.
1426 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1427 Currently, you can specify either C<normal> (default) or C<columns>. If you
1428 specify C<columns>, you will get an array that looks like this:
1430 my $sql = SQL::Abstract->new(bindtype => 'columns');
1431 my($stmt, @bind) = $sql->insert(...);
1434 [ 'column1', 'value1' ],
1435 [ 'column2', 'value2' ],
1436 [ 'column3', 'value3' ],
1439 You can then iterate through this manually, using DBI's C<bind_param()>.
1441 $sth->prepare($stmt);
1444 my($col, $data) = @$_;
1445 if ($col eq 'details' || $col eq 'comments') {
1446 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1447 } elsif ($col eq 'image') {
1448 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1450 $sth->bind_param($i, $data);
1454 $sth->execute; # execute without @bind now
1456 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1457 Basically, the advantage is still that you don't have to care which fields
1458 are or are not included. You could wrap that above C<for> loop in a simple
1459 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1460 get a layer of abstraction over manual SQL specification.
1462 Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1463 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1464 will expect the bind values in this format.
1468 This is the character that a table or column name will be quoted
1469 with. By default this is an empty string, but you could set it to
1470 the character C<`>, to generate SQL like this:
1472 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1474 Alternatively, you can supply an array ref of two items, the first being the left
1475 hand quote character, and the second the right hand quote character. For
1476 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1477 that generates SQL like this:
1479 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1481 Quoting is useful if you have tables or columns names that are reserved
1482 words in your database's SQL dialect.
1486 This is the character that separates a table and column name. It is
1487 necessary to specify this when the C<quote_char> option is selected,
1488 so that tables and column names can be individually quoted like this:
1490 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1492 =item array_datatypes
1494 When this option is true, arrayrefs in INSERT or UPDATE are
1495 interpreted as array datatypes and are passed directly
1497 When this option is false, arrayrefs are interpreted
1498 as literal SQL, just like refs to arrayrefs
1499 (but this behavior is for backwards compatibility; when writing
1500 new queries, use the "reference to arrayref" syntax
1506 Takes a reference to a list of "special operators"
1507 to extend the syntax understood by L<SQL::Abstract>.
1508 See section L</"SPECIAL OPERATORS"> for details.
1514 =head2 insert($table, \@values || \%fieldvals)
1516 This is the simplest function. You simply give it a table name
1517 and either an arrayref of values or hashref of field/value pairs.
1518 It returns an SQL INSERT statement and a list of bind values.
1519 See the sections on L</"Inserting and Updating Arrays"> and
1520 L</"Inserting and Updating SQL"> for information on how to insert
1521 with those data types.
1523 =head2 update($table, \%fieldvals, \%where)
1525 This takes a table, hashref of field/value pairs, and an optional
1526 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1528 See the sections on L</"Inserting and Updating Arrays"> and
1529 L</"Inserting and Updating SQL"> for information on how to insert
1530 with those data types.
1532 =head2 select($source, $fields, $where, $order)
1534 This returns a SQL SELECT statement and associated list of bind values, as
1535 specified by the arguments :
1541 Specification of the 'FROM' part of the statement.
1542 The argument can be either a plain scalar (interpreted as a table
1543 name, will be quoted), or an arrayref (interpreted as a list
1544 of table names, joined by commas, quoted), or a scalarref
1545 (literal table name, not quoted), or a ref to an arrayref
1546 (list of literal table names, joined by commas, not quoted).
1550 Specification of the list of fields to retrieve from
1552 The argument can be either an arrayref (interpreted as a list
1553 of field names, will be joined by commas and quoted), or a
1554 plain scalar (literal SQL, not quoted).
1555 Please observe that this API is not as flexible as for
1556 the first argument C<$table>, for backwards compatibility reasons.
1560 Optional argument to specify the WHERE part of the query.
1561 The argument is most often a hashref, but can also be
1562 an arrayref or plain scalar --
1563 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1567 Optional argument to specify the ORDER BY part of the query.
1568 The argument can be a scalar, a hashref or an arrayref
1569 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1575 =head2 delete($table, \%where)
1577 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1578 It returns an SQL DELETE statement and list of bind values.
1580 =head2 where(\%where, \@order)
1582 This is used to generate just the WHERE clause. For example,
1583 if you have an arbitrary data structure and know what the
1584 rest of your SQL is going to look like, but want an easy way
1585 to produce a WHERE clause, use this. It returns an SQL WHERE
1586 clause and list of bind values.
1589 =head2 values(\%data)
1591 This just returns the values from the hash C<%data>, in the same
1592 order that would be returned from any of the other above queries.
1593 Using this allows you to markedly speed up your queries if you
1594 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1596 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1598 Warning: This is an experimental method and subject to change.
1600 This returns arbitrarily generated SQL. It's a really basic shortcut.
1601 It will return two different things, depending on return context:
1603 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1604 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1606 These would return the following:
1608 # First calling form
1609 $stmt = "CREATE TABLE test (?, ?)";
1610 @bind = (field1, field2);
1612 # Second calling form
1613 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1615 Depending on what you're trying to do, it's up to you to choose the correct
1616 format. In this example, the second form is what you would want.
1620 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1624 ALTER SESSION SET nls_date_format = 'MM/YY'
1626 You get the idea. Strings get their case twiddled, but everything
1627 else remains verbatim.
1632 =head1 WHERE CLAUSES
1636 This module uses a variation on the idea from L<DBIx::Abstract>. It
1637 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1638 module is that things in arrays are OR'ed, and things in hashes
1641 The easiest way to explain is to show lots of examples. After
1642 each C<%where> hash shown, it is assumed you used:
1644 my($stmt, @bind) = $sql->where(\%where);
1646 However, note that the C<%where> hash can be used directly in any
1647 of the other functions as well, as described above.
1649 =head2 Key-value pairs
1651 So, let's get started. To begin, a simple hash:
1655 status => 'completed'
1658 Is converted to SQL C<key = val> statements:
1660 $stmt = "WHERE user = ? AND status = ?";
1661 @bind = ('nwiger', 'completed');
1663 One common thing I end up doing is having a list of values that
1664 a field can be in. To do this, simply specify a list inside of
1669 status => ['assigned', 'in-progress', 'pending'];
1672 This simple code will create the following:
1674 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1675 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1677 A field associated to an empty arrayref will be considered a
1678 logical false and will generate 0=1.
1680 =head2 Specific comparison operators
1682 If you want to specify a different type of operator for your comparison,
1683 you can use a hashref for a given column:
1687 status => { '!=', 'completed' }
1690 Which would generate:
1692 $stmt = "WHERE user = ? AND status != ?";
1693 @bind = ('nwiger', 'completed');
1695 To test against multiple values, just enclose the values in an arrayref:
1697 status => { '=', ['assigned', 'in-progress', 'pending'] };
1699 Which would give you:
1701 "WHERE status = ? OR status = ? OR status = ?"
1704 The hashref can also contain multiple pairs, in which case it is expanded
1705 into an C<AND> of its elements:
1709 status => { '!=', 'completed', -not_like => 'pending%' }
1712 # Or more dynamically, like from a form
1713 $where{user} = 'nwiger';
1714 $where{status}{'!='} = 'completed';
1715 $where{status}{'-not_like'} = 'pending%';
1717 # Both generate this
1718 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1719 @bind = ('nwiger', 'completed', 'pending%');
1722 To get an OR instead, you can combine it with the arrayref idea:
1726 priority => [ {'=', 2}, {'!=', 1} ]
1729 Which would generate:
1731 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1732 @bind = ('nwiger', '2', '1');
1734 If you want to include literal SQL (with or without bind values), just use a
1735 scalar reference or array reference as the value:
1738 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1739 date_expires => { '<' => \"now()" }
1742 Which would generate:
1744 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1745 @bind = ('11/26/2008');
1748 =head2 Logic and nesting operators
1750 In the example above,
1751 there is a subtle trap if you want to say something like
1752 this (notice the C<AND>):
1754 WHERE priority != ? AND priority != ?
1756 Because, in Perl you I<can't> do this:
1758 priority => { '!=', 2, '!=', 1 }
1760 As the second C<!=> key will obliterate the first. The solution
1761 is to use the special C<-modifier> form inside an arrayref:
1763 priority => [ -and => {'!=', 2},
1767 Normally, these would be joined by C<OR>, but the modifier tells it
1768 to use C<AND> instead. (Hint: You can use this in conjunction with the
1769 C<logic> option to C<new()> in order to change the way your queries
1770 work by default.) B<Important:> Note that the C<-modifier> goes
1771 B<INSIDE> the arrayref, as an extra first element. This will
1772 B<NOT> do what you think it might:
1774 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1776 Here is a quick list of equivalencies, since there is some overlap:
1779 status => {'!=', 'completed', 'not like', 'pending%' }
1780 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1783 status => {'=', ['assigned', 'in-progress']}
1784 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1785 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1789 =head2 Special operators : IN, BETWEEN, etc.
1791 You can also use the hashref format to compare a list of fields using the
1792 C<IN> comparison operator, by specifying the list as an arrayref:
1795 status => 'completed',
1796 reportid => { -in => [567, 2335, 2] }
1799 Which would generate:
1801 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1802 @bind = ('completed', '567', '2335', '2');
1804 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1807 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
1808 (by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
1809 'sqltrue' (by default : C<1=1>).
1813 Another pair of operators is C<-between> and C<-not_between>,
1814 used with an arrayref of two values:
1818 completion_date => {
1819 -not_between => ['2002-10-01', '2003-02-06']
1825 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1827 These are the two builtin "special operators"; but the
1828 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1830 =head2 Nested conditions, -and/-or prefixes
1832 So far, we've seen how multiple conditions are joined with a top-level
1833 C<AND>. We can change this by putting the different conditions we want in
1834 hashes and then putting those hashes in an array. For example:
1839 status => { -like => ['pending%', 'dispatched'] },
1843 status => 'unassigned',
1847 This data structure would create the following:
1849 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1850 OR ( user = ? AND status = ? ) )";
1851 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1854 There is also a special C<-nest>
1855 operator which adds an additional set of parens, to create a subquery.
1856 For example, to get something like this:
1858 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
1859 @bind = ('nwiger', '20', 'ASIA');
1865 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1869 Finally, clauses in hashrefs or arrayrefs can be
1870 prefixed with an C<-and> or C<-or> to change the logic
1877 -and => [workhrs => {'>', 20}, geo => 'ASIA' ],
1878 -and => [workhrs => {'<', 50}, geo => 'EURO' ]
1885 WHERE ( user = ? AND
1886 ( ( workhrs > ? AND geo = ? )
1887 OR ( workhrs < ? AND geo = ? ) ) )
1890 =head2 Algebraic inconsistency, for historical reasons
1892 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
1893 operator goes C<outside> of the nested structure; whereas when connecting
1894 several constraints on one column, the C<-and> operator goes
1895 C<inside> the arrayref. Here is an example combining both features :
1898 -and => [a => 1, b => 2],
1899 -or => [c => 3, d => 4],
1900 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
1905 WHERE ( ( ( a = ? AND b = ? )
1906 OR ( c = ? OR d = ? )
1907 OR ( e LIKE ? AND e LIKE ? ) ) )
1909 This difference in syntax is unfortunate but must be preserved for
1910 historical reasons. So be careful : the two examples below would
1911 seem algebraically equivalent, but they are not
1913 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
1914 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
1916 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
1917 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
1922 Finally, sometimes only literal SQL will do. If you want to include
1923 literal SQL verbatim, you can specify it as a scalar reference, namely:
1925 my $inn = 'is Not Null';
1927 priority => { '<', 2 },
1933 $stmt = "WHERE priority < ? AND requestor is Not Null";
1936 Note that in this example, you only get one bind parameter back, since
1937 the verbatim SQL is passed as part of the statement.
1939 Of course, just to prove a point, the above can also be accomplished
1943 priority => { '<', 2 },
1944 requestor => { '!=', undef },
1950 Conditions on boolean columns can be expressed in the
1951 same way, passing a reference to an empty string :
1954 priority => { '<', 2 },
1960 $stmt = "WHERE priority < ? AND is_ready";
1964 =head2 Literal SQL with placeholders and bind values (subqueries)
1966 If the literal SQL to be inserted has placeholders and bind values,
1967 use a reference to an arrayref (yes this is a double reference --
1968 not so common, but perfectly legal Perl). For example, to find a date
1969 in Postgres you can use something like this:
1972 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1977 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
1980 Note that you must pass the bind values in the same format as they are returned
1981 by L</where>. That means that if you set L</bindtype> to C<columns>, you must
1982 provide the bind values in the C<< [ column_meta => value ] >> format, where
1983 C<column_meta> is an opaque scalar value; most commonly the column name, but
1984 you can use any scalar value (including references and blessed references),
1985 L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
1986 to C<columns> the above example will look like:
1989 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
1992 Literal SQL is especially useful for nesting parenthesized clauses in the
1993 main SQL query. Here is a first example :
1995 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1999 bar => \["IN ($sub_stmt)" => @sub_bind],
2004 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2005 WHERE c2 < ? AND c3 LIKE ?))";
2006 @bind = (1234, 100, "foo%");
2008 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2009 are expressed in the same way. Of course the C<$sub_stmt> and
2010 its associated bind values can be generated through a former call
2013 my ($sub_stmt, @sub_bind)
2014 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2015 c3 => {-like => "foo%"}});
2018 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2021 In the examples above, the subquery was used as an operator on a column;
2022 but the same principle also applies for a clause within the main C<%where>
2023 hash, like an EXISTS subquery :
2025 my ($sub_stmt, @sub_bind)
2026 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2029 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
2034 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2035 WHERE c1 = ? AND c2 > t0.c0))";
2039 Observe that the condition on C<c2> in the subquery refers to
2040 column C<t0.c0> of the main query : this is I<not> a bind
2041 value, so we have to express it through a scalar ref.
2042 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2043 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2044 what we wanted here.
2046 Another use of the subquery technique is when some SQL clauses need
2047 parentheses, as it often occurs with some proprietary SQL extensions
2048 like for example fulltext expressions, geospatial expressions,
2049 NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
2052 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
2055 Finally, here is an example where a subquery is used
2056 for expressing unary negation:
2058 my ($sub_stmt, @sub_bind)
2059 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2060 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2062 lname => {like => '%son%'},
2063 -nest => \["NOT ($sub_stmt)" => @sub_bind],
2068 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2069 @bind = ('%son%', 10, 20)
2075 These pages could go on for a while, since the nesting of the data
2076 structures this module can handle are pretty much unlimited (the
2077 module implements the C<WHERE> expansion as a recursive function
2078 internally). Your best bet is to "play around" with the module a
2079 little to see how the data structures behave, and choose the best
2080 format for your data based on that.
2082 And of course, all the values above will probably be replaced with
2083 variables gotten from forms or the command line. After all, if you
2084 knew everything ahead of time, you wouldn't have to worry about
2085 dynamically-generating SQL and could just hardwire it into your
2091 =head1 ORDER BY CLAUSES
2093 Some functions take an order by clause. This can either be a scalar (just a
2094 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
2095 or an array of either of the two previous forms. Examples:
2097 Given | Will Generate
2098 ----------------------------------------------------------
2100 \'colA DESC' | ORDER BY colA DESC
2102 'colA' | ORDER BY colA
2104 [qw/colA colB/] | ORDER BY colA, colB
2106 {-asc => 'colA'} | ORDER BY colA ASC
2108 {-desc => 'colB'} | ORDER BY colB DESC
2110 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2112 { -asc => [qw/colA colB] } | ORDER BY colA ASC, colB ASC
2115 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
2116 { -desc => [qw/colB/], | colC ASC, colD ASC
2117 { -asc => [qw/colC colD/],|
2119 ===========================================================
2123 =head1 SPECIAL OPERATORS
2125 my $sqlmaker = SQL::Abstract->new(special_ops => [
2128 my ($self, $field, $op, $arg) = @_;
2134 A "special operator" is a SQL syntactic clause that can be
2135 applied to a field, instead of a usual binary operator.
2138 WHERE field IN (?, ?, ?)
2139 WHERE field BETWEEN ? AND ?
2140 WHERE MATCH(field) AGAINST (?, ?)
2142 Special operators IN and BETWEEN are fairly standard and therefore
2143 are builtin within C<SQL::Abstract>. For other operators,
2144 like the MATCH .. AGAINST example above which is
2145 specific to MySQL, you can write your own operator handlers :
2146 supply a C<special_ops> argument to the C<new> method.
2147 That argument takes an arrayref of operator definitions;
2148 each operator definition is a hashref with two entries
2154 the regular expression to match the operator
2158 coderef that will be called when meeting that operator
2159 in the input tree. The coderef will be called with
2160 arguments C<< ($self, $field, $op, $arg) >>, and
2161 should return a C<< ($sql, @bind) >> structure.
2165 For example, here is an implementation
2166 of the MATCH .. AGAINST syntax for MySQL
2168 my $sqlmaker = SQL::Abstract->new(special_ops => [
2170 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2171 {regex => qr/^match$/i,
2173 my ($self, $field, $op, $arg) = @_;
2174 $arg = [$arg] if not ref $arg;
2175 my $label = $self->_quote($field);
2176 my ($placeholder) = $self->_convert('?');
2177 my $placeholders = join ", ", (($placeholder) x @$arg);
2178 my $sql = $self->_sqlcase('match') . " ($label) "
2179 . $self->_sqlcase('against') . " ($placeholders) ";
2180 my @bind = $self->_bindtype($field, @$arg);
2181 return ($sql, @bind);
2190 Thanks to some benchmarking by Mark Stosberg, it turns out that
2191 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2192 I must admit this wasn't an intentional design issue, but it's a
2193 byproduct of the fact that you get to control your C<DBI> handles
2196 To maximize performance, use a code snippet like the following:
2198 # prepare a statement handle using the first row
2199 # and then reuse it for the rest of the rows
2201 for my $href (@array_of_hashrefs) {
2202 $stmt ||= $sql->insert('table', $href);
2203 $sth ||= $dbh->prepare($stmt);
2204 $sth->execute($sql->values($href));
2207 The reason this works is because the keys in your C<$href> are sorted
2208 internally by B<SQL::Abstract>. Thus, as long as your data retains
2209 the same structure, you only have to generate the SQL the first time
2210 around. On subsequent queries, simply use the C<values> function provided
2211 by this module to return your values in the correct order.
2216 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2217 really like this part (I do, at least). Building up a complex query
2218 can be as simple as the following:
2222 use CGI::FormBuilder;
2225 my $form = CGI::FormBuilder->new(...);
2226 my $sql = SQL::Abstract->new;
2228 if ($form->submitted) {
2229 my $field = $form->field;
2230 my $id = delete $field->{id};
2231 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2234 Of course, you would still have to connect using C<DBI> to run the
2235 query, but the point is that if you make your form look like your
2236 table, the actual query script can be extremely simplistic.
2238 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2239 a fast interface to returning and formatting data. I frequently
2240 use these three modules together to write complex database query
2241 apps in under 50 lines.
2246 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2247 Great care has been taken to preserve the I<published> behavior
2248 documented in previous versions in the 1.* family; however,
2249 some features that were previously undocumented, or behaved
2250 differently from the documentation, had to be changed in order
2251 to clarify the semantics. Hence, client code that was relying
2252 on some dark areas of C<SQL::Abstract> v1.*
2253 B<might behave differently> in v1.50.
2255 The main changes are :
2261 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2265 support for the { operator => \"..." } construct (to embed literal SQL)
2269 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2273 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2277 defensive programming : check arguments
2281 fixed bug with global logic, which was previously implemented
2282 through global variables yielding side-effects. Prior versions would
2283 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2284 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2285 Now this is interpreted
2286 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2291 fixed semantics of _bindtype on array args
2295 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2296 we just avoid shifting arrays within that tree.
2300 dropped the C<_modlogic> function
2306 =head1 ACKNOWLEDGEMENTS
2308 There are a number of individuals that have really helped out with
2309 this module. Unfortunately, most of them submitted bugs via CPAN
2310 so I have no idea who they are! But the people I do know are:
2312 Ash Berlin (order_by hash term support)
2313 Matt Trout (DBIx::Class support)
2314 Mark Stosberg (benchmarking)
2315 Chas Owens (initial "IN" operator support)
2316 Philip Collins (per-field SQL functions)
2317 Eric Kolve (hashref "AND" support)
2318 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2319 Dan Kubb (support for "quote_char" and "name_sep")
2320 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2321 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
2322 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2323 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
2329 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2333 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2335 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
2337 For support, your best bet is to try the C<DBIx::Class> users mailing list.
2338 While not an official support venue, C<DBIx::Class> makes heavy use of
2339 C<SQL::Abstract>, and as such list members there are very familiar with
2340 how to create queries.
2342 This module is free software; you may copy this under the terms of
2343 the GNU General Public License, or the Artistic License, copies of
2344 which should have accompanied your Perl kit.