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.50';
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} = 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, $v) = @_;
447 $op =~ /^(AND|OR|NEST)[_\d]*/i
448 or puke "unknown operator: -$op";
449 $op = uc($1); # uppercase, remove trailing digits
450 $self->_debug("OP(-$op) within hashref, recursing...");
452 $self->_SWITCH_refkind($v, {
455 return $self->_where_ARRAYREF($v, $op eq 'NEST' ? '' : $op);
460 return $self->_where_ARRAYREF([%$v], 'OR');
463 return $self->_where_HASHREF($v);
467 SCALARREF => sub { # literal SQL
469 or puke "-$op => \\\$scalar not supported, use -nest => ...";
473 ARRAYREFREF => sub { # literal SQL
475 or puke "-$op => \\[..] not supported, use -nest => ...";
479 SCALAR => sub { # permissively interpreted as SQL
481 or puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
482 belch "literal SQL should be -nest => \\'scalar' "
483 . "instead of -nest => 'scalar' ";
488 puke "-$op => undef not supported";
494 sub _where_hashpair_ARRAYREF {
495 my ($self, $k, $v) = @_;
498 my @v = @$v; # need copy because of shift below
499 $self->_debug("ARRAY($k) means distribute over elements");
501 # put apart first element if it is an operator (-and, -or)
502 my $op = $v[0] =~ /^-/ ? shift @v : undef;
503 $self->_debug("OP($op) reinjected into the distributed array") if $op;
505 my @distributed = map { {$k => $_} } @v;
506 unshift @distributed, $op if $op;
507 my $logic = $op ? substr($op, 1) : '';
509 return $self->_recurse_where(\@distributed, $logic);
512 # LDNOTE : not sure of this one. What does "distribute over nothing" mean?
513 $self->_debug("empty ARRAY($k) means 0=1");
514 return ($self->{sqlfalse});
518 sub _where_hashpair_HASHREF {
519 my ($self, $k, $v) = @_;
521 my (@all_sql, @all_bind);
523 for my $op (sort keys %$v) {
526 # put the operator in canonical form
527 $op =~ s/^-//; # remove initial dash
528 $op =~ tr/_/ /; # underscores become spaces
529 $op =~ s/^\s+//; # no initial space
530 $op =~ s/\s+$//; # no final space
531 $op =~ s/\s+/ /; # multiple spaces become one
535 # CASE: special operators like -in or -between
536 my $special_op = first {$op =~ $_->{regex}} @{$self->{special_ops}};
538 ($sql, @bind) = $special_op->{handler}->($self, $k, $op, $val);
541 $self->_SWITCH_refkind($val, {
543 ARRAYREF => sub { # CASE: col => {op => \@vals}
544 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
547 SCALARREF => sub { # CASE: col => {op => \$scalar} (literal SQL without bind)
548 $sql = join ' ', $self->_convert($self->_quote($k)),
549 $self->_sqlcase($op),
553 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]} (literal SQL with bind)
554 my ($sub_sql, @sub_bind) = @$$val;
555 $self->_assert_bindval_matches_bindtype(@sub_bind);
556 $sql = join ' ', $self->_convert($self->_quote($k)),
557 $self->_sqlcase($op),
562 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
563 my $is = ($op =~ $self->{equality_op}) ? 'is' :
564 ($op =~ $self->{inequality_op}) ? 'is not' :
565 puke "unexpected operator '$op' with undef operand";
566 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
569 FALLBACK => sub { # CASE: col => {op => $scalar}
570 $sql = join ' ', $self->_convert($self->_quote($k)),
571 $self->_sqlcase($op),
572 $self->_convert('?');
573 @bind = $self->_bindtype($k, $val);
579 push @all_bind, @bind;
582 return $self->_join_sql_clauses('and', \@all_sql, \@all_bind);
587 sub _where_field_op_ARRAYREF {
588 my ($self, $k, $op, $vals) = @_;
591 $self->_debug("ARRAY($vals) means multiple elements: [ @$vals ]");
593 # LDNOTE : had planned to change the distribution logic when
594 # $op =~ $self->{inequality_op}, because of Morgan laws :
595 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
596 # WHERE field != 22 OR field != 33 : the user probably means
597 # WHERE field != 22 AND field != 33.
598 # To do this, replace the line below by :
599 # my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
600 # return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
602 # distribute $op over each member of @$vals
603 return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals]);
606 # try to DWIM on equality operators
607 # LDNOTE : not 100% sure this is the correct thing to do ...
608 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
609 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
612 puke "operator '$op' applied on an empty array (field '$k')";
617 sub _where_hashpair_SCALARREF {
618 my ($self, $k, $v) = @_;
619 $self->_debug("SCALAR($k) means literal SQL: $$v");
620 my $sql = $self->_quote($k) . " " . $$v;
624 # literal SQL with bind
625 sub _where_hashpair_ARRAYREFREF {
626 my ($self, $k, $v) = @_;
627 $self->_debug("REF($k) means literal SQL: @${$v}");
628 my ($sql, @bind) = @${$v};
629 $self->_assert_bindval_matches_bindtype(@bind);
630 $sql = $self->_quote($k) . " " . $sql;
631 return ($sql, @bind );
634 # literal SQL without bind
635 sub _where_hashpair_SCALAR {
636 my ($self, $k, $v) = @_;
637 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
638 my $sql = join ' ', $self->_convert($self->_quote($k)),
639 $self->_sqlcase($self->{cmp}),
640 $self->_convert('?');
641 my @bind = $self->_bindtype($k, $v);
642 return ( $sql, @bind);
646 sub _where_hashpair_UNDEF {
647 my ($self, $k, $v) = @_;
648 $self->_debug("UNDEF($k) means IS NULL");
649 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
653 #======================================================================
654 # WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
655 #======================================================================
658 sub _where_SCALARREF {
659 my ($self, $where) = @_;
662 $self->_debug("SCALAR(*top) means literal SQL: $$where");
668 my ($self, $where) = @_;
671 $self->_debug("NOREF(*top) means literal SQL: $where");
682 #======================================================================
683 # WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
684 #======================================================================
687 sub _where_field_BETWEEN {
688 my ($self, $k, $op, $vals) = @_;
690 ref $vals eq 'ARRAY' && @$vals == 2
691 or puke "special op 'between' requires an arrayref of two values";
693 my ($label) = $self->_convert($self->_quote($k));
694 my ($placeholder) = $self->_convert('?');
695 my $and = $self->_sqlcase('and');
696 $op = $self->_sqlcase($op);
698 my $sql = "( $label $op $placeholder $and $placeholder )";
699 my @bind = $self->_bindtype($k, @$vals);
704 sub _where_field_IN {
705 my ($self, $k, $op, $vals) = @_;
707 # backwards compatibility : if scalar, force into an arrayref
708 $vals = [$vals] if defined $vals && ! ref $vals;
710 my ($label) = $self->_convert($self->_quote($k));
711 my ($placeholder) = $self->_convert('?');
712 $op = $self->_sqlcase($op);
714 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
715 ARRAYREF => sub { # list of choices
716 if (@$vals) { # nonempty list
717 my $placeholders = join ", ", (($placeholder) x @$vals);
718 my $sql = "$label $op ( $placeholders )";
719 my @bind = $self->_bindtype($k, @$vals);
721 return ($sql, @bind);
723 else { # empty list : some databases won't understand "IN ()", so DWIM
724 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
729 ARRAYREFREF => sub { # literal SQL with bind
730 my ($sql, @bind) = @$$vals;
731 $self->_assert_bindval_matches_bindtype(@bind);
732 return ("$label $op ( $sql )", @bind);
736 puke "special op 'in' requires an arrayref (or arrayref-ref)";
740 return ($sql, @bind);
748 #======================================================================
750 #======================================================================
753 my ($self, $arg) = @_;
755 # construct list of ordering instructions
756 my @order = $self->_SWITCH_refkind($arg, {
759 map {$self->_SWITCH_refkind($_, {
760 SCALAR => sub {$self->_quote($_)},
762 SCALARREF => sub {$$_}, # literal SQL, no quoting
763 HASHREF => sub {$self->_order_by_hash($_)}
767 SCALAR => sub {$self->_quote($arg)},
769 SCALARREF => sub {$$arg}, # literal SQL, no quoting
770 HASHREF => sub {$self->_order_by_hash($arg)},
775 my $order = join ', ', @order;
776 return $order ? $self->_sqlcase(' order by')." $order" : '';
781 my ($self, $hash) = @_;
783 # get first pair in hash
784 my ($key, $val) = each %$hash;
786 # check if one pair was found and no other pair in hash
787 $key && !(each %$hash)
788 or puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
790 my ($order) = ($key =~ /^-(desc|asc)/i)
791 or puke "invalid key in _order_by hash : $key";
793 return $self->_quote($val) ." ". $self->_sqlcase($order);
798 #======================================================================
799 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
800 #======================================================================
805 $self->_SWITCH_refkind($from, {
806 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
807 SCALAR => sub {$self->_quote($from)},
808 SCALARREF => sub {$$from},
809 ARRAYREFREF => sub {join ', ', @$from;},
814 #======================================================================
816 #======================================================================
822 $label or puke "can't quote an empty label";
824 # left and right quote characters
825 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
826 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
827 ARRAYREF => sub {@{$self->{quote_char}}},
831 or puke "quote_char must be an arrayref of 2 values";
833 # no quoting if no quoting chars
834 $ql or return $label;
836 # no quoting for literal SQL
837 return $$label if ref($label) eq 'SCALAR';
839 # separate table / column (if applicable)
840 my $sep = $self->{name_sep} || '';
841 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
843 # do the quoting, except for "*" or for `table`.*
844 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
846 # reassemble and return.
847 return join $sep, @quoted;
851 # Conversion, if applicable
853 my ($self, $arg) = @_;
855 # LDNOTE : modified the previous implementation below because
856 # it was not consistent : the first "return" is always an array,
857 # the second "return" is context-dependent. Anyway, _convert
858 # seems always used with just a single argument, so make it a
860 # return @_ unless $self->{convert};
861 # my $conv = $self->_sqlcase($self->{convert});
862 # my @ret = map { $conv.'('.$_.')' } @_;
863 # return wantarray ? @ret : $ret[0];
864 if ($self->{convert}) {
865 my $conv = $self->_sqlcase($self->{convert});
866 $arg = $conv.'('.$arg.')';
874 my($col, @vals) = @_;
876 #LDNOTE : changed original implementation below because it did not make
877 # sense when bindtype eq 'columns' and @vals > 1.
878 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
880 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
883 # Dies if any element of @bind is not in [colname => value] format
884 # if bindtype is 'columns'.
885 sub _assert_bindval_matches_bindtype {
886 my ($self, @bind) = @_;
888 if ($self->{bindtype} eq 'columns') {
889 foreach my $val (@bind) {
890 if (!defined $val || ref($val) ne 'ARRAY' || @$val != 2) {
891 die "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
897 sub _join_sql_clauses {
898 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
900 if (@$clauses_aref > 1) {
901 my $join = " " . $self->_sqlcase($logic) . " ";
902 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
903 return ($sql, @$bind_aref);
905 elsif (@$clauses_aref) {
906 return ($clauses_aref->[0], @$bind_aref); # no parentheses
909 return (); # if no SQL, ignore @$bind_aref
914 # Fix SQL case, if so requested
918 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
919 # don't touch the argument ... crooked logic, but let's not change it!
920 return $self->{case} ? $_[0] : uc($_[0]);
924 #======================================================================
925 # DISPATCHING FROM REFKIND
926 #======================================================================
929 my ($self, $data) = @_;
935 # blessed objects are treated like scalars
936 $ref = (blessed $data) ? '' : ref $data;
937 $n_steps += 1 if $ref;
938 last if $ref ne 'REF';
942 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
944 return $base . ('REF' x $n_steps);
950 my ($self, $data) = @_;
951 my @try = ($self->_refkind($data));
952 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
953 push @try, 'FALLBACK';
957 sub _METHOD_FOR_refkind {
958 my ($self, $meth_prefix, $data) = @_;
959 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
960 $self->_try_refkind($data)
961 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
966 sub _SWITCH_refkind {
967 my ($self, $data, $dispatch_table) = @_;
969 my $coderef = first {$_} map {$dispatch_table->{$_}}
970 $self->_try_refkind($data)
971 or puke "no dispatch entry for ".$self->_refkind($data);
978 #======================================================================
979 # VALUES, GENERATE, AUTOLOAD
980 #======================================================================
982 # LDNOTE: original code from nwiger, didn't touch code in that section
983 # I feel the AUTOLOAD stuff should not be the default, it should
984 # only be activated on explicit demand by user.
988 my $data = shift || return;
989 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
990 unless ref $data eq 'HASH';
993 foreach my $k ( sort keys %$data ) {
995 $self->_SWITCH_refkind($v, {
997 if ($self->{array_datatypes}) { # array datatype
998 push @all_bind, $self->_bindtype($k, $v);
1000 else { # literal SQL with bind
1001 my ($sql, @bind) = @$v;
1002 $self->_assert_bindval_matches_bindtype(@bind);
1003 push @all_bind, @bind;
1006 ARRAYREFREF => sub { # literal SQL with bind
1007 my ($sql, @bind) = @${$v};
1008 $self->_assert_bindval_matches_bindtype(@bind);
1009 push @all_bind, @bind;
1011 SCALARREF => sub { # literal SQL without bind
1013 SCALAR_or_UNDEF => sub {
1014 push @all_bind, $self->_bindtype($k, $v);
1025 my(@sql, @sqlq, @sqlv);
1029 if ($ref eq 'HASH') {
1030 for my $k (sort keys %$_) {
1033 my $label = $self->_quote($k);
1034 if ($r eq 'ARRAY') {
1035 # literal SQL with bind
1036 my ($sql, @bind) = @$v;
1037 $self->_assert_bindval_matches_bindtype(@bind);
1038 push @sqlq, "$label = $sql";
1040 } elsif ($r eq 'SCALAR') {
1041 # literal SQL without bind
1042 push @sqlq, "$label = $$v";
1044 push @sqlq, "$label = ?";
1045 push @sqlv, $self->_bindtype($k, $v);
1048 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1049 } elsif ($ref eq 'ARRAY') {
1050 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1053 if ($r eq 'ARRAY') { # literal SQL with bind
1054 my ($sql, @bind) = @$v;
1055 $self->_assert_bindval_matches_bindtype(@bind);
1058 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1059 # embedded literal SQL
1066 push @sql, '(' . join(', ', @sqlq) . ')';
1067 } elsif ($ref eq 'SCALAR') {
1071 # strings get case twiddled
1072 push @sql, $self->_sqlcase($_);
1076 my $sql = join ' ', @sql;
1078 # this is pretty tricky
1079 # if ask for an array, return ($stmt, @bind)
1080 # otherwise, s/?/shift @sqlv/ to put it inline
1082 return ($sql, @sqlv);
1084 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1085 ref $d ? $d->[1] : $d/e;
1094 # This allows us to check for a local, then _form, attr
1096 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1097 return $self->generate($name, @_);
1108 SQL::Abstract - Generate SQL from Perl data structures
1114 my $sql = SQL::Abstract->new;
1116 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1118 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1120 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1122 my($stmt, @bind) = $sql->delete($table, \%where);
1124 # Then, use these in your DBI statements
1125 my $sth = $dbh->prepare($stmt);
1126 $sth->execute(@bind);
1128 # Just generate the WHERE clause
1129 my($stmt, @bind) = $sql->where(\%where, \@order);
1131 # Return values in the same order, for hashed queries
1132 # See PERFORMANCE section for more details
1133 my @bind = $sql->values(\%fieldvals);
1137 This module was inspired by the excellent L<DBIx::Abstract>.
1138 However, in using that module I found that what I really wanted
1139 to do was generate SQL, but still retain complete control over my
1140 statement handles and use the DBI interface. So, I set out to
1141 create an abstract SQL generation module.
1143 While based on the concepts used by L<DBIx::Abstract>, there are
1144 several important differences, especially when it comes to WHERE
1145 clauses. I have modified the concepts used to make the SQL easier
1146 to generate from Perl data structures and, IMO, more intuitive.
1147 The underlying idea is for this module to do what you mean, based
1148 on the data structures you provide it. The big advantage is that
1149 you don't have to modify your code every time your data changes,
1150 as this module figures it out.
1152 To begin with, an SQL INSERT is as easy as just specifying a hash
1153 of C<key=value> pairs:
1156 name => 'Jimbo Bobson',
1157 phone => '123-456-7890',
1158 address => '42 Sister Lane',
1159 city => 'St. Louis',
1160 state => 'Louisiana',
1163 The SQL can then be generated with this:
1165 my($stmt, @bind) = $sql->insert('people', \%data);
1167 Which would give you something like this:
1169 $stmt = "INSERT INTO people
1170 (address, city, name, phone, state)
1171 VALUES (?, ?, ?, ?, ?)";
1172 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1173 '123-456-7890', 'Louisiana');
1175 These are then used directly in your DBI code:
1177 my $sth = $dbh->prepare($stmt);
1178 $sth->execute(@bind);
1180 =head2 Inserting and Updating Arrays
1182 If your database has array types (like for example Postgres),
1183 activate the special option C<< array_datatypes => 1 >>
1184 when creating the C<SQL::Abstract> object.
1185 Then you may use an arrayref to insert and update database array types:
1187 my $sql = SQL::Abstract->new(array_datatypes => 1);
1189 planets => [qw/Mercury Venus Earth Mars/]
1192 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1196 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1198 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1201 =head2 Inserting and Updating SQL
1203 In order to apply SQL functions to elements of your C<%data> you may
1204 specify a reference to an arrayref for the given hash value. For example,
1205 if you need to execute the Oracle C<to_date> function on a value, you can
1206 say something like this:
1210 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
1213 The first value in the array is the actual SQL. Any other values are
1214 optional and would be included in the bind values array. This gives
1217 my($stmt, @bind) = $sql->insert('people', \%data);
1219 $stmt = "INSERT INTO people (name, date_entered)
1220 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1221 @bind = ('Bill', '03/02/2003');
1223 An UPDATE is just as easy, all you change is the name of the function:
1225 my($stmt, @bind) = $sql->update('people', \%data);
1227 Notice that your C<%data> isn't touched; the module will generate
1228 the appropriately quirky SQL for you automatically. Usually you'll
1229 want to specify a WHERE clause for your UPDATE, though, which is
1230 where handling C<%where> hashes comes in handy...
1232 =head2 Complex where statements
1234 This module can generate pretty complicated WHERE statements
1235 easily. For example, simple C<key=value> pairs are taken to mean
1236 equality, and if you want to see if a field is within a set
1237 of values, you can use an arrayref. Let's say we wanted to
1238 SELECT some data based on this criteria:
1241 requestor => 'inna',
1242 worker => ['nwiger', 'rcwe', 'sfz'],
1243 status => { '!=', 'completed' }
1246 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1248 The above would give you something like this:
1250 $stmt = "SELECT * FROM tickets WHERE
1251 ( requestor = ? ) AND ( status != ? )
1252 AND ( worker = ? OR worker = ? OR worker = ? )";
1253 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1255 Which you could then use in DBI code like so:
1257 my $sth = $dbh->prepare($stmt);
1258 $sth->execute(@bind);
1264 The functions are simple. There's one for each major SQL operation,
1265 and a constructor you use first. The arguments are specified in a
1266 similar order to each function (table, then fields, then a where
1267 clause) to try and simplify things.
1272 =head2 new(option => 'value')
1274 The C<new()> function takes a list of options and values, and returns
1275 a new B<SQL::Abstract> object which can then be used to generate SQL
1276 through the methods below. The options accepted are:
1282 If set to 'lower', then SQL will be generated in all lowercase. By
1283 default SQL is generated in "textbook" case meaning something like:
1285 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1287 Any setting other than 'lower' is ignored.
1291 This determines what the default comparison operator is. By default
1292 it is C<=>, meaning that a hash like this:
1294 %where = (name => 'nwiger', email => 'nate@wiger.org');
1296 Will generate SQL like this:
1298 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1300 However, you may want loose comparisons by default, so if you set
1301 C<cmp> to C<like> you would get SQL such as:
1303 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1305 You can also override the comparsion on an individual basis - see
1306 the huge section on L</"WHERE CLAUSES"> at the bottom.
1308 =item sqltrue, sqlfalse
1310 Expressions for inserting boolean values within SQL statements.
1311 By default these are C<1=1> and C<1=0>.
1315 This determines the default logical operator for multiple WHERE
1316 statements in arrays. By default it is "or", meaning that a WHERE
1320 event_date => {'>=', '2/13/99'},
1321 event_date => {'<=', '4/24/03'},
1324 Will generate SQL like this:
1326 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1328 This is probably not what you want given this query, though (look
1329 at the dates). To change the "OR" to an "AND", simply specify:
1331 my $sql = SQL::Abstract->new(logic => 'and');
1333 Which will change the above C<WHERE> to:
1335 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1337 The logic can also be changed locally by inserting
1338 an extra first element in the array :
1340 @where = (-and => event_date => {'>=', '2/13/99'},
1341 event_date => {'<=', '4/24/03'} );
1343 See the L</"WHERE CLAUSES"> section for explanations.
1347 This will automatically convert comparisons using the specified SQL
1348 function for both column and value. This is mostly used with an argument
1349 of C<upper> or C<lower>, so that the SQL will have the effect of
1350 case-insensitive "searches". For example, this:
1352 $sql = SQL::Abstract->new(convert => 'upper');
1353 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1355 Will turn out the following SQL:
1357 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1359 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1360 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1361 not validate this option; it will just pass through what you specify verbatim).
1365 This is a kludge because many databases suck. For example, you can't
1366 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1367 Instead, you have to use C<bind_param()>:
1369 $sth->bind_param(1, 'reg data');
1370 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1372 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1373 which loses track of which field each slot refers to. Fear not.
1375 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1376 Currently, you can specify either C<normal> (default) or C<columns>. If you
1377 specify C<columns>, you will get an array that looks like this:
1379 my $sql = SQL::Abstract->new(bindtype => 'columns');
1380 my($stmt, @bind) = $sql->insert(...);
1383 [ 'column1', 'value1' ],
1384 [ 'column2', 'value2' ],
1385 [ 'column3', 'value3' ],
1388 You can then iterate through this manually, using DBI's C<bind_param()>.
1390 $sth->prepare($stmt);
1393 my($col, $data) = @$_;
1394 if ($col eq 'details' || $col eq 'comments') {
1395 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1396 } elsif ($col eq 'image') {
1397 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1399 $sth->bind_param($i, $data);
1403 $sth->execute; # execute without @bind now
1405 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1406 Basically, the advantage is still that you don't have to care which fields
1407 are or are not included. You could wrap that above C<for> loop in a simple
1408 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1409 get a layer of abstraction over manual SQL specification.
1411 Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1412 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1413 will expect the bind values in this format.
1417 This is the character that a table or column name will be quoted
1418 with. By default this is an empty string, but you could set it to
1419 the character C<`>, to generate SQL like this:
1421 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1423 Alternatively, you can supply an array ref of two items, the first being the left
1424 hand quote character, and the second the right hand quote character. For
1425 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1426 that generates SQL like this:
1428 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1430 Quoting is useful if you have tables or columns names that are reserved
1431 words in your database's SQL dialect.
1435 This is the character that separates a table and column name. It is
1436 necessary to specify this when the C<quote_char> option is selected,
1437 so that tables and column names can be individually quoted like this:
1439 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1441 =item array_datatypes
1443 When this option is true, arrayrefs in INSERT or UPDATE are
1444 interpreted as array datatypes and are passed directly
1446 When this option is false, arrayrefs are interpreted
1447 as literal SQL, just like refs to arrayrefs
1448 (but this behavior is for backwards compatibility; when writing
1449 new queries, use the "reference to arrayref" syntax
1455 Takes a reference to a list of "special operators"
1456 to extend the syntax understood by L<SQL::Abstract>.
1457 See section L</"SPECIAL OPERATORS"> for details.
1463 =head2 insert($table, \@values || \%fieldvals)
1465 This is the simplest function. You simply give it a table name
1466 and either an arrayref of values or hashref of field/value pairs.
1467 It returns an SQL INSERT statement and a list of bind values.
1468 See the sections on L</"Inserting and Updating Arrays"> and
1469 L</"Inserting and Updating SQL"> for information on how to insert
1470 with those data types.
1472 =head2 update($table, \%fieldvals, \%where)
1474 This takes a table, hashref of field/value pairs, and an optional
1475 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1477 See the sections on L</"Inserting and Updating Arrays"> and
1478 L</"Inserting and Updating SQL"> for information on how to insert
1479 with those data types.
1481 =head2 select($source, $fields, $where, $order)
1483 This returns a SQL SELECT statement and associated list of bind values, as
1484 specified by the arguments :
1490 Specification of the 'FROM' part of the statement.
1491 The argument can be either a plain scalar (interpreted as a table
1492 name, will be quoted), or an arrayref (interpreted as a list
1493 of table names, joined by commas, quoted), or a scalarref
1494 (literal table name, not quoted), or a ref to an arrayref
1495 (list of literal table names, joined by commas, not quoted).
1499 Specification of the list of fields to retrieve from
1501 The argument can be either an arrayref (interpreted as a list
1502 of field names, will be joined by commas and quoted), or a
1503 plain scalar (literal SQL, not quoted).
1504 Please observe that this API is not as flexible as for
1505 the first argument C<$table>, for backwards compatibility reasons.
1509 Optional argument to specify the WHERE part of the query.
1510 The argument is most often a hashref, but can also be
1511 an arrayref or plain scalar --
1512 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1516 Optional argument to specify the ORDER BY part of the query.
1517 The argument can be a scalar, a hashref or an arrayref
1518 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1524 =head2 delete($table, \%where)
1526 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1527 It returns an SQL DELETE statement and list of bind values.
1529 =head2 where(\%where, \@order)
1531 This is used to generate just the WHERE clause. For example,
1532 if you have an arbitrary data structure and know what the
1533 rest of your SQL is going to look like, but want an easy way
1534 to produce a WHERE clause, use this. It returns an SQL WHERE
1535 clause and list of bind values.
1538 =head2 values(\%data)
1540 This just returns the values from the hash C<%data>, in the same
1541 order that would be returned from any of the other above queries.
1542 Using this allows you to markedly speed up your queries if you
1543 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1545 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1547 Warning: This is an experimental method and subject to change.
1549 This returns arbitrarily generated SQL. It's a really basic shortcut.
1550 It will return two different things, depending on return context:
1552 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1553 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1555 These would return the following:
1557 # First calling form
1558 $stmt = "CREATE TABLE test (?, ?)";
1559 @bind = (field1, field2);
1561 # Second calling form
1562 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1564 Depending on what you're trying to do, it's up to you to choose the correct
1565 format. In this example, the second form is what you would want.
1569 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1573 ALTER SESSION SET nls_date_format = 'MM/YY'
1575 You get the idea. Strings get their case twiddled, but everything
1576 else remains verbatim.
1581 =head1 WHERE CLAUSES
1585 This module uses a variation on the idea from L<DBIx::Abstract>. It
1586 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1587 module is that things in arrays are OR'ed, and things in hashes
1590 The easiest way to explain is to show lots of examples. After
1591 each C<%where> hash shown, it is assumed you used:
1593 my($stmt, @bind) = $sql->where(\%where);
1595 However, note that the C<%where> hash can be used directly in any
1596 of the other functions as well, as described above.
1598 =head2 Key-value pairs
1600 So, let's get started. To begin, a simple hash:
1604 status => 'completed'
1607 Is converted to SQL C<key = val> statements:
1609 $stmt = "WHERE user = ? AND status = ?";
1610 @bind = ('nwiger', 'completed');
1612 One common thing I end up doing is having a list of values that
1613 a field can be in. To do this, simply specify a list inside of
1618 status => ['assigned', 'in-progress', 'pending'];
1621 This simple code will create the following:
1623 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1624 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1626 An empty arrayref will be considered a logical false and
1629 =head2 Key-value pairs
1631 If you want to specify a different type of operator for your comparison,
1632 you can use a hashref for a given column:
1636 status => { '!=', 'completed' }
1639 Which would generate:
1641 $stmt = "WHERE user = ? AND status != ?";
1642 @bind = ('nwiger', 'completed');
1644 To test against multiple values, just enclose the values in an arrayref:
1646 status => { '=', ['assigned', 'in-progress', 'pending'] };
1648 Which would give you:
1650 "WHERE status = ? OR status = ? OR status = ?"
1653 The hashref can also contain multiple pairs, in which case it is expanded
1654 into an C<AND> of its elements:
1658 status => { '!=', 'completed', -not_like => 'pending%' }
1661 # Or more dynamically, like from a form
1662 $where{user} = 'nwiger';
1663 $where{status}{'!='} = 'completed';
1664 $where{status}{'-not_like'} = 'pending%';
1666 # Both generate this
1667 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1668 @bind = ('nwiger', 'completed', 'pending%');
1671 To get an OR instead, you can combine it with the arrayref idea:
1675 priority => [ {'=', 2}, {'!=', 1} ]
1678 Which would generate:
1680 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1681 @bind = ('nwiger', '2', '1');
1683 If you want to include literal SQL (with or without bind values), just use a
1684 scalar reference or array reference as the value:
1687 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1688 date_expires => { '<' => \"now()" }
1691 Which would generate:
1693 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1694 @bind = ('11/26/2008');
1697 =head2 Logic and nesting operators
1699 In the example above,
1700 there is a subtle trap if you want to say something like
1701 this (notice the C<AND>):
1703 WHERE priority != ? AND priority != ?
1705 Because, in Perl you I<can't> do this:
1707 priority => { '!=', 2, '!=', 1 }
1709 As the second C<!=> key will obliterate the first. The solution
1710 is to use the special C<-modifier> form inside an arrayref:
1712 priority => [ -and => {'!=', 2},
1716 Normally, these would be joined by C<OR>, but the modifier tells it
1717 to use C<AND> instead. (Hint: You can use this in conjunction with the
1718 C<logic> option to C<new()> in order to change the way your queries
1719 work by default.) B<Important:> Note that the C<-modifier> goes
1720 B<INSIDE> the arrayref, as an extra first element. This will
1721 B<NOT> do what you think it might:
1723 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1725 Here is a quick list of equivalencies, since there is some overlap:
1728 status => {'!=', 'completed', 'not like', 'pending%' }
1729 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1732 status => {'=', ['assigned', 'in-progress']}
1733 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1734 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1736 In addition to C<-and> and C<-or>, there is also a special C<-nest>
1737 operator which adds an additional set of parens, to create a subquery.
1738 For example, to get something like this:
1740 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
1741 @bind = ('nwiger', '20', 'ASIA');
1747 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1750 If you need several nested subexpressions, you can number
1751 the C<-nest> branches :
1761 =head2 Special operators : IN, BETWEEN, etc.
1763 You can also use the hashref format to compare a list of fields using the
1764 C<IN> comparison operator, by specifying the list as an arrayref:
1767 status => 'completed',
1768 reportid => { -in => [567, 2335, 2] }
1771 Which would generate:
1773 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1774 @bind = ('completed', '567', '2335', '2');
1776 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1779 Another pair of operators is C<-between> and C<-not_between>,
1780 used with an arrayref of two values:
1784 completion_date => {
1785 -not_between => ['2002-10-01', '2003-02-06']
1791 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1793 These are the two builtin "special operators"; but the
1794 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1796 =head2 Nested conditions
1798 So far, we've seen how multiple conditions are joined with a top-level
1799 C<AND>. We can change this by putting the different conditions we want in
1800 hashes and then putting those hashes in an array. For example:
1805 status => { -like => ['pending%', 'dispatched'] },
1809 status => 'unassigned',
1813 This data structure would create the following:
1815 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1816 OR ( user = ? AND status = ? ) )";
1817 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1819 This can be combined with the C<-nest> operator to properly group
1826 ["-and", workhrs => {'>', 20}, geo => 'ASIA' ],
1827 ["-and", workhrs => {'<', 50}, geo => 'EURO' ]
1834 WHERE ( user = ? AND
1835 ( ( workhrs > ? AND geo = ? )
1836 OR ( workhrs < ? AND geo = ? ) ) )
1840 Finally, sometimes only literal SQL will do. If you want to include
1841 literal SQL verbatim, you can specify it as a scalar reference, namely:
1843 my $inn = 'is Not Null';
1845 priority => { '<', 2 },
1851 $stmt = "WHERE priority < ? AND requestor is Not Null";
1854 Note that in this example, you only get one bind parameter back, since
1855 the verbatim SQL is passed as part of the statement.
1857 Of course, just to prove a point, the above can also be accomplished
1861 priority => { '<', 2 },
1862 requestor => { '!=', undef },
1868 Conditions on boolean columns can be expressed in the
1869 same way, passing a reference to an empty string :
1872 priority => { '<', 2 },
1878 $stmt = "WHERE priority < ? AND is_ready";
1882 =head2 Literal SQL with placeholders and bind values (subqueries)
1884 If the literal SQL to be inserted has placeholders and bind values,
1885 use a reference to an arrayref (yes this is a double reference --
1886 not so common, but perfectly legal Perl). For example, to find a date
1887 in Postgres you can use something like this:
1890 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1895 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
1898 Note that you must pass the bind values in the same format as they are returned
1899 by L</where>. That means that if you set L</bindtype> to C<columns>, you must
1900 provide the bind values in the C<< [ column_meta => value ] >> format, where
1901 C<column_meta> is an opaque scalar value; most commonly the column name, but
1902 you can use any scalar value (including references and blessed references),
1903 L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
1904 to C<columns> the above example will look like:
1907 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
1910 Literal SQL is especially useful for nesting parenthesized clauses in the
1911 main SQL query. Here is a first example :
1913 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1917 bar => \["IN ($sub_stmt)" => @sub_bind],
1922 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
1923 WHERE c2 < ? AND c3 LIKE ?))";
1924 @bind = (1234, 100, "foo%");
1926 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
1927 are expressed in the same way. Of course the C<$sub_stmt> and
1928 its associated bind values can be generated through a former call
1931 my ($sub_stmt, @sub_bind)
1932 = $sql->select("t1", "c1", {c2 => {"<" => 100},
1933 c3 => {-like => "foo%"}});
1936 bar => \["> ALL ($sub_stmt)" => @sub_bind],
1939 In the examples above, the subquery was used as an operator on a column;
1940 but the same principle also applies for a clause within the main C<%where>
1941 hash, like an EXISTS subquery :
1943 my ($sub_stmt, @sub_bind)
1944 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
1947 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
1952 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
1953 WHERE c1 = ? AND c2 > t0.c0))";
1957 Observe that the condition on C<c2> in the subquery refers to
1958 column C<t0.c0> of the main query : this is I<not> a bind
1959 value, so we have to express it through a scalar ref.
1960 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
1961 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
1962 what we wanted here.
1964 Another use of the subquery technique is when some SQL clauses need
1965 parentheses, as it often occurs with some proprietary SQL extensions
1966 like for example fulltext expressions, geospatial expressions,
1967 NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
1970 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
1973 Finally, here is an example where a subquery is used
1974 for expressing unary negation:
1976 my ($sub_stmt, @sub_bind)
1977 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
1978 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
1980 lname => {like => '%son%'},
1981 -nest => \["NOT ($sub_stmt)" => @sub_bind],
1986 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
1987 @bind = ('%son%', 10, 20)
1993 These pages could go on for a while, since the nesting of the data
1994 structures this module can handle are pretty much unlimited (the
1995 module implements the C<WHERE> expansion as a recursive function
1996 internally). Your best bet is to "play around" with the module a
1997 little to see how the data structures behave, and choose the best
1998 format for your data based on that.
2000 And of course, all the values above will probably be replaced with
2001 variables gotten from forms or the command line. After all, if you
2002 knew everything ahead of time, you wouldn't have to worry about
2003 dynamically-generating SQL and could just hardwire it into your
2009 =head1 ORDER BY CLAUSES
2011 Some functions take an order by clause. This can either be a scalar (just a
2012 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
2013 or an array of either of the two previous forms. Examples:
2015 Given | Will Generate
2016 ----------------------------------------------------------
2017 \'colA DESC' | ORDER BY colA DESC
2018 'colA' | ORDER BY colA
2019 [qw/colA colB/] | ORDER BY colA, colB
2020 {-asc => 'colA'} | ORDER BY colA ASC
2021 {-desc => 'colB'} | ORDER BY colB DESC
2023 {-asc => 'colA'}, | ORDER BY colA ASC, colB DESC
2026 [colA => {-asc => 'colB'}] | ORDER BY colA, colB ASC
2027 ==========================================================
2031 =head1 SPECIAL OPERATORS
2033 my $sqlmaker = SQL::Abstract->new(special_ops => [
2036 my ($self, $field, $op, $arg) = @_;
2042 A "special operator" is a SQL syntactic clause that can be
2043 applied to a field, instead of a usual binary operator.
2046 WHERE field IN (?, ?, ?)
2047 WHERE field BETWEEN ? AND ?
2048 WHERE MATCH(field) AGAINST (?, ?)
2050 Special operators IN and BETWEEN are fairly standard and therefore
2051 are builtin within C<SQL::Abstract>. For other operators,
2052 like the MATCH .. AGAINST example above which is
2053 specific to MySQL, you can write your own operator handlers :
2054 supply a C<special_ops> argument to the C<new> method.
2055 That argument takes an arrayref of operator definitions;
2056 each operator definition is a hashref with two entries
2062 the regular expression to match the operator
2066 coderef that will be called when meeting that operator
2067 in the input tree. The coderef will be called with
2068 arguments C<< ($self, $field, $op, $arg) >>, and
2069 should return a C<< ($sql, @bind) >> structure.
2073 For example, here is an implementation
2074 of the MATCH .. AGAINST syntax for MySQL
2076 my $sqlmaker = SQL::Abstract->new(special_ops => [
2078 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2079 {regex => qr/^match$/i,
2081 my ($self, $field, $op, $arg) = @_;
2082 $arg = [$arg] if not ref $arg;
2083 my $label = $self->_quote($field);
2084 my ($placeholder) = $self->_convert('?');
2085 my $placeholders = join ", ", (($placeholder) x @$arg);
2086 my $sql = $self->_sqlcase('match') . " ($label) "
2087 . $self->_sqlcase('against') . " ($placeholders) ";
2088 my @bind = $self->_bindtype($field, @$arg);
2089 return ($sql, @bind);
2098 Thanks to some benchmarking by Mark Stosberg, it turns out that
2099 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2100 I must admit this wasn't an intentional design issue, but it's a
2101 byproduct of the fact that you get to control your C<DBI> handles
2104 To maximize performance, use a code snippet like the following:
2106 # prepare a statement handle using the first row
2107 # and then reuse it for the rest of the rows
2109 for my $href (@array_of_hashrefs) {
2110 $stmt ||= $sql->insert('table', $href);
2111 $sth ||= $dbh->prepare($stmt);
2112 $sth->execute($sql->values($href));
2115 The reason this works is because the keys in your C<$href> are sorted
2116 internally by B<SQL::Abstract>. Thus, as long as your data retains
2117 the same structure, you only have to generate the SQL the first time
2118 around. On subsequent queries, simply use the C<values> function provided
2119 by this module to return your values in the correct order.
2124 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2125 really like this part (I do, at least). Building up a complex query
2126 can be as simple as the following:
2130 use CGI::FormBuilder;
2133 my $form = CGI::FormBuilder->new(...);
2134 my $sql = SQL::Abstract->new;
2136 if ($form->submitted) {
2137 my $field = $form->field;
2138 my $id = delete $field->{id};
2139 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2142 Of course, you would still have to connect using C<DBI> to run the
2143 query, but the point is that if you make your form look like your
2144 table, the actual query script can be extremely simplistic.
2146 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2147 a fast interface to returning and formatting data. I frequently
2148 use these three modules together to write complex database query
2149 apps in under 50 lines.
2154 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2155 Great care has been taken to preserve the I<published> behavior
2156 documented in previous versions in the 1.* family; however,
2157 some features that were previously undocumented, or behaved
2158 differently from the documentation, had to be changed in order
2159 to clarify the semantics. Hence, client code that was relying
2160 on some dark areas of C<SQL::Abstract> v1.*
2161 B<might behave differently> in v1.50.
2163 The main changes are :
2169 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2173 support for the { operator => \"..." } construct (to embed literal SQL)
2177 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2181 added -nest1, -nest2 or -nest_1, -nest_2, ...
2185 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2189 defensive programming : check arguments
2193 fixed bug with global logic, which was previously implemented
2194 through global variables yielding side-effects. Prior versons would
2195 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2196 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2197 Now this is interpreted
2198 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2202 C<-and> / C<-or> operators are no longer accepted
2203 in the middle of an arrayref : they are
2204 only admitted if in first position.
2208 changed logic for distributing an op over arrayrefs
2212 fixed semantics of _bindtype on array args
2216 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2217 we just avoid shifting arrays within that tree.
2221 dropped the C<_modlogic> function
2227 =head1 ACKNOWLEDGEMENTS
2229 There are a number of individuals that have really helped out with
2230 this module. Unfortunately, most of them submitted bugs via CPAN
2231 so I have no idea who they are! But the people I do know are:
2233 Ash Berlin (order_by hash term support)
2234 Matt Trout (DBIx::Class support)
2235 Mark Stosberg (benchmarking)
2236 Chas Owens (initial "IN" operator support)
2237 Philip Collins (per-field SQL functions)
2238 Eric Kolve (hashref "AND" support)
2239 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2240 Dan Kubb (support for "quote_char" and "name_sep")
2241 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2242 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
2243 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2249 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2253 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2255 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
2257 For support, your best bet is to try the C<DBIx::Class> users mailing list.
2258 While not an official support venue, C<DBIx::Class> makes heavy use of
2259 C<SQL::Abstract>, and as such list members there are very familiar with
2260 how to create queries.
2262 This module is free software; you may copy this under the terms of
2263 the GNU General Public License, or the Artistic License, copies of
2264 which should have accompanied your Perl kit.