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)
14 #======================================================================
16 #======================================================================
18 our $VERSION = '1.68';
20 # This would confuse some packagers
21 $VERSION = eval $VERSION if $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 \s )? between $/ix, handler => '_where_field_BETWEEN'},
29 {regex => qr/^ (?: not \s )? in $/ix, handler => '_where_field_IN'},
32 # unaryish operators - key maps to handler
33 my @BUILTIN_UNARY_OPS = (
34 # the digits are backcompat stuff
35 { regex => qr/^ and (?: [_\s]? \d+ )? $/xi, handler => '_where_op_ANDOR' },
36 { regex => qr/^ or (?: [_\s]? \d+ )? $/xi, handler => '_where_op_ANDOR' },
37 { regex => qr/^ nest (?: [_\s]? \d+ )? $/xi, handler => '_where_op_NEST' },
38 { regex => qr/^ (?: not \s )? bool $/xi, handler => '_where_op_BOOL' },
41 #======================================================================
42 # DEBUGGING AND ERROR REPORTING
43 #======================================================================
46 return unless $_[0]->{debug}; shift; # a little faster
47 my $func = (caller(1))[3];
48 warn "[$func] ", @_, "\n";
52 my($func) = (caller(1))[3];
53 carp "[$func] Warning: ", @_;
57 my($func) = (caller(1))[3];
58 croak "[$func] Fatal: ", @_;
62 #======================================================================
64 #======================================================================
68 my $class = ref($self) || $self;
69 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
71 # choose our case by keeping an option around
72 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
74 # default logic for interpreting arrayrefs
75 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
77 # how to return bind vars
78 # LDNOTE: changed nwiger code : why this 'delete' ??
79 # $opt{bindtype} ||= delete($opt{bind_type}) || 'normal';
80 $opt{bindtype} ||= 'normal';
82 # default comparison is "=", but can be overridden
85 # try to recognize which are the 'equality' and 'unequality' ops
86 # (temporary quickfix, should go through a more seasoned API)
87 $opt{equality_op} = qr/^(\Q$opt{cmp}\E|is|(is\s+)?like)$/i;
88 $opt{inequality_op} = qr/^(!=|<>|(is\s+)?not(\s+like)?)$/i;
91 $opt{sqltrue} ||= '1=1';
92 $opt{sqlfalse} ||= '0=1';
95 $opt{special_ops} ||= [];
96 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
99 $opt{unary_ops} ||= [];
100 push @{$opt{unary_ops}}, @BUILTIN_UNARY_OPS;
102 return bless \%opt, $class;
107 #======================================================================
109 #======================================================================
113 my $table = $self->_table(shift);
114 my $data = shift || return;
117 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
118 my ($sql, @bind) = $self->$method($data);
119 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
121 if (my $ret = $options->{returning}) {
122 $sql .= $self->_insert_returning ($ret);
125 return wantarray ? ($sql, @bind) : $sql;
128 sub _insert_returning {
129 my ($self, $fields) = @_;
131 my $f = $self->_SWITCH_refkind($fields, {
132 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$fields;},
133 SCALAR => sub {$self->_quote($fields)},
134 SCALARREF => sub {$$fields},
136 return join (' ', $self->_sqlcase(' returning'), $f);
139 sub _insert_HASHREF { # explicit list of fields and then values
140 my ($self, $data) = @_;
142 my @fields = sort keys %$data;
144 my ($sql, @bind) = $self->_insert_values($data);
147 $_ = $self->_quote($_) foreach @fields;
148 $sql = "( ".join(", ", @fields).") ".$sql;
150 return ($sql, @bind);
153 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
154 my ($self, $data) = @_;
156 # no names (arrayref) so can't generate bindtype
157 $self->{bindtype} ne 'columns'
158 or belch "can't do 'columns' bindtype when called with arrayref";
160 # fold the list of values into a hash of column name - value pairs
161 # (where the column names are artificially generated, and their
162 # lexicographical ordering keep the ordering of the original list)
163 my $i = "a"; # incremented values will be in lexicographical order
164 my $data_in_hash = { map { ($i++ => $_) } @$data };
166 return $self->_insert_values($data_in_hash);
169 sub _insert_ARRAYREFREF { # literal SQL with bind
170 my ($self, $data) = @_;
172 my ($sql, @bind) = @${$data};
173 $self->_assert_bindval_matches_bindtype(@bind);
175 return ($sql, @bind);
179 sub _insert_SCALARREF { # literal SQL without bind
180 my ($self, $data) = @_;
186 my ($self, $data) = @_;
188 my (@values, @all_bind);
189 foreach my $column (sort keys %$data) {
190 my $v = $data->{$column};
192 $self->_SWITCH_refkind($v, {
195 if ($self->{array_datatypes}) { # if array datatype are activated
197 push @all_bind, $self->_bindtype($column, $v);
199 else { # else literal SQL with bind
200 my ($sql, @bind) = @$v;
201 $self->_assert_bindval_matches_bindtype(@bind);
203 push @all_bind, @bind;
207 ARRAYREFREF => sub { # literal SQL with bind
208 my ($sql, @bind) = @${$v};
209 $self->_assert_bindval_matches_bindtype(@bind);
211 push @all_bind, @bind;
214 # THINK : anything useful to do with a HASHREF ?
215 HASHREF => sub { # (nothing, but old SQLA passed it through)
216 #TODO in SQLA >= 2.0 it will die instead
217 belch "HASH ref as bind value in insert is not supported";
219 push @all_bind, $self->_bindtype($column, $v);
222 SCALARREF => sub { # literal SQL without bind
226 SCALAR_or_UNDEF => sub {
228 push @all_bind, $self->_bindtype($column, $v);
235 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
236 return ($sql, @all_bind);
241 #======================================================================
243 #======================================================================
248 my $table = $self->_table(shift);
249 my $data = shift || return;
252 # first build the 'SET' part of the sql statement
253 my (@set, @all_bind);
254 puke "Unsupported data type specified to \$sql->update"
255 unless ref $data eq 'HASH';
257 for my $k (sort keys %$data) {
260 my $label = $self->_quote($k);
262 $self->_SWITCH_refkind($v, {
264 if ($self->{array_datatypes}) { # array datatype
265 push @set, "$label = ?";
266 push @all_bind, $self->_bindtype($k, $v);
268 else { # literal SQL with bind
269 my ($sql, @bind) = @$v;
270 $self->_assert_bindval_matches_bindtype(@bind);
271 push @set, "$label = $sql";
272 push @all_bind, @bind;
275 ARRAYREFREF => sub { # literal SQL with bind
276 my ($sql, @bind) = @${$v};
277 $self->_assert_bindval_matches_bindtype(@bind);
278 push @set, "$label = $sql";
279 push @all_bind, @bind;
281 SCALARREF => sub { # literal SQL without bind
282 push @set, "$label = $$v";
284 SCALAR_or_UNDEF => sub {
285 push @set, "$label = ?";
286 push @all_bind, $self->_bindtype($k, $v);
292 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ')
296 my($where_sql, @where_bind) = $self->where($where);
298 push @all_bind, @where_bind;
301 return wantarray ? ($sql, @all_bind) : $sql;
307 #======================================================================
309 #======================================================================
314 my $table = $self->_table(shift);
315 my $fields = shift || '*';
319 my($where_sql, @bind) = $self->where($where, $order);
321 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields
323 my $sql = join(' ', $self->_sqlcase('select'), $f,
324 $self->_sqlcase('from'), $table)
327 return wantarray ? ($sql, @bind) : $sql;
330 #======================================================================
332 #======================================================================
337 my $table = $self->_table(shift);
341 my($where_sql, @bind) = $self->where($where);
342 my $sql = $self->_sqlcase('delete from') . " $table" . $where_sql;
344 return wantarray ? ($sql, @bind) : $sql;
348 #======================================================================
350 #======================================================================
354 # Finally, a separate routine just to handle WHERE clauses
356 my ($self, $where, $order) = @_;
359 my ($sql, @bind) = $self->_recurse_where($where);
360 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
364 $sql .= $self->_order_by($order);
367 return wantarray ? ($sql, @bind) : $sql;
372 my ($self, $where, $logic) = @_;
374 # dispatch on appropriate method according to refkind of $where
375 my $method = $self->_METHOD_FOR_refkind("_where", $where);
377 my ($sql, @bind) = $self->$method($where, $logic);
379 # DBIx::Class directly calls _recurse_where in scalar context, so
380 # we must implement it, even if not in the official API
381 return wantarray ? ($sql, @bind) : $sql;
386 #======================================================================
387 # WHERE: top-level ARRAYREF
388 #======================================================================
391 sub _where_ARRAYREF {
392 my ($self, $where, $logic) = @_;
394 $logic = uc($logic || $self->{logic});
395 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
397 my @clauses = @$where;
399 my (@sql_clauses, @all_bind);
400 # need to use while() so can shift() for pairs
401 while (my $el = shift @clauses) {
403 # switch according to kind of $el and get corresponding ($sql, @bind)
404 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
406 # skip empty elements, otherwise get invalid trailing AND stuff
407 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
411 $self->_assert_bindval_matches_bindtype(@b);
415 HASHREF => sub {$self->_recurse_where($el, 'and') if %$el},
416 # LDNOTE : previous SQLA code for hashrefs was creating a dirty
417 # side-effect: the first hashref within an array would change
418 # the global logic to 'AND'. So [ {cond1, cond2}, [cond3, cond4] ]
419 # was interpreted as "(cond1 AND cond2) OR (cond3 AND cond4)",
420 # whereas it should be "(cond1 AND cond2) OR (cond3 OR cond4)".
422 SCALARREF => sub { ($$el); },
424 SCALAR => sub {# top-level arrayref with scalars, recurse in pairs
425 $self->_recurse_where({$el => shift(@clauses)})},
427 UNDEF => sub {puke "not supported : UNDEF in arrayref" },
431 push @sql_clauses, $sql;
432 push @all_bind, @bind;
436 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
439 #======================================================================
440 # WHERE: top-level ARRAYREFREF
441 #======================================================================
443 sub _where_ARRAYREFREF {
444 my ($self, $where) = @_;
445 my ($sql, @bind) = @$$where;
446 $self->_assert_bindval_matches_bindtype(@bind);
447 return ($sql, @bind);
450 #======================================================================
451 # WHERE: top-level HASHREF
452 #======================================================================
455 my ($self, $where) = @_;
456 my (@sql_clauses, @all_bind);
458 for my $k (sort keys %$where) {
459 my $v = $where->{$k};
461 # ($k => $v) is either a special unary op or a regular hashpair
462 my ($sql, @bind) = do {
464 # put the operator in canonical form
466 $op = substr $op, 1; # remove initial dash
467 $op =~ s/^\s+|\s+$//g;# remove leading/trailing space
468 $op =~ s/\s+/ /g; # compress whitespace
470 # so that -not_foo works correctly
471 $op =~ s/^not_/NOT /i;
473 $self->_debug("Unary OP(-$op) within hashref, recursing...");
475 my $op_entry = List::Util::first {$op =~ $_->{regex}} @{$self->{unary_ops}};
476 if (my $handler = $op_entry->{handler}) {
477 if (not ref $handler) {
478 if ($op =~ s/ [_\s]? \d+ $//x ) {
479 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
480 . "You probably wanted ...-and => [ -$op => COND1, -$op => COND2 ... ]";
482 $self->$handler ($op, $v);
484 elsif (ref $handler eq 'CODE') {
485 $handler->($self, $op, $v);
488 puke "Illegal handler for operator $k - expecting a method name or a coderef";
492 $self->debug("Generic unary OP: $k - recursing as function");
493 my ($s, @b) = $self->_where_func_generic ($op, $v);
494 $s = "($s)" unless (defined($self->{_nested_func_lhs}) && ($self->{_nested_func_lhs} eq $k)); # top level vs nested
499 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
500 $self->$method($k, $v);
504 push @sql_clauses, $sql;
505 push @all_bind, @bind;
508 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
511 sub _where_func_generic {
512 my ($self, $op, $rhs) = @_;
514 my ($sql, @bind) = $self->_SWITCH_refkind ($rhs, {
516 puke "Illegal use of top-level '$op'"
517 unless $self->{_nested_func_lhs};
520 $self->_convert('?'),
521 $self->_bindtype($self->{_nested_func_lhs}, $rhs)
525 $self->_recurse_where ($rhs)
529 $sql = sprintf ('%s %s',
530 $self->_sqlcase($op),
534 return ($sql, @bind);
537 sub _where_op_ANDOR {
538 my ($self, $op, $v) = @_;
540 $self->_SWITCH_refkind($v, {
542 return $self->_where_ARRAYREF($v, $op);
546 return ( $op =~ /^or/i )
547 ? $self->_where_ARRAYREF( [ map { $_ => $v->{$_} } ( sort keys %$v ) ], $op )
548 : $self->_where_HASHREF($v);
552 puke "-$op => \\\$scalar not supported, use -nest => ...";
556 puke "-$op => \\[..] not supported, use -nest => ...";
559 SCALAR => sub { # permissively interpreted as SQL
560 puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
564 puke "-$op => undef not supported";
570 my ($self, $op, $v) = @_;
572 $self->_SWITCH_refkind($v, {
574 SCALAR => sub { # permissively interpreted as SQL
575 belch "literal SQL should be -nest => \\'scalar' "
576 . "instead of -nest => 'scalar' ";
581 puke "-$op => undef not supported";
585 $self->_recurse_where ($v);
593 my ($self, $op, $v) = @_;
595 my ($s, @b) = $self->_SWITCH_refkind($v, {
596 SCALAR => sub { # interpreted as SQL column
597 $self->_convert($self->_quote($v));
601 puke "-$op => undef not supported";
605 $self->_recurse_where ($v);
609 $s = "(NOT $s)" if $op =~ /^not/i;
614 sub _where_hashpair_ARRAYREF {
615 my ($self, $k, $v) = @_;
618 my @v = @$v; # need copy because of shift below
619 $self->_debug("ARRAY($k) means distribute over elements");
621 # put apart first element if it is an operator (-and, -or)
623 (defined $v[0] && $v[0] =~ /^ - (?: AND|OR ) $/ix)
627 my @distributed = map { {$k => $_} } @v;
630 $self->_debug("OP($op) reinjected into the distributed array");
631 unshift @distributed, $op;
634 my $logic = $op ? substr($op, 1) : '';
636 return $self->_recurse_where(\@distributed, $logic);
639 # LDNOTE : not sure of this one. What does "distribute over nothing" mean?
640 $self->_debug("empty ARRAY($k) means 0=1");
641 return ($self->{sqlfalse});
645 sub _where_hashpair_HASHREF {
646 my ($self, $k, $v, $logic) = @_;
649 local $self->{_nested_func_lhs} = $self->{_nested_func_lhs};
651 my ($all_sql, @all_bind);
653 for my $orig_op (sort keys %$v) {
654 my $val = $v->{$orig_op};
656 # put the operator in canonical form
659 # FIXME - we need to phase out dash-less ops
660 $op =~ s/^-//; # remove possible initial dash
661 $op =~ s/^\s+|\s+$//g;# remove leading/trailing space
662 $op =~ s/\s+/ /g; # compress whitespace
664 # so that -not_foo works correctly
665 $op =~ s/^not_/NOT /i;
669 # CASE: col-value logic modifiers
670 if ( $orig_op =~ /^ \- (and|or) $/xi ) {
671 ($sql, @bind) = $self->_where_hashpair_HASHREF($k, $val, $1);
673 # CASE: special operators like -in or -between
674 elsif ( my $special_op = List::Util::first {$op =~ $_->{regex}} @{$self->{special_ops}} ) {
675 my $handler = $special_op->{handler};
677 puke "No handler supplied for special operator $orig_op";
679 elsif (not ref $handler) {
680 ($sql, @bind) = $self->$handler ($k, $op, $val);
682 elsif (ref $handler eq 'CODE') {
683 ($sql, @bind) = $handler->($self, $k, $op, $val);
686 puke "Illegal handler for special operator $orig_op - expecting a method name or a coderef";
690 $self->_SWITCH_refkind($val, {
692 ARRAYREF => sub { # CASE: col => {op => \@vals}
693 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
696 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]} (literal SQL with bind)
697 my ($sub_sql, @sub_bind) = @$$val;
698 $self->_assert_bindval_matches_bindtype(@sub_bind);
699 $sql = join ' ', $self->_convert($self->_quote($k)),
700 $self->_sqlcase($op),
705 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
706 my $is = ($op =~ $self->{equality_op}) ? 'is' :
707 ($op =~ $self->{inequality_op}) ? 'is not' :
708 puke "unexpected operator '$orig_op' with undef operand";
709 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
712 FALLBACK => sub { # CASE: col => {op/func => $stuff}
714 # retain for proper column type bind
715 $self->{_nested_func_lhs} ||= $k;
717 ($sql, @bind) = $self->_where_func_generic ($op, $val);
720 $self->_convert($self->_quote($k)),
721 $self->{_nested_func_lhs} eq $k ? $sql : "($sql)", # top level vs nested
727 ($all_sql) = (defined $all_sql and $all_sql) ? $self->_join_sql_clauses($logic, [$all_sql, $sql], []) : $sql;
728 push @all_bind, @bind;
730 return ($all_sql, @all_bind);
735 sub _where_field_op_ARRAYREF {
736 my ($self, $k, $op, $vals) = @_;
738 my @vals = @$vals; #always work on a copy
741 $self->_debug(sprintf '%s means multiple elements: [ %s ]',
743 join (', ', map { defined $_ ? "'$_'" : 'NULL' } @vals ),
746 # see if the first element is an -and/-or op
748 if (defined $vals[0] && $vals[0] =~ /^ - ( AND|OR ) $/ix) {
753 # distribute $op over each remaining member of @vals, append logic if exists
754 return $self->_recurse_where([map { {$k => {$op, $_}} } @vals], $logic);
756 # LDNOTE : had planned to change the distribution logic when
757 # $op =~ $self->{inequality_op}, because of Morgan laws :
758 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
759 # WHERE field != 22 OR field != 33 : the user probably means
760 # WHERE field != 22 AND field != 33.
761 # To do this, replace the above to roughly :
762 # my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
763 # return $self->_recurse_where([map { {$k => {$op, $_}} } @vals], $logic);
767 # try to DWIM on equality operators
768 # LDNOTE : not 100% sure this is the correct thing to do ...
769 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
770 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
773 puke "operator '$op' applied on an empty array (field '$k')";
778 sub _where_hashpair_SCALARREF {
779 my ($self, $k, $v) = @_;
780 $self->_debug("SCALAR($k) means literal SQL: $$v");
781 my $sql = $self->_quote($k) . " " . $$v;
785 # literal SQL with bind
786 sub _where_hashpair_ARRAYREFREF {
787 my ($self, $k, $v) = @_;
788 $self->_debug("REF($k) means literal SQL: @${$v}");
789 my ($sql, @bind) = @$$v;
790 $self->_assert_bindval_matches_bindtype(@bind);
791 $sql = $self->_quote($k) . " " . $sql;
792 return ($sql, @bind );
795 # literal SQL without bind
796 sub _where_hashpair_SCALAR {
797 my ($self, $k, $v) = @_;
798 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
799 my $sql = join ' ', $self->_convert($self->_quote($k)),
800 $self->_sqlcase($self->{cmp}),
801 $self->_convert('?');
802 my @bind = $self->_bindtype($k, $v);
803 return ( $sql, @bind);
807 sub _where_hashpair_UNDEF {
808 my ($self, $k, $v) = @_;
809 $self->_debug("UNDEF($k) means IS NULL");
810 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
814 #======================================================================
815 # WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
816 #======================================================================
819 sub _where_SCALARREF {
820 my ($self, $where) = @_;
823 $self->_debug("SCALAR(*top) means literal SQL: $$where");
829 my ($self, $where) = @_;
832 $self->_debug("NOREF(*top) means literal SQL: $where");
843 #======================================================================
844 # WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
845 #======================================================================
848 sub _where_field_BETWEEN {
849 my ($self, $k, $op, $vals) = @_;
851 my ($label, $and, $placeholder);
852 $label = $self->_convert($self->_quote($k));
853 $and = ' ' . $self->_sqlcase('and') . ' ';
854 $placeholder = $self->_convert('?');
855 $op = $self->_sqlcase($op);
857 my ($clause, @bind) = $self->_SWITCH_refkind($vals, {
859 my ($s, @b) = @$$vals;
860 $self->_assert_bindval_matches_bindtype(@b);
867 puke "special op 'between' accepts an arrayref with exactly two values"
870 my (@all_sql, @all_bind);
871 foreach my $val (@$vals) {
872 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
874 return ($placeholder, $val);
880 my ($sql, @bind) = @$$val;
881 $self->_assert_bindval_matches_bindtype(@bind);
882 return ($sql, @bind);
885 my ($func, $arg, @rest) = %$val;
886 puke ("Only simple { -func => arg } functions accepted as sub-arguments to BETWEEN")
887 if (@rest or $func !~ /^ \- (.+)/x);
888 local $self->{_nested_func_lhs} = $k;
889 $self->_where_func_generic ($1 => $arg);
893 push @all_bind, @bind;
897 (join $and, @all_sql),
898 $self->_bindtype($k, @all_bind),
902 puke "special op 'between' accepts an arrayref with two values, or a single literal scalarref/arrayref-ref";
906 my $sql = "( $label $op $clause )";
911 sub _where_field_IN {
912 my ($self, $k, $op, $vals) = @_;
914 # backwards compatibility : if scalar, force into an arrayref
915 $vals = [$vals] if defined $vals && ! ref $vals;
917 my ($label) = $self->_convert($self->_quote($k));
918 my ($placeholder) = $self->_convert('?');
919 $op = $self->_sqlcase($op);
921 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
922 ARRAYREF => sub { # list of choices
923 if (@$vals) { # nonempty list
924 my (@all_sql, @all_bind);
926 for my $val (@$vals) {
927 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
929 return ($placeholder, $val);
935 my ($sql, @bind) = @$$val;
936 $self->_assert_bindval_matches_bindtype(@bind);
937 return ($sql, @bind);
940 my ($func, $arg, @rest) = %$val;
941 puke ("Only simple { -func => arg } functions accepted as sub-arguments to IN")
942 if (@rest or $func !~ /^ \- (.+)/x);
943 local $self->{_nested_func_lhs} = $k;
944 $self->_where_func_generic ($1 => $arg);
948 push @all_bind, @bind;
952 sprintf ('%s %s ( %s )',
955 join (', ', @all_sql)
957 $self->_bindtype($k, @all_bind),
960 else { # empty list : some databases won't understand "IN ()", so DWIM
961 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
966 SCALARREF => sub { # literal SQL
967 my $sql = $self->_open_outer_paren ($$vals);
968 return ("$label $op ( $sql )");
970 ARRAYREFREF => sub { # literal SQL with bind
971 my ($sql, @bind) = @$$vals;
972 $self->_assert_bindval_matches_bindtype(@bind);
973 $sql = $self->_open_outer_paren ($sql);
974 return ("$label $op ( $sql )", @bind);
978 puke "special op 'in' requires an arrayref (or scalarref/arrayref-ref)";
982 return ($sql, @bind);
985 # Some databases (SQLite) treat col IN (1, 2) different from
986 # col IN ( (1, 2) ). Use this to strip all outer parens while
987 # adding them back in the corresponding method
988 sub _open_outer_paren {
989 my ($self, $sql) = @_;
990 $sql = $1 while $sql =~ /^ \s* \( (.*) \) \s* $/xs;
995 #======================================================================
997 #======================================================================
1000 my ($self, $arg) = @_;
1003 for my $c ($self->_order_by_chunks ($arg) ) {
1004 $self->_SWITCH_refkind ($c, {
1005 SCALAR => sub { push @sql, $c },
1006 ARRAYREF => sub { push @sql, shift @$c; push @bind, @$c },
1012 $self->_sqlcase(' order by'),
1018 return wantarray ? ($sql, @bind) : $sql;
1021 sub _order_by_chunks {
1022 my ($self, $arg) = @_;
1024 return $self->_SWITCH_refkind($arg, {
1027 map { $self->_order_by_chunks ($_ ) } @$arg;
1030 ARRAYREFREF => sub {
1031 my ($s, @b) = @$$arg;
1032 $self->_assert_bindval_matches_bindtype(@b);
1036 SCALAR => sub {$self->_quote($arg)},
1038 UNDEF => sub {return () },
1040 SCALARREF => sub {$$arg}, # literal SQL, no quoting
1043 # get first pair in hash
1044 my ($key, $val, @rest) = %$arg;
1046 return () unless $key;
1048 if ( @rest or not $key =~ /^-(desc|asc)/i ) {
1049 puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
1055 for my $c ($self->_order_by_chunks ($val)) {
1058 $self->_SWITCH_refkind ($c, {
1063 ($sql, @bind) = @$c;
1067 $sql = $sql . ' ' . $self->_sqlcase($direction);
1069 push @ret, [ $sql, @bind];
1078 #======================================================================
1079 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1080 #======================================================================
1085 $self->_SWITCH_refkind($from, {
1086 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
1087 SCALAR => sub {$self->_quote($from)},
1088 SCALARREF => sub {$$from},
1089 ARRAYREFREF => sub {join ', ', @$from;},
1094 #======================================================================
1096 #======================================================================
1098 # highly optimized, as it's called way too often
1100 # my ($self, $label) = @_;
1102 return '' unless defined $_[1];
1103 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1105 return $_[1] unless $_[0]->{quote_char};
1107 my $qref = ref $_[0]->{quote_char};
1110 ($l, $r) = ( $_[0]->{quote_char}, $_[0]->{quote_char} );
1112 elsif ($qref eq 'ARRAY') {
1113 ($l, $r) = @{$_[0]->{quote_char}};
1116 puke "Unsupported quote_char format: $_[0]->{quote_char}";
1119 # parts containing * are naturally unquoted
1120 return join( $_[0]->{name_sep}||'', map
1121 { $_ eq '*' ? $_ : $l . $_ . $r }
1122 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
1127 # Conversion, if applicable
1129 #my ($self, $arg) = @_;
1131 # LDNOTE : modified the previous implementation below because
1132 # it was not consistent : the first "return" is always an array,
1133 # the second "return" is context-dependent. Anyway, _convert
1134 # seems always used with just a single argument, so make it a
1136 # return @_ unless $self->{convert};
1137 # my $conv = $self->_sqlcase($self->{convert});
1138 # my @ret = map { $conv.'('.$_.')' } @_;
1139 # return wantarray ? @ret : $ret[0];
1140 if ($_[0]->{convert}) {
1141 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
1148 #my ($self, $col, @vals) = @_;
1150 #LDNOTE : changed original implementation below because it did not make
1151 # sense when bindtype eq 'columns' and @vals > 1.
1152 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
1154 # called often - tighten code
1155 return $_[0]->{bindtype} eq 'columns'
1156 ? map {[$_[1], $_]} @_[2 .. $#_]
1161 # Dies if any element of @bind is not in [colname => value] format
1162 # if bindtype is 'columns'.
1163 sub _assert_bindval_matches_bindtype {
1164 # my ($self, @bind) = @_;
1166 if ($self->{bindtype} eq 'columns') {
1168 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1169 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1175 sub _join_sql_clauses {
1176 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1178 if (@$clauses_aref > 1) {
1179 my $join = " " . $self->_sqlcase($logic) . " ";
1180 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1181 return ($sql, @$bind_aref);
1183 elsif (@$clauses_aref) {
1184 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1187 return (); # if no SQL, ignore @$bind_aref
1192 # Fix SQL case, if so requested
1194 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1195 # don't touch the argument ... crooked logic, but let's not change it!
1196 return $_[0]->{case} ? $_[1] : uc($_[1]);
1200 #======================================================================
1201 # DISPATCHING FROM REFKIND
1202 #======================================================================
1205 my ($self, $data) = @_;
1207 return 'UNDEF' unless defined $data;
1209 # blessed objects are treated like scalars
1210 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1212 return 'SCALAR' unless $ref;
1215 while ($ref eq 'REF') {
1217 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1221 return ($ref||'SCALAR') . ('REF' x $n_steps);
1225 my ($self, $data) = @_;
1226 my @try = ($self->_refkind($data));
1227 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1228 push @try, 'FALLBACK';
1232 sub _METHOD_FOR_refkind {
1233 my ($self, $meth_prefix, $data) = @_;
1236 for (@{$self->_try_refkind($data)}) {
1237 $method = $self->can($meth_prefix."_".$_)
1241 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1245 sub _SWITCH_refkind {
1246 my ($self, $data, $dispatch_table) = @_;
1249 for (@{$self->_try_refkind($data)}) {
1250 $coderef = $dispatch_table->{$_}
1254 puke "no dispatch entry for ".$self->_refkind($data)
1263 #======================================================================
1264 # VALUES, GENERATE, AUTOLOAD
1265 #======================================================================
1267 # LDNOTE: original code from nwiger, didn't touch code in that section
1268 # I feel the AUTOLOAD stuff should not be the default, it should
1269 # only be activated on explicit demand by user.
1273 my $data = shift || return;
1274 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1275 unless ref $data eq 'HASH';
1278 foreach my $k ( sort keys %$data ) {
1279 my $v = $data->{$k};
1280 $self->_SWITCH_refkind($v, {
1282 if ($self->{array_datatypes}) { # array datatype
1283 push @all_bind, $self->_bindtype($k, $v);
1285 else { # literal SQL with bind
1286 my ($sql, @bind) = @$v;
1287 $self->_assert_bindval_matches_bindtype(@bind);
1288 push @all_bind, @bind;
1291 ARRAYREFREF => sub { # literal SQL with bind
1292 my ($sql, @bind) = @${$v};
1293 $self->_assert_bindval_matches_bindtype(@bind);
1294 push @all_bind, @bind;
1296 SCALARREF => sub { # literal SQL without bind
1298 SCALAR_or_UNDEF => sub {
1299 push @all_bind, $self->_bindtype($k, $v);
1310 my(@sql, @sqlq, @sqlv);
1314 if ($ref eq 'HASH') {
1315 for my $k (sort keys %$_) {
1318 my $label = $self->_quote($k);
1319 if ($r eq 'ARRAY') {
1320 # literal SQL with bind
1321 my ($sql, @bind) = @$v;
1322 $self->_assert_bindval_matches_bindtype(@bind);
1323 push @sqlq, "$label = $sql";
1325 } elsif ($r eq 'SCALAR') {
1326 # literal SQL without bind
1327 push @sqlq, "$label = $$v";
1329 push @sqlq, "$label = ?";
1330 push @sqlv, $self->_bindtype($k, $v);
1333 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1334 } elsif ($ref eq 'ARRAY') {
1335 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1338 if ($r eq 'ARRAY') { # literal SQL with bind
1339 my ($sql, @bind) = @$v;
1340 $self->_assert_bindval_matches_bindtype(@bind);
1343 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1344 # embedded literal SQL
1351 push @sql, '(' . join(', ', @sqlq) . ')';
1352 } elsif ($ref eq 'SCALAR') {
1356 # strings get case twiddled
1357 push @sql, $self->_sqlcase($_);
1361 my $sql = join ' ', @sql;
1363 # this is pretty tricky
1364 # if ask for an array, return ($stmt, @bind)
1365 # otherwise, s/?/shift @sqlv/ to put it inline
1367 return ($sql, @sqlv);
1369 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1370 ref $d ? $d->[1] : $d/e;
1379 # This allows us to check for a local, then _form, attr
1381 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1382 return $self->generate($name, @_);
1393 SQL::Abstract - Generate SQL from Perl data structures
1399 my $sql = SQL::Abstract->new;
1401 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1403 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1405 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1407 my($stmt, @bind) = $sql->delete($table, \%where);
1409 # Then, use these in your DBI statements
1410 my $sth = $dbh->prepare($stmt);
1411 $sth->execute(@bind);
1413 # Just generate the WHERE clause
1414 my($stmt, @bind) = $sql->where(\%where, \@order);
1416 # Return values in the same order, for hashed queries
1417 # See PERFORMANCE section for more details
1418 my @bind = $sql->values(\%fieldvals);
1422 This module was inspired by the excellent L<DBIx::Abstract>.
1423 However, in using that module I found that what I really wanted
1424 to do was generate SQL, but still retain complete control over my
1425 statement handles and use the DBI interface. So, I set out to
1426 create an abstract SQL generation module.
1428 While based on the concepts used by L<DBIx::Abstract>, there are
1429 several important differences, especially when it comes to WHERE
1430 clauses. I have modified the concepts used to make the SQL easier
1431 to generate from Perl data structures and, IMO, more intuitive.
1432 The underlying idea is for this module to do what you mean, based
1433 on the data structures you provide it. The big advantage is that
1434 you don't have to modify your code every time your data changes,
1435 as this module figures it out.
1437 To begin with, an SQL INSERT is as easy as just specifying a hash
1438 of C<key=value> pairs:
1441 name => 'Jimbo Bobson',
1442 phone => '123-456-7890',
1443 address => '42 Sister Lane',
1444 city => 'St. Louis',
1445 state => 'Louisiana',
1448 The SQL can then be generated with this:
1450 my($stmt, @bind) = $sql->insert('people', \%data);
1452 Which would give you something like this:
1454 $stmt = "INSERT INTO people
1455 (address, city, name, phone, state)
1456 VALUES (?, ?, ?, ?, ?)";
1457 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1458 '123-456-7890', 'Louisiana');
1460 These are then used directly in your DBI code:
1462 my $sth = $dbh->prepare($stmt);
1463 $sth->execute(@bind);
1465 =head2 Inserting and Updating Arrays
1467 If your database has array types (like for example Postgres),
1468 activate the special option C<< array_datatypes => 1 >>
1469 when creating the C<SQL::Abstract> object.
1470 Then you may use an arrayref to insert and update database array types:
1472 my $sql = SQL::Abstract->new(array_datatypes => 1);
1474 planets => [qw/Mercury Venus Earth Mars/]
1477 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1481 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1483 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1486 =head2 Inserting and Updating SQL
1488 In order to apply SQL functions to elements of your C<%data> you may
1489 specify a reference to an arrayref for the given hash value. For example,
1490 if you need to execute the Oracle C<to_date> function on a value, you can
1491 say something like this:
1495 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
1498 The first value in the array is the actual SQL. Any other values are
1499 optional and would be included in the bind values array. This gives
1502 my($stmt, @bind) = $sql->insert('people', \%data);
1504 $stmt = "INSERT INTO people (name, date_entered)
1505 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1506 @bind = ('Bill', '03/02/2003');
1508 An UPDATE is just as easy, all you change is the name of the function:
1510 my($stmt, @bind) = $sql->update('people', \%data);
1512 Notice that your C<%data> isn't touched; the module will generate
1513 the appropriately quirky SQL for you automatically. Usually you'll
1514 want to specify a WHERE clause for your UPDATE, though, which is
1515 where handling C<%where> hashes comes in handy...
1517 =head2 Complex where statements
1519 This module can generate pretty complicated WHERE statements
1520 easily. For example, simple C<key=value> pairs are taken to mean
1521 equality, and if you want to see if a field is within a set
1522 of values, you can use an arrayref. Let's say we wanted to
1523 SELECT some data based on this criteria:
1526 requestor => 'inna',
1527 worker => ['nwiger', 'rcwe', 'sfz'],
1528 status => { '!=', 'completed' }
1531 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1533 The above would give you something like this:
1535 $stmt = "SELECT * FROM tickets WHERE
1536 ( requestor = ? ) AND ( status != ? )
1537 AND ( worker = ? OR worker = ? OR worker = ? )";
1538 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1540 Which you could then use in DBI code like so:
1542 my $sth = $dbh->prepare($stmt);
1543 $sth->execute(@bind);
1549 The functions are simple. There's one for each major SQL operation,
1550 and a constructor you use first. The arguments are specified in a
1551 similar order to each function (table, then fields, then a where
1552 clause) to try and simplify things.
1557 =head2 new(option => 'value')
1559 The C<new()> function takes a list of options and values, and returns
1560 a new B<SQL::Abstract> object which can then be used to generate SQL
1561 through the methods below. The options accepted are:
1567 If set to 'lower', then SQL will be generated in all lowercase. By
1568 default SQL is generated in "textbook" case meaning something like:
1570 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1572 Any setting other than 'lower' is ignored.
1576 This determines what the default comparison operator is. By default
1577 it is C<=>, meaning that a hash like this:
1579 %where = (name => 'nwiger', email => 'nate@wiger.org');
1581 Will generate SQL like this:
1583 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1585 However, you may want loose comparisons by default, so if you set
1586 C<cmp> to C<like> you would get SQL such as:
1588 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1590 You can also override the comparsion on an individual basis - see
1591 the huge section on L</"WHERE CLAUSES"> at the bottom.
1593 =item sqltrue, sqlfalse
1595 Expressions for inserting boolean values within SQL statements.
1596 By default these are C<1=1> and C<1=0>. They are used
1597 by the special operators C<-in> and C<-not_in> for generating
1598 correct SQL even when the argument is an empty array (see below).
1602 This determines the default logical operator for multiple WHERE
1603 statements in arrays or hashes. If absent, the default logic is "or"
1604 for arrays, and "and" for hashes. This means that a WHERE
1608 event_date => {'>=', '2/13/99'},
1609 event_date => {'<=', '4/24/03'},
1612 will generate SQL like this:
1614 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1616 This is probably not what you want given this query, though (look
1617 at the dates). To change the "OR" to an "AND", simply specify:
1619 my $sql = SQL::Abstract->new(logic => 'and');
1621 Which will change the above C<WHERE> to:
1623 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1625 The logic can also be changed locally by inserting
1626 a modifier in front of an arrayref :
1628 @where = (-and => [event_date => {'>=', '2/13/99'},
1629 event_date => {'<=', '4/24/03'} ]);
1631 See the L</"WHERE CLAUSES"> section for explanations.
1635 This will automatically convert comparisons using the specified SQL
1636 function for both column and value. This is mostly used with an argument
1637 of C<upper> or C<lower>, so that the SQL will have the effect of
1638 case-insensitive "searches". For example, this:
1640 $sql = SQL::Abstract->new(convert => 'upper');
1641 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1643 Will turn out the following SQL:
1645 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1647 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1648 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1649 not validate this option; it will just pass through what you specify verbatim).
1653 This is a kludge because many databases suck. For example, you can't
1654 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1655 Instead, you have to use C<bind_param()>:
1657 $sth->bind_param(1, 'reg data');
1658 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1660 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1661 which loses track of which field each slot refers to. Fear not.
1663 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1664 Currently, you can specify either C<normal> (default) or C<columns>. If you
1665 specify C<columns>, you will get an array that looks like this:
1667 my $sql = SQL::Abstract->new(bindtype => 'columns');
1668 my($stmt, @bind) = $sql->insert(...);
1671 [ 'column1', 'value1' ],
1672 [ 'column2', 'value2' ],
1673 [ 'column3', 'value3' ],
1676 You can then iterate through this manually, using DBI's C<bind_param()>.
1678 $sth->prepare($stmt);
1681 my($col, $data) = @$_;
1682 if ($col eq 'details' || $col eq 'comments') {
1683 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1684 } elsif ($col eq 'image') {
1685 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1687 $sth->bind_param($i, $data);
1691 $sth->execute; # execute without @bind now
1693 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1694 Basically, the advantage is still that you don't have to care which fields
1695 are or are not included. You could wrap that above C<for> loop in a simple
1696 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1697 get a layer of abstraction over manual SQL specification.
1699 Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1700 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1701 will expect the bind values in this format.
1705 This is the character that a table or column name will be quoted
1706 with. By default this is an empty string, but you could set it to
1707 the character C<`>, to generate SQL like this:
1709 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1711 Alternatively, you can supply an array ref of two items, the first being the left
1712 hand quote character, and the second the right hand quote character. For
1713 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1714 that generates SQL like this:
1716 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1718 Quoting is useful if you have tables or columns names that are reserved
1719 words in your database's SQL dialect.
1723 This is the character that separates a table and column name. It is
1724 necessary to specify this when the C<quote_char> option is selected,
1725 so that tables and column names can be individually quoted like this:
1727 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1729 =item array_datatypes
1731 When this option is true, arrayrefs in INSERT or UPDATE are
1732 interpreted as array datatypes and are passed directly
1734 When this option is false, arrayrefs are interpreted
1735 as literal SQL, just like refs to arrayrefs
1736 (but this behavior is for backwards compatibility; when writing
1737 new queries, use the "reference to arrayref" syntax
1743 Takes a reference to a list of "special operators"
1744 to extend the syntax understood by L<SQL::Abstract>.
1745 See section L</"SPECIAL OPERATORS"> for details.
1749 Takes a reference to a list of "unary operators"
1750 to extend the syntax understood by L<SQL::Abstract>.
1751 See section L</"UNARY OPERATORS"> for details.
1757 =head2 insert($table, \@values || \%fieldvals, \%options)
1759 This is the simplest function. You simply give it a table name
1760 and either an arrayref of values or hashref of field/value pairs.
1761 It returns an SQL INSERT statement and a list of bind values.
1762 See the sections on L</"Inserting and Updating Arrays"> and
1763 L</"Inserting and Updating SQL"> for information on how to insert
1764 with those data types.
1766 The optional C<\%options> hash reference may contain additional
1767 options to generate the insert SQL. Currently supported options
1774 Takes either a scalar of raw SQL fields, or an array reference of
1775 field names, and adds on an SQL C<RETURNING> statement at the end.
1776 This allows you to return data generated by the insert statement
1777 (such as row IDs) without performing another C<SELECT> statement.
1778 Note, however, this is not part of the SQL standard and may not
1779 be supported by all database engines.
1783 =head2 update($table, \%fieldvals, \%where)
1785 This takes a table, hashref of field/value pairs, and an optional
1786 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1788 See the sections on L</"Inserting and Updating Arrays"> and
1789 L</"Inserting and Updating SQL"> for information on how to insert
1790 with those data types.
1792 =head2 select($source, $fields, $where, $order)
1794 This returns a SQL SELECT statement and associated list of bind values, as
1795 specified by the arguments :
1801 Specification of the 'FROM' part of the statement.
1802 The argument can be either a plain scalar (interpreted as a table
1803 name, will be quoted), or an arrayref (interpreted as a list
1804 of table names, joined by commas, quoted), or a scalarref
1805 (literal table name, not quoted), or a ref to an arrayref
1806 (list of literal table names, joined by commas, not quoted).
1810 Specification of the list of fields to retrieve from
1812 The argument can be either an arrayref (interpreted as a list
1813 of field names, will be joined by commas and quoted), or a
1814 plain scalar (literal SQL, not quoted).
1815 Please observe that this API is not as flexible as for
1816 the first argument C<$table>, for backwards compatibility reasons.
1820 Optional argument to specify the WHERE part of the query.
1821 The argument is most often a hashref, but can also be
1822 an arrayref or plain scalar --
1823 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1827 Optional argument to specify the ORDER BY part of the query.
1828 The argument can be a scalar, a hashref or an arrayref
1829 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1835 =head2 delete($table, \%where)
1837 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1838 It returns an SQL DELETE statement and list of bind values.
1840 =head2 where(\%where, \@order)
1842 This is used to generate just the WHERE clause. For example,
1843 if you have an arbitrary data structure and know what the
1844 rest of your SQL is going to look like, but want an easy way
1845 to produce a WHERE clause, use this. It returns an SQL WHERE
1846 clause and list of bind values.
1849 =head2 values(\%data)
1851 This just returns the values from the hash C<%data>, in the same
1852 order that would be returned from any of the other above queries.
1853 Using this allows you to markedly speed up your queries if you
1854 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1856 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1858 Warning: This is an experimental method and subject to change.
1860 This returns arbitrarily generated SQL. It's a really basic shortcut.
1861 It will return two different things, depending on return context:
1863 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1864 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1866 These would return the following:
1868 # First calling form
1869 $stmt = "CREATE TABLE test (?, ?)";
1870 @bind = (field1, field2);
1872 # Second calling form
1873 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1875 Depending on what you're trying to do, it's up to you to choose the correct
1876 format. In this example, the second form is what you would want.
1880 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1884 ALTER SESSION SET nls_date_format = 'MM/YY'
1886 You get the idea. Strings get their case twiddled, but everything
1887 else remains verbatim.
1892 =head1 WHERE CLAUSES
1896 This module uses a variation on the idea from L<DBIx::Abstract>. It
1897 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1898 module is that things in arrays are OR'ed, and things in hashes
1901 The easiest way to explain is to show lots of examples. After
1902 each C<%where> hash shown, it is assumed you used:
1904 my($stmt, @bind) = $sql->where(\%where);
1906 However, note that the C<%where> hash can be used directly in any
1907 of the other functions as well, as described above.
1909 =head2 Key-value pairs
1911 So, let's get started. To begin, a simple hash:
1915 status => 'completed'
1918 Is converted to SQL C<key = val> statements:
1920 $stmt = "WHERE user = ? AND status = ?";
1921 @bind = ('nwiger', 'completed');
1923 One common thing I end up doing is having a list of values that
1924 a field can be in. To do this, simply specify a list inside of
1929 status => ['assigned', 'in-progress', 'pending'];
1932 This simple code will create the following:
1934 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1935 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1937 A field associated to an empty arrayref will be considered a
1938 logical false and will generate 0=1.
1940 =head2 Tests for NULL values
1942 If the value part is C<undef> then this is converted to SQL <IS NULL>
1951 $stmt = "WHERE user = ? AND status IS NULL";
1954 =head2 Specific comparison operators
1956 If you want to specify a different type of operator for your comparison,
1957 you can use a hashref for a given column:
1961 status => { '!=', 'completed' }
1964 Which would generate:
1966 $stmt = "WHERE user = ? AND status != ?";
1967 @bind = ('nwiger', 'completed');
1969 To test against multiple values, just enclose the values in an arrayref:
1971 status => { '=', ['assigned', 'in-progress', 'pending'] };
1973 Which would give you:
1975 "WHERE status = ? OR status = ? OR status = ?"
1978 The hashref can also contain multiple pairs, in which case it is expanded
1979 into an C<AND> of its elements:
1983 status => { '!=', 'completed', -not_like => 'pending%' }
1986 # Or more dynamically, like from a form
1987 $where{user} = 'nwiger';
1988 $where{status}{'!='} = 'completed';
1989 $where{status}{'-not_like'} = 'pending%';
1991 # Both generate this
1992 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1993 @bind = ('nwiger', 'completed', 'pending%');
1996 To get an OR instead, you can combine it with the arrayref idea:
2000 priority => [ {'=', 2}, {'!=', 1} ]
2003 Which would generate:
2005 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
2006 @bind = ('nwiger', '2', '1');
2008 If you want to include literal SQL (with or without bind values), just use a
2009 scalar reference or array reference as the value:
2012 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2013 date_expires => { '<' => \"now()" }
2016 Which would generate:
2018 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2019 @bind = ('11/26/2008');
2022 =head2 Logic and nesting operators
2024 In the example above,
2025 there is a subtle trap if you want to say something like
2026 this (notice the C<AND>):
2028 WHERE priority != ? AND priority != ?
2030 Because, in Perl you I<can't> do this:
2032 priority => { '!=', 2, '!=', 1 }
2034 As the second C<!=> key will obliterate the first. The solution
2035 is to use the special C<-modifier> form inside an arrayref:
2037 priority => [ -and => {'!=', 2},
2041 Normally, these would be joined by C<OR>, but the modifier tells it
2042 to use C<AND> instead. (Hint: You can use this in conjunction with the
2043 C<logic> option to C<new()> in order to change the way your queries
2044 work by default.) B<Important:> Note that the C<-modifier> goes
2045 B<INSIDE> the arrayref, as an extra first element. This will
2046 B<NOT> do what you think it might:
2048 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2050 Here is a quick list of equivalencies, since there is some overlap:
2053 status => {'!=', 'completed', 'not like', 'pending%' }
2054 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2057 status => {'=', ['assigned', 'in-progress']}
2058 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2059 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2063 =head2 Special operators : IN, BETWEEN, etc.
2065 You can also use the hashref format to compare a list of fields using the
2066 C<IN> comparison operator, by specifying the list as an arrayref:
2069 status => 'completed',
2070 reportid => { -in => [567, 2335, 2] }
2073 Which would generate:
2075 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2076 @bind = ('completed', '567', '2335', '2');
2078 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2081 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2082 (by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
2083 'sqltrue' (by default : C<1=1>).
2085 In addition to the array you can supply a chunk of literal sql or
2086 literal sql with bind:
2089 customer => { -in => \[
2090 'SELECT cust_id FROM cust WHERE balance > ?',
2093 status => { -in => \'SELECT status_codes FROM states' },
2099 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2100 AND status IN ( SELECT status_codes FROM states )
2106 Another pair of operators is C<-between> and C<-not_between>,
2107 used with an arrayref of two values:
2111 completion_date => {
2112 -not_between => ['2002-10-01', '2003-02-06']
2118 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2120 Just like with C<-in> all plausible combinations of literal SQL
2124 start0 => { -between => [ 1, 2 ] },
2125 start1 => { -between => \["? AND ?", 1, 2] },
2126 start2 => { -between => \"lower(x) AND upper(y)" },
2127 start3 => { -between => [
2129 \["upper(?)", 'stuff' ],
2136 ( start0 BETWEEN ? AND ? )
2137 AND ( start1 BETWEEN ? AND ? )
2138 AND ( start2 BETWEEN lower(x) AND upper(y) )
2139 AND ( start3 BETWEEN lower(x) AND upper(?) )
2141 @bind = (1, 2, 1, 2, 'stuff');
2144 These are the two builtin "special operators"; but the
2145 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
2147 =head2 Unary operators: bool
2149 If you wish to test against boolean columns or functions within your
2150 database you can use the C<-bool> and C<-not_bool> operators. For
2151 example to test the column C<is_user> being true and the column
2152 C<is_enabled> being false you would use:-
2156 -not_bool => 'is_enabled',
2161 WHERE is_user AND NOT is_enabled
2163 If a more complex combination is required, testing more conditions,
2164 then you should use the and/or operators:-
2171 -not_bool => 'four',
2177 WHERE one AND two AND three AND NOT four
2180 =head2 Nested conditions, -and/-or prefixes
2182 So far, we've seen how multiple conditions are joined with a top-level
2183 C<AND>. We can change this by putting the different conditions we want in
2184 hashes and then putting those hashes in an array. For example:
2189 status => { -like => ['pending%', 'dispatched'] },
2193 status => 'unassigned',
2197 This data structure would create the following:
2199 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2200 OR ( user = ? AND status = ? ) )";
2201 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2204 There is also a special C<-nest>
2205 operator which adds an additional set of parens, to create a subquery.
2206 For example, to get something like this:
2208 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
2209 @bind = ('nwiger', '20', 'ASIA');
2215 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2219 Finally, clauses in hashrefs or arrayrefs can be
2220 prefixed with an C<-and> or C<-or> to change the logic
2227 -and => [workhrs => {'>', 20}, geo => 'ASIA' ],
2228 -and => [workhrs => {'<', 50}, geo => 'EURO' ]
2235 WHERE ( user = ? AND
2236 ( ( workhrs > ? AND geo = ? )
2237 OR ( workhrs < ? AND geo = ? ) ) )
2240 =head2 Algebraic inconsistency, for historical reasons
2242 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2243 operator goes C<outside> of the nested structure; whereas when connecting
2244 several constraints on one column, the C<-and> operator goes
2245 C<inside> the arrayref. Here is an example combining both features :
2248 -and => [a => 1, b => 2],
2249 -or => [c => 3, d => 4],
2250 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2255 WHERE ( ( ( a = ? AND b = ? )
2256 OR ( c = ? OR d = ? )
2257 OR ( e LIKE ? AND e LIKE ? ) ) )
2259 This difference in syntax is unfortunate but must be preserved for
2260 historical reasons. So be careful : the two examples below would
2261 seem algebraically equivalent, but they are not
2263 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
2264 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
2266 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
2267 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
2272 Finally, sometimes only literal SQL will do. If you want to include
2273 literal SQL verbatim, you can specify it as a scalar reference, namely:
2275 my $inn = 'is Not Null';
2277 priority => { '<', 2 },
2283 $stmt = "WHERE priority < ? AND requestor is Not Null";
2286 Note that in this example, you only get one bind parameter back, since
2287 the verbatim SQL is passed as part of the statement.
2289 Of course, just to prove a point, the above can also be accomplished
2293 priority => { '<', 2 },
2294 requestor => { '!=', undef },
2300 Conditions on boolean columns can be expressed in the same way, passing
2301 a reference to an empty string, however using liternal SQL in this way
2302 is deprecated - the preferred method is to use the boolean operators -
2303 see L</"Unary operators: bool"> :
2306 priority => { '<', 2 },
2312 $stmt = "WHERE priority < ? AND is_ready";
2315 Literal SQL is also the only way to compare 2 columns to one another:
2318 priority => { '<', 2 },
2319 requestor => \'= submittor'
2324 $stmt = "WHERE priority < ? AND requestor = submitter";
2327 =head2 Literal SQL with placeholders and bind values (subqueries)
2329 If the literal SQL to be inserted has placeholders and bind values,
2330 use a reference to an arrayref (yes this is a double reference --
2331 not so common, but perfectly legal Perl). For example, to find a date
2332 in Postgres you can use something like this:
2335 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
2340 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2343 Note that you must pass the bind values in the same format as they are returned
2344 by L</where>. That means that if you set L</bindtype> to C<columns>, you must
2345 provide the bind values in the C<< [ column_meta => value ] >> format, where
2346 C<column_meta> is an opaque scalar value; most commonly the column name, but
2347 you can use any scalar value (including references and blessed references),
2348 L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
2349 to C<columns> the above example will look like:
2352 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
2355 Literal SQL is especially useful for nesting parenthesized clauses in the
2356 main SQL query. Here is a first example :
2358 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2362 bar => \["IN ($sub_stmt)" => @sub_bind],
2367 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2368 WHERE c2 < ? AND c3 LIKE ?))";
2369 @bind = (1234, 100, "foo%");
2371 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2372 are expressed in the same way. Of course the C<$sub_stmt> and
2373 its associated bind values can be generated through a former call
2376 my ($sub_stmt, @sub_bind)
2377 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2378 c3 => {-like => "foo%"}});
2381 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2384 In the examples above, the subquery was used as an operator on a column;
2385 but the same principle also applies for a clause within the main C<%where>
2386 hash, like an EXISTS subquery :
2388 my ($sub_stmt, @sub_bind)
2389 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2392 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
2397 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2398 WHERE c1 = ? AND c2 > t0.c0))";
2402 Observe that the condition on C<c2> in the subquery refers to
2403 column C<t0.c0> of the main query : this is I<not> a bind
2404 value, so we have to express it through a scalar ref.
2405 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2406 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2407 what we wanted here.
2409 Another use of the subquery technique is when some SQL clauses need
2410 parentheses, as it often occurs with some proprietary SQL extensions
2411 like for example fulltext expressions, geospatial expressions,
2412 NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
2415 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
2418 Finally, here is an example where a subquery is used
2419 for expressing unary negation:
2421 my ($sub_stmt, @sub_bind)
2422 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2423 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2425 lname => {like => '%son%'},
2426 -nest => \["NOT ($sub_stmt)" => @sub_bind],
2431 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2432 @bind = ('%son%', 10, 20)
2438 These pages could go on for a while, since the nesting of the data
2439 structures this module can handle are pretty much unlimited (the
2440 module implements the C<WHERE> expansion as a recursive function
2441 internally). Your best bet is to "play around" with the module a
2442 little to see how the data structures behave, and choose the best
2443 format for your data based on that.
2445 And of course, all the values above will probably be replaced with
2446 variables gotten from forms or the command line. After all, if you
2447 knew everything ahead of time, you wouldn't have to worry about
2448 dynamically-generating SQL and could just hardwire it into your
2454 =head1 ORDER BY CLAUSES
2456 Some functions take an order by clause. This can either be a scalar (just a
2457 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
2458 or an array of either of the two previous forms. Examples:
2460 Given | Will Generate
2461 ----------------------------------------------------------
2463 \'colA DESC' | ORDER BY colA DESC
2465 'colA' | ORDER BY colA
2467 [qw/colA colB/] | ORDER BY colA, colB
2469 {-asc => 'colA'} | ORDER BY colA ASC
2471 {-desc => 'colB'} | ORDER BY colB DESC
2473 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2475 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2478 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
2479 { -desc => [qw/colB/], | colC ASC, colD ASC
2480 { -asc => [qw/colC colD/],|
2482 ===========================================================
2486 =head1 SPECIAL OPERATORS
2488 my $sqlmaker = SQL::Abstract->new(special_ops => [
2492 my ($self, $field, $op, $arg) = @_;
2498 handler => 'method_name',
2502 A "special operator" is a SQL syntactic clause that can be
2503 applied to a field, instead of a usual binary operator.
2506 WHERE field IN (?, ?, ?)
2507 WHERE field BETWEEN ? AND ?
2508 WHERE MATCH(field) AGAINST (?, ?)
2510 Special operators IN and BETWEEN are fairly standard and therefore
2511 are builtin within C<SQL::Abstract> (as the overridable methods
2512 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2513 like the MATCH .. AGAINST example above which is specific to MySQL,
2514 you can write your own operator handlers - supply a C<special_ops>
2515 argument to the C<new> method. That argument takes an arrayref of
2516 operator definitions; each operator definition is a hashref with two
2523 the regular expression to match the operator
2527 Either a coderef or a plain scalar method name. In both cases
2528 the expected return is C<< ($sql, @bind) >>.
2530 When supplied with a method name, it is simply called on the
2531 L<SQL::Abstract/> object as:
2533 $self->$method_name ($field, $op, $arg)
2537 $op is the part that matched the handler regex
2538 $field is the LHS of the operator
2541 When supplied with a coderef, it is called as:
2543 $coderef->($self, $field, $op, $arg)
2548 For example, here is an implementation
2549 of the MATCH .. AGAINST syntax for MySQL
2551 my $sqlmaker = SQL::Abstract->new(special_ops => [
2553 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2554 {regex => qr/^match$/i,
2556 my ($self, $field, $op, $arg) = @_;
2557 $arg = [$arg] if not ref $arg;
2558 my $label = $self->_quote($field);
2559 my ($placeholder) = $self->_convert('?');
2560 my $placeholders = join ", ", (($placeholder) x @$arg);
2561 my $sql = $self->_sqlcase('match') . " ($label) "
2562 . $self->_sqlcase('against') . " ($placeholders) ";
2563 my @bind = $self->_bindtype($field, @$arg);
2564 return ($sql, @bind);
2571 =head1 UNARY OPERATORS
2573 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2577 my ($self, $op, $arg) = @_;
2583 handler => 'method_name',
2587 A "unary operator" is a SQL syntactic clause that can be
2588 applied to a field - the operator goes before the field
2590 You can write your own operator handlers - supply a C<unary_ops>
2591 argument to the C<new> method. That argument takes an arrayref of
2592 operator definitions; each operator definition is a hashref with two
2599 the regular expression to match the operator
2603 Either a coderef or a plain scalar method name. In both cases
2604 the expected return is C<< $sql >>.
2606 When supplied with a method name, it is simply called on the
2607 L<SQL::Abstract/> object as:
2609 $self->$method_name ($op, $arg)
2613 $op is the part that matched the handler regex
2614 $arg is the RHS or argument of the operator
2616 When supplied with a coderef, it is called as:
2618 $coderef->($self, $op, $arg)
2626 Thanks to some benchmarking by Mark Stosberg, it turns out that
2627 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2628 I must admit this wasn't an intentional design issue, but it's a
2629 byproduct of the fact that you get to control your C<DBI> handles
2632 To maximize performance, use a code snippet like the following:
2634 # prepare a statement handle using the first row
2635 # and then reuse it for the rest of the rows
2637 for my $href (@array_of_hashrefs) {
2638 $stmt ||= $sql->insert('table', $href);
2639 $sth ||= $dbh->prepare($stmt);
2640 $sth->execute($sql->values($href));
2643 The reason this works is because the keys in your C<$href> are sorted
2644 internally by B<SQL::Abstract>. Thus, as long as your data retains
2645 the same structure, you only have to generate the SQL the first time
2646 around. On subsequent queries, simply use the C<values> function provided
2647 by this module to return your values in the correct order.
2649 However this depends on the values having the same type - if, for
2650 example, the values of a where clause may either have values
2651 (resulting in sql of the form C<column = ?> with a single bind
2652 value), or alternatively the values might be C<undef> (resulting in
2653 sql of the form C<column IS NULL> with no bind value) then the
2654 caching technique suggested will not work.
2658 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2659 really like this part (I do, at least). Building up a complex query
2660 can be as simple as the following:
2664 use CGI::FormBuilder;
2667 my $form = CGI::FormBuilder->new(...);
2668 my $sql = SQL::Abstract->new;
2670 if ($form->submitted) {
2671 my $field = $form->field;
2672 my $id = delete $field->{id};
2673 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2676 Of course, you would still have to connect using C<DBI> to run the
2677 query, but the point is that if you make your form look like your
2678 table, the actual query script can be extremely simplistic.
2680 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2681 a fast interface to returning and formatting data. I frequently
2682 use these three modules together to write complex database query
2683 apps in under 50 lines.
2688 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2689 Great care has been taken to preserve the I<published> behavior
2690 documented in previous versions in the 1.* family; however,
2691 some features that were previously undocumented, or behaved
2692 differently from the documentation, had to be changed in order
2693 to clarify the semantics. Hence, client code that was relying
2694 on some dark areas of C<SQL::Abstract> v1.*
2695 B<might behave differently> in v1.50.
2697 The main changes are :
2703 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2707 support for the { operator => \"..." } construct (to embed literal SQL)
2711 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2715 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2719 defensive programming : check arguments
2723 fixed bug with global logic, which was previously implemented
2724 through global variables yielding side-effects. Prior versions would
2725 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2726 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2727 Now this is interpreted
2728 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2733 fixed semantics of _bindtype on array args
2737 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2738 we just avoid shifting arrays within that tree.
2742 dropped the C<_modlogic> function
2748 =head1 ACKNOWLEDGEMENTS
2750 There are a number of individuals that have really helped out with
2751 this module. Unfortunately, most of them submitted bugs via CPAN
2752 so I have no idea who they are! But the people I do know are:
2754 Ash Berlin (order_by hash term support)
2755 Matt Trout (DBIx::Class support)
2756 Mark Stosberg (benchmarking)
2757 Chas Owens (initial "IN" operator support)
2758 Philip Collins (per-field SQL functions)
2759 Eric Kolve (hashref "AND" support)
2760 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2761 Dan Kubb (support for "quote_char" and "name_sep")
2762 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2763 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
2764 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2765 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
2766 Oliver Charles (support for "RETURNING" after "INSERT")
2772 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2776 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2778 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
2780 For support, your best bet is to try the C<DBIx::Class> users mailing list.
2781 While not an official support venue, C<DBIx::Class> makes heavy use of
2782 C<SQL::Abstract>, and as such list members there are very familiar with
2783 how to create queries.
2787 This module is free software; you may copy this under the same
2788 terms as perl itself (either the GNU General Public License or
2789 the Artistic License)