1 package SQL::Abstract; # see doc at end of file
10 our @EXPORT_OK = qw(is_plain_value is_literal_value);
20 *SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION = $ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}
26 #======================================================================
28 #======================================================================
30 our $VERSION = '1.86';
32 # This would confuse some packagers
33 $VERSION = eval $VERSION if $VERSION =~ /_/; # numify for warning-free dev releases
37 # special operators (-in, -between). May be extended/overridden by user.
38 # See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
39 my @BUILTIN_SPECIAL_OPS = (
40 {regex => qr/^ (?: not \s )? between $/ix, handler => sub { die "NOPE" }},
41 {regex => qr/^ (?: not \s )? in $/ix, handler => sub { die "NOPE" }},
42 {regex => qr/^ is (?: \s+ not )? $/ix, handler => sub { die "NOPE" }},
45 #======================================================================
46 # DEBUGGING AND ERROR REPORTING
47 #======================================================================
50 return unless $_[0]->{debug}; shift; # a little faster
51 my $func = (caller(1))[3];
52 warn "[$func] ", @_, "\n";
56 my($func) = (caller(1))[3];
57 Carp::carp "[$func] Warning: ", @_;
61 my($func) = (caller(1))[3];
62 Carp::croak "[$func] Fatal: ", @_;
65 sub is_literal_value ($) {
66 ref $_[0] eq 'SCALAR' ? [ ${$_[0]} ]
67 : ( ref $_[0] eq 'REF' and ref ${$_[0]} eq 'ARRAY' ) ? [ @${ $_[0] } ]
71 # FIXME XSify - this can be done so much more efficiently
72 sub is_plain_value ($) {
74 ! length ref $_[0] ? \($_[0])
76 ref $_[0] eq 'HASH' and keys %{$_[0]} == 1
78 exists $_[0]->{-value}
79 ) ? \($_[0]->{-value})
81 # reuse @_ for even moar speedz
82 defined ( $_[1] = Scalar::Util::blessed $_[0] )
84 # deliberately not using Devel::OverloadInfo - the checks we are
85 # intersted in are much more limited than the fullblown thing, and
86 # this is a very hot piece of code
88 # simply using ->can('(""') can leave behind stub methods that
89 # break actually using the overload later (see L<perldiag/Stub
90 # found while resolving method "%s" overloading "%s" in package
91 # "%s"> and the source of overload::mycan())
93 # either has stringification which DBI SHOULD prefer out of the box
94 grep { *{ (qq[${_}::(""]) }{CODE} } @{ $_[2] = mro::get_linear_isa( $_[1] ) }
96 # has nummification or boolification, AND fallback is *not* disabled
98 SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION
101 grep { *{"${_}::(0+"}{CODE} } @{$_[2]}
103 grep { *{"${_}::(bool"}{CODE} } @{$_[2]}
107 # no fallback specified at all
108 ! ( ($_[3]) = grep { *{"${_}::()"}{CODE} } @{$_[2]} )
110 # fallback explicitly undef
111 ! defined ${"$_[3]::()"}
124 #======================================================================
126 #======================================================================
130 my $class = ref($self) || $self;
131 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
133 # choose our case by keeping an option around
134 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
136 # default logic for interpreting arrayrefs
137 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
139 # how to return bind vars
140 $opt{bindtype} ||= 'normal';
142 # default comparison is "=", but can be overridden
145 # try to recognize which are the 'equality' and 'inequality' ops
146 # (temporary quickfix (in 2007), should go through a more seasoned API)
147 $opt{equality_op} = qr/^( \Q$opt{cmp}\E | \= )$/ix;
148 $opt{inequality_op} = qr/^( != | <> )$/ix;
150 $opt{like_op} = qr/^ (is\s+)? r?like $/xi;
151 $opt{not_like_op} = qr/^ (is\s+)? not \s+ r?like $/xi;
154 $opt{sqltrue} ||= '1=1';
155 $opt{sqlfalse} ||= '0=1';
158 $opt{special_ops} ||= [];
160 # regexes are applied in order, thus push after user-defines
161 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
164 $opt{unary_ops} ||= [];
166 # rudimentary sanity-check for user supplied bits treated as functions/operators
167 # If a purported function matches this regular expression, an exception is thrown.
168 # Literal SQL is *NOT* subject to this check, only functions (and column names
169 # when quoting is not in effect)
172 # need to guard against ()'s in column names too, but this will break tons of
173 # hacks... ideas anyone?
174 $opt{injection_guard} ||= qr/
180 $opt{node_types} = +{
181 map +("-$_" => '_render_'.$_),
182 qw(op func value bind ident literal)
185 $opt{expand_unary} = {};
187 return bless \%opt, $class;
190 sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
191 sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
193 sub _assert_pass_injection_guard {
194 if ($_[1] =~ $_[0]->{injection_guard}) {
195 my $class = ref $_[0];
196 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
197 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
198 . "{injection_guard} attribute to ${class}->new()"
203 #======================================================================
205 #======================================================================
209 my $table = $self->_table(shift);
210 my $data = shift || return;
213 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
214 my ($sql, @bind) = $self->$method($data);
215 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
217 if ($options->{returning}) {
218 my ($s, @b) = $self->_insert_returning($options);
223 return wantarray ? ($sql, @bind) : $sql;
226 # So that subclasses can override INSERT ... RETURNING separately from
227 # UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
228 sub _insert_returning { shift->_returning(@_) }
231 my ($self, $options) = @_;
233 my $f = $options->{returning};
235 my ($sql, @bind) = $self->_render_expr(
236 $self->_expand_maybe_list_expr($f, undef, -ident)
239 ? $self->_sqlcase(' returning ') . $sql
240 : ($self->_sqlcase(' returning ').$sql, @bind);
243 sub _insert_HASHREF { # explicit list of fields and then values
244 my ($self, $data) = @_;
246 my @fields = sort keys %$data;
248 my ($sql, @bind) = $self->_insert_values($data);
251 $_ = $self->_quote($_) foreach @fields;
252 $sql = "( ".join(", ", @fields).") ".$sql;
254 return ($sql, @bind);
257 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
258 my ($self, $data) = @_;
260 # no names (arrayref) so can't generate bindtype
261 $self->{bindtype} ne 'columns'
262 or belch "can't do 'columns' bindtype when called with arrayref";
264 my (@values, @all_bind);
265 foreach my $value (@$data) {
266 my ($values, @bind) = $self->_insert_value(undef, $value);
267 push @values, $values;
268 push @all_bind, @bind;
270 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
271 return ($sql, @all_bind);
274 sub _insert_ARRAYREFREF { # literal SQL with bind
275 my ($self, $data) = @_;
277 my ($sql, @bind) = @${$data};
278 $self->_assert_bindval_matches_bindtype(@bind);
280 return ($sql, @bind);
284 sub _insert_SCALARREF { # literal SQL without bind
285 my ($self, $data) = @_;
291 my ($self, $data) = @_;
293 my (@values, @all_bind);
294 foreach my $column (sort keys %$data) {
295 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
296 push @values, $values;
297 push @all_bind, @bind;
299 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
300 return ($sql, @all_bind);
304 my ($self, $column, $v) = @_;
306 return $self->_render_expr(
307 $self->_expand_insert_value($column, $v)
311 sub _expand_insert_value {
312 my ($self, $column, $v) = @_;
314 if (ref($v) eq 'ARRAY') {
315 if ($self->{array_datatypes}) {
316 return +{ -bind => [ $column, $v ] };
318 my ($sql, @bind) = @$v;
319 $self->_assert_bindval_matches_bindtype(@bind);
320 return +{ -literal => $v };
322 if (ref($v) eq 'HASH') {
323 if (grep !/^-/, keys %$v) {
324 belch "HASH ref as bind value in insert is not supported";
325 return +{ -bind => [ $column, $v ] };
329 return +{ -bind => [ $column, undef ] };
331 local our $Cur_Col_Meta = $column;
332 return $self->_expand_expr($v);
337 #======================================================================
339 #======================================================================
344 my $table = $self->_table(shift);
345 my $data = shift || return;
349 # first build the 'SET' part of the sql statement
350 puke "Unsupported data type specified to \$sql->update"
351 unless ref $data eq 'HASH';
353 my ($sql, @all_bind) = $self->_update_set_values($data);
354 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
358 my($where_sql, @where_bind) = $self->where($where);
360 push @all_bind, @where_bind;
363 if ($options->{returning}) {
364 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
365 $sql .= $returning_sql;
366 push @all_bind, @returning_bind;
369 return wantarray ? ($sql, @all_bind) : $sql;
372 sub _update_set_values {
373 my ($self, $data) = @_;
375 return $self->_render_expr(
376 $self->_expand_update_set_values($data),
380 sub _expand_update_set_values {
381 my ($self, $data) = @_;
382 $self->_expand_maybe_list_expr( [
385 +{ -op => [ '=', { -ident => $k }, $set ] };
391 ? ($self->{array_datatypes}
392 ? [ $k, +{ -bind => [ $k, $v ] } ]
393 : [ $k, +{ -literal => $v } ])
395 local our $Cur_Col_Meta = $k;
396 [ $k, $self->_expand_expr($v) ]
403 # So that subclasses can override UPDATE ... RETURNING separately from
405 sub _update_returning { shift->_returning(@_) }
409 #======================================================================
411 #======================================================================
416 my $table = $self->_table(shift);
417 my $fields = shift || '*';
421 my ($fields_sql, @bind) = $self->_select_fields($fields);
423 my ($where_sql, @where_bind) = $self->where($where, $order);
424 push @bind, @where_bind;
426 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
427 $self->_sqlcase('from'), $table)
430 return wantarray ? ($sql, @bind) : $sql;
434 my ($self, $fields) = @_;
435 return $self->_render_expr(
436 $self->_expand_maybe_list_expr($fields, undef, '-ident')
440 #======================================================================
442 #======================================================================
447 my $table = $self->_table(shift);
451 my($where_sql, @bind) = $self->where($where);
452 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
454 if ($options->{returning}) {
455 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
456 $sql .= $returning_sql;
457 push @bind, @returning_bind;
460 return wantarray ? ($sql, @bind) : $sql;
463 # So that subclasses can override DELETE ... RETURNING separately from
465 sub _delete_returning { shift->_returning(@_) }
469 #======================================================================
471 #======================================================================
475 # Finally, a separate routine just to handle WHERE clauses
477 my ($self, $where, $order) = @_;
479 local $self->{convert_where} = $self->{convert};
482 my ($sql, @bind) = defined($where)
483 ? $self->_recurse_where($where)
485 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
489 my ($order_sql, @order_bind) = $self->_order_by($order);
491 push @bind, @order_bind;
494 return wantarray ? ($sql, @bind) : $sql;
498 my ($self, $expr, $logic, $default_scalar_to) = @_;
499 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
500 return undef unless defined($expr);
501 if (ref($expr) eq 'HASH') {
502 if (keys %$expr > 1) {
506 map $self->_expand_expr_hashpair($_ => $expr->{$_}, $logic),
510 return unless %$expr;
511 return $self->_expand_expr_hashpair(%$expr, $logic);
513 if (ref($expr) eq 'ARRAY') {
514 my $logic = lc($logic || $self->{logic});
515 $logic eq 'and' or $logic eq 'or' or puke "unknown logic: $logic";
521 while (my ($el) = splice @expr, 0, 1) {
522 puke "Supplying an empty left hand side argument is not supported in array-pairs"
523 unless defined($el) and length($el);
524 my $elref = ref($el);
526 push(@res, $self->_expand_expr({ $el, shift(@expr) }));
527 } elsif ($elref eq 'ARRAY') {
528 push(@res, $self->_expand_expr($el)) if @$el;
529 } elsif (my $l = is_literal_value($el)) {
530 push @res, { -literal => $l };
531 } elsif ($elref eq 'HASH') {
532 push @res, $self->_expand_expr($el);
537 return { -op => [ $logic, @res ] };
539 if (my $literal = is_literal_value($expr)) {
540 return +{ -literal => $literal };
542 if (!ref($expr) or Scalar::Util::blessed($expr)) {
543 if (my $d = $Default_Scalar_To) {
544 return +{ $d => $expr };
546 if (my $m = our $Cur_Col_Meta) {
547 return +{ -bind => [ $m, $expr ] };
549 return +{ -value => $expr };
554 sub _expand_expr_hashpair {
555 my ($self, $k, $v, $logic) = @_;
556 unless (defined($k) and length($k)) {
557 if (defined($k) and my $literal = is_literal_value($v)) {
558 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
559 return { -literal => $literal };
561 puke "Supplying an empty left hand side argument is not supported";
564 $self->_assert_pass_injection_guard($k =~ /^-(.*)$/s);
565 if ($k =~ s/ [_\s]? \d+ $//x ) {
566 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
567 . "You probably wanted ...-and => [ $k => COND1, $k => COND2 ... ]";
570 return $self->_expand_expr($v);
574 return $self->_expand_expr($v);
576 puke "-bool => undef not supported" unless defined($v);
577 return { -ident => $v };
580 return { -op => [ 'not', $self->_expand_expr($v) ] };
582 if (my ($rest) = $k =~/^-not[_ ](.*)$/) {
585 $self->_expand_expr_hashpair("-${rest}", $v, $logic)
588 if (my ($logic) = $k =~ /^-(and|or)$/i) {
589 if (ref($v) eq 'HASH') {
590 return $self->_expand_expr($v, $logic);
592 if (ref($v) eq 'ARRAY') {
593 return $self->_expand_expr($v, $logic);
598 $op =~ s/^-// if length($op) > 1;
600 # top level special ops are illegal in general
601 puke "Illegal use of top-level '-$op'"
602 if List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
603 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
604 return { -op => [ $op, $v ] };
607 if ($k eq '-value' and my $m = our $Cur_Col_Meta) {
608 return +{ -bind => [ $m, $v ] };
610 if (my $custom = $self->{expand_unary}{$k}) {
611 return $self->$custom($v);
613 if ($self->{node_types}{$k}) {
619 and (keys %$v)[0] =~ /^-/
621 my ($func) = $k =~ /^-(.*)$/;
622 return +{ -func => [ $func, $self->_expand_expr($v) ] };
624 if (!ref($v) or is_literal_value($v)) {
625 return +{ -op => [ $k =~ /^-(.*)$/, $self->_expand_expr($v) ] };
632 and exists $v->{-value}
633 and not defined $v->{-value}
636 return $self->_expand_expr_hashpair($k => { $self->{cmp} => undef });
638 if (!ref($v) or Scalar::Util::blessed($v)) {
639 my $d = our $Default_Scalar_To;
644 ($d ? { $d => $v } : { -bind => [ $k, $v ] })
648 if (ref($v) eq 'HASH') {
652 map $self->_expand_expr_hashpair($k => { $_ => $v->{$_} }),
659 $self->_assert_pass_injection_guard($vk);
660 if ($vk =~ s/ [_\s]? \d+ $//x ) {
661 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
662 . "You probably wanted ...-and => [ -$vk => COND1, -$vk => COND2 ... ]";
664 if ($vk =~ /^(?:not[ _])?between$/) {
665 local our $Cur_Col_Meta = $k;
666 my @rhs = map $self->_expand_expr($_),
667 ref($vv) eq 'ARRAY' ? @$vv : $vv;
669 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
671 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
673 puke "Operator '${\uc($vk)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
676 join(' ', split '_', $vk),
681 if ($vk =~ /^(?:not[ _])?in$/) {
682 if (my $literal = is_literal_value($vv)) {
683 my ($sql, @bind) = @$literal;
684 my $opened_sql = $self->_open_outer_paren($sql);
686 $vk, { -ident => $k },
687 [ { -literal => [ $opened_sql, @bind ] } ]
691 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
692 . "-${\uc($vk)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
693 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
694 . 'will emit the logically correct SQL instead of raising this exception)'
696 puke("Argument passed to the '${\uc($vk)}' operator can not be undefined")
698 my @rhs = map $self->_expand_expr($_),
699 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
700 map { defined($_) ? $_: puke($undef_err) }
701 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
702 return $self->${\($vk =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
705 join(' ', split '_', $vk),
710 if ($vk eq 'ident') {
711 if (! defined $vv or (ref($vv) and ref($vv) eq 'ARRAY')) {
712 puke "-$vk requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
720 if ($vk eq 'value') {
721 return $self->_expand_expr_hashpair($k, undef) unless defined($vv);
725 { -bind => [ $k, $vv ] }
728 if ($vk =~ /^is(?:[ _]not)?$/) {
729 puke "$vk can only take undef as argument"
733 and exists($vv->{-value})
734 and !defined($vv->{-value})
737 return +{ -op => [ $vk.' null', { -ident => $k } ] };
739 if ($vk =~ /^(and|or)$/) {
740 if (ref($vv) eq 'HASH') {
743 map $self->_expand_expr_hashpair($k, { $_ => $vv->{$_} }),
748 if (my $us = List::Util::first { $vk =~ $_->{regex} } @{$self->{special_ops}}) {
749 return { -op => [ $vk, { -ident => $k }, $vv ] };
751 if (my $us = List::Util::first { $vk =~ $_->{regex} } @{$self->{unary_ops}}) {
755 { -op => [ $vk, $vv ] }
758 if (ref($vv) eq 'ARRAY') {
759 my ($logic, @values) = (
760 (defined($vv->[0]) and $vv->[0] =~ /^-(and|or)$/i)
765 $vk =~ $self->{inequality_op}
766 or join(' ', split '_', $vk) =~ $self->{not_like_op}
768 if (lc($logic) eq '-or' and @values > 1) {
769 my $op = uc join ' ', split '_', $vk;
770 belch "A multi-element arrayref as an argument to the inequality op '$op' "
771 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
772 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
777 # try to DWIM on equality operators
778 my $op = join ' ', split '_', $vk;
780 $op =~ $self->{equality_op} ? $self->sqlfalse
781 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
782 : $op =~ $self->{inequality_op} ? $self->sqltrue
783 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
784 : puke "operator '$op' applied on an empty array (field '$k')";
788 map $self->_expand_expr_hashpair($k => { $vk => $_ }),
796 and exists $vv->{-value}
797 and not defined $vv->{-value}
800 my $op = join ' ', split '_', $vk;
802 $op =~ /^not$/i ? 'is not' # legacy
803 : $op =~ $self->{equality_op} ? 'is'
804 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
805 : $op =~ $self->{inequality_op} ? 'is not'
806 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
807 : puke "unexpected operator '$op' with undef operand";
808 return +{ -op => [ $is.' null', { -ident => $k } ] };
810 local our $Cur_Col_Meta = $k;
814 $self->_expand_expr($vv)
817 if (ref($v) eq 'ARRAY') {
818 return $self->sqlfalse unless @$v;
819 $self->_debug("ARRAY($k) means distribute over elements");
821 $v->[0] =~ /^-((?:and|or))$/i
822 ? ($v = [ @{$v}[1..$#$v] ], $1)
823 : ($self->{logic} || 'or')
827 map $self->_expand_expr({ $k => $_ }, $this_logic), @$v
830 if (my $literal = is_literal_value($v)) {
832 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
835 my ($sql, @bind) = @$literal;
836 if ($self->{bindtype} eq 'columns') {
838 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
839 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
843 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
849 my ($self, $expr) = @_;
850 my ($k, $v, @rest) = %$expr;
852 if (my $meth = $self->{node_types}{$k}) {
853 return $self->$meth($v);
855 die "notreached: $k";
859 my ($self, $where, $logic) = @_;
861 #print STDERR Data::Dumper::Concise::Dumper([ $where, $logic ]);
863 my $where_exp = $self->_expand_expr($where, $logic);
865 #print STDERR Data::Dumper::Concise::Dumper([ EXP => $where_exp ]);
867 # dispatch on appropriate method according to refkind of $where
868 # my $method = $self->_METHOD_FOR_refkind("_where", $where_exp);
870 # my ($sql, @bind) = $self->$method($where_exp, $logic);
872 my ($sql, @bind) = defined($where_exp) ? $self->_render_expr($where_exp) : (undef);
874 # DBIx::Class used to call _recurse_where in scalar context
875 # something else might too...
877 return ($sql, @bind);
880 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
886 my ($self, $ident) = @_;
888 return $self->_convert($self->_quote($ident));
892 my ($self, $value) = @_;
894 return ($self->_convert('?'), $self->_bindtype(undef, $value));
897 my %unop_postfix = map +($_ => 1),
898 'is null', 'is not null',
906 my ($self, $args) = @_;
907 my ($left, $low, $high) = @$args;
908 my ($rhsql, @rhbind) = do {
910 puke "Single arg to between must be a literal"
911 unless $low->{-literal};
914 my ($l, $h) = map [ $self->_render_expr($_) ], $low, $high;
915 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
916 @{$l}[1..$#$l], @{$h}[1..$#$h])
919 my ($lhsql, @lhbind) = $self->_render_expr($left);
921 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
925 }), 'between', 'not between'),
929 my ($self, $args) = @_;
930 my ($lhs, $rhs) = @$args;
933 my ($sql, @bind) = $self->_render_expr($_);
934 push @in_bind, @bind;
937 my ($lhsql, @lbind) = $self->_render_expr($lhs);
939 $lhsql.' '.$self->_sqlcase($op).' ( '
950 my ($op, @args) = @$v;
951 $op =~ s/^-// if length($op) > 1;
953 if (my $h = $special{$op}) {
954 return $self->$h(\@args);
956 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
957 puke "Special op '${op}' requires first value to be identifier"
958 unless my ($k) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
959 return $self->${\($us->{handler})}($k, $op, $args[1]);
961 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
962 return $self->${\($us->{handler})}($op, $args[0]);
964 my $final_op = $op =~ /^(?:is|not)_/ ? join(' ', split '_', $op) : $op;
965 if (@args == 1 and $op !~ /^(and|or)$/) {
966 my ($expr_sql, @bind) = $self->_render_expr($args[0]);
967 my $op_sql = $self->_sqlcase($final_op);
969 $unop_postfix{lc($final_op)}
970 ? "${expr_sql} ${op_sql}"
971 : "${op_sql} ${expr_sql}"
973 return (($op eq 'not' ? '('.$final_sql.')' : $final_sql), @bind);
975 my @parts = map [ $self->_render_expr($_) ], @args;
976 my ($final_sql) = map +($op =~ /^(and|or)$/ ? "(${_})" : $_), join(
977 ($final_op eq ',' ? '' : ' ').$self->_sqlcase($final_op).' ',
982 map @{$_}[1..$#$_], @parts
989 my ($self, $rest) = @_;
990 my ($func, @args) = @$rest;
994 push @arg_sql, shift @x;
996 } map [ $self->_render_expr($_) ], @args;
997 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1001 my ($self, $bind) = @_;
1002 return ($self->_convert('?'), $self->_bindtype(@$bind));
1005 sub _render_literal {
1006 my ($self, $literal) = @_;
1007 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1011 # Some databases (SQLite) treat col IN (1, 2) different from
1012 # col IN ( (1, 2) ). Use this to strip all outer parens while
1013 # adding them back in the corresponding method
1014 sub _open_outer_paren {
1015 my ($self, $sql) = @_;
1017 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1019 # there are closing parens inside, need the heavy duty machinery
1020 # to reevaluate the extraction starting from $sql (full reevaluation)
1021 if ($inner =~ /\)/) {
1022 require Text::Balanced;
1024 my (undef, $remainder) = do {
1025 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1027 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1030 # the entire expression needs to be a balanced bracketed thing
1031 # (after an extract no remainder sans trailing space)
1032 last if defined $remainder and $remainder =~ /\S/;
1042 #======================================================================
1044 #======================================================================
1047 my ($self, $arg) = @_;
1049 return '' unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
1051 my $expander = sub {
1052 my ($self, $dir, $expr) = @_;
1053 my @exp = map +(defined($dir) ? { -op => [ $dir => $_ ] } : $_),
1054 map $self->_expand_expr($_, undef, -ident),
1055 ref($expr) eq 'ARRAY' ? @$expr : $expr;
1056 return (@exp > 1 ? { -op => [ ',', @exp ] } : $exp[0]);
1059 local @{$self->{expand_unary}}{qw(-asc -desc)} = (
1060 sub { shift->$expander(asc => @_) },
1061 sub { shift->$expander(desc => @_) },
1064 my $expanded = $self->$expander(undef, $arg);
1066 my ($sql, @bind) = $self->_render_expr($expanded);
1068 my $final_sql = $self->_sqlcase(' order by ').$sql;
1070 return wantarray ? ($final_sql, @bind) : $final_sql;
1073 #======================================================================
1074 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1075 #======================================================================
1080 ($self->_render_expr(
1081 $self->_expand_maybe_list_expr($from, undef, -ident)
1086 #======================================================================
1088 #======================================================================
1090 sub _expand_maybe_list_expr {
1091 my ($self, $expr, $logic, $default) = @_;
1093 if (ref($expr) eq 'ARRAY') {
1095 ',', map $self->_expand_expr($_, $logic, $default), @$expr
1102 return $self->_expand_expr($e, $logic, $default);
1105 # highly optimized, as it's called way too often
1107 # my ($self, $label) = @_;
1109 return '' unless defined $_[1];
1110 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1111 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
1113 unless ($_[0]->{quote_char}) {
1114 if (ref($_[1]) eq 'ARRAY') {
1115 return join($_[0]->{name_sep}||'.', @{$_[1]});
1117 $_[0]->_assert_pass_injection_guard($_[1]);
1122 my $qref = ref $_[0]->{quote_char};
1124 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1125 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1126 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1128 my $esc = $_[0]->{escape_char} || $r;
1130 # parts containing * are naturally unquoted
1132 $_[0]->{name_sep}||'',
1136 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1138 (ref($_[1]) eq 'ARRAY'
1142 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1150 # Conversion, if applicable
1152 #my ($self, $arg) = @_;
1153 if ($_[0]->{convert_where}) {
1154 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
1161 #my ($self, $col, @vals) = @_;
1162 # called often - tighten code
1163 return $_[0]->{bindtype} eq 'columns'
1164 ? map {[$_[1], $_]} @_[2 .. $#_]
1169 # Dies if any element of @bind is not in [colname => value] format
1170 # if bindtype is 'columns'.
1171 sub _assert_bindval_matches_bindtype {
1172 # my ($self, @bind) = @_;
1174 if ($self->{bindtype} eq 'columns') {
1176 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1177 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1183 sub _join_sql_clauses {
1184 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1186 if (@$clauses_aref > 1) {
1187 my $join = " " . $self->_sqlcase($logic) . " ";
1188 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1189 return ($sql, @$bind_aref);
1191 elsif (@$clauses_aref) {
1192 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1195 return (); # if no SQL, ignore @$bind_aref
1200 # Fix SQL case, if so requested
1202 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1203 # don't touch the argument ... crooked logic, but let's not change it!
1204 return $_[0]->{case} ? $_[1] : uc($_[1]);
1208 #======================================================================
1209 # DISPATCHING FROM REFKIND
1210 #======================================================================
1213 my ($self, $data) = @_;
1215 return 'UNDEF' unless defined $data;
1217 # blessed objects are treated like scalars
1218 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1220 return 'SCALAR' unless $ref;
1223 while ($ref eq 'REF') {
1225 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1229 return ($ref||'SCALAR') . ('REF' x $n_steps);
1233 my ($self, $data) = @_;
1234 my @try = ($self->_refkind($data));
1235 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1236 push @try, 'FALLBACK';
1240 sub _METHOD_FOR_refkind {
1241 my ($self, $meth_prefix, $data) = @_;
1244 for (@{$self->_try_refkind($data)}) {
1245 $method = $self->can($meth_prefix."_".$_)
1249 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1253 sub _SWITCH_refkind {
1254 my ($self, $data, $dispatch_table) = @_;
1257 for (@{$self->_try_refkind($data)}) {
1258 $coderef = $dispatch_table->{$_}
1262 puke "no dispatch entry for ".$self->_refkind($data)
1271 #======================================================================
1272 # VALUES, GENERATE, AUTOLOAD
1273 #======================================================================
1275 # LDNOTE: original code from nwiger, didn't touch code in that section
1276 # I feel the AUTOLOAD stuff should not be the default, it should
1277 # only be activated on explicit demand by user.
1281 my $data = shift || return;
1282 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1283 unless ref $data eq 'HASH';
1286 foreach my $k (sort keys %$data) {
1287 my $v = $data->{$k};
1288 $self->_SWITCH_refkind($v, {
1290 if ($self->{array_datatypes}) { # array datatype
1291 push @all_bind, $self->_bindtype($k, $v);
1293 else { # literal SQL with bind
1294 my ($sql, @bind) = @$v;
1295 $self->_assert_bindval_matches_bindtype(@bind);
1296 push @all_bind, @bind;
1299 ARRAYREFREF => sub { # literal SQL with bind
1300 my ($sql, @bind) = @${$v};
1301 $self->_assert_bindval_matches_bindtype(@bind);
1302 push @all_bind, @bind;
1304 SCALARREF => sub { # literal SQL without bind
1306 SCALAR_or_UNDEF => sub {
1307 push @all_bind, $self->_bindtype($k, $v);
1318 my(@sql, @sqlq, @sqlv);
1322 if ($ref eq 'HASH') {
1323 for my $k (sort keys %$_) {
1326 my $label = $self->_quote($k);
1327 if ($r eq 'ARRAY') {
1328 # literal SQL with bind
1329 my ($sql, @bind) = @$v;
1330 $self->_assert_bindval_matches_bindtype(@bind);
1331 push @sqlq, "$label = $sql";
1333 } elsif ($r eq 'SCALAR') {
1334 # literal SQL without bind
1335 push @sqlq, "$label = $$v";
1337 push @sqlq, "$label = ?";
1338 push @sqlv, $self->_bindtype($k, $v);
1341 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1342 } elsif ($ref eq 'ARRAY') {
1343 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1346 if ($r eq 'ARRAY') { # literal SQL with bind
1347 my ($sql, @bind) = @$v;
1348 $self->_assert_bindval_matches_bindtype(@bind);
1351 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1352 # embedded literal SQL
1359 push @sql, '(' . join(', ', @sqlq) . ')';
1360 } elsif ($ref eq 'SCALAR') {
1364 # strings get case twiddled
1365 push @sql, $self->_sqlcase($_);
1369 my $sql = join ' ', @sql;
1371 # this is pretty tricky
1372 # if ask for an array, return ($stmt, @bind)
1373 # otherwise, s/?/shift @sqlv/ to put it inline
1375 return ($sql, @sqlv);
1377 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1378 ref $d ? $d->[1] : $d/e;
1387 # This allows us to check for a local, then _form, attr
1389 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1390 return $self->generate($name, @_);
1401 SQL::Abstract - Generate SQL from Perl data structures
1407 my $sql = SQL::Abstract->new;
1409 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1411 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1413 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1415 my($stmt, @bind) = $sql->delete($table, \%where);
1417 # Then, use these in your DBI statements
1418 my $sth = $dbh->prepare($stmt);
1419 $sth->execute(@bind);
1421 # Just generate the WHERE clause
1422 my($stmt, @bind) = $sql->where(\%where, $order);
1424 # Return values in the same order, for hashed queries
1425 # See PERFORMANCE section for more details
1426 my @bind = $sql->values(\%fieldvals);
1430 This module was inspired by the excellent L<DBIx::Abstract>.
1431 However, in using that module I found that what I really wanted
1432 to do was generate SQL, but still retain complete control over my
1433 statement handles and use the DBI interface. So, I set out to
1434 create an abstract SQL generation module.
1436 While based on the concepts used by L<DBIx::Abstract>, there are
1437 several important differences, especially when it comes to WHERE
1438 clauses. I have modified the concepts used to make the SQL easier
1439 to generate from Perl data structures and, IMO, more intuitive.
1440 The underlying idea is for this module to do what you mean, based
1441 on the data structures you provide it. The big advantage is that
1442 you don't have to modify your code every time your data changes,
1443 as this module figures it out.
1445 To begin with, an SQL INSERT is as easy as just specifying a hash
1446 of C<key=value> pairs:
1449 name => 'Jimbo Bobson',
1450 phone => '123-456-7890',
1451 address => '42 Sister Lane',
1452 city => 'St. Louis',
1453 state => 'Louisiana',
1456 The SQL can then be generated with this:
1458 my($stmt, @bind) = $sql->insert('people', \%data);
1460 Which would give you something like this:
1462 $stmt = "INSERT INTO people
1463 (address, city, name, phone, state)
1464 VALUES (?, ?, ?, ?, ?)";
1465 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1466 '123-456-7890', 'Louisiana');
1468 These are then used directly in your DBI code:
1470 my $sth = $dbh->prepare($stmt);
1471 $sth->execute(@bind);
1473 =head2 Inserting and Updating Arrays
1475 If your database has array types (like for example Postgres),
1476 activate the special option C<< array_datatypes => 1 >>
1477 when creating the C<SQL::Abstract> object.
1478 Then you may use an arrayref to insert and update database array types:
1480 my $sql = SQL::Abstract->new(array_datatypes => 1);
1482 planets => [qw/Mercury Venus Earth Mars/]
1485 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1489 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1491 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1494 =head2 Inserting and Updating SQL
1496 In order to apply SQL functions to elements of your C<%data> you may
1497 specify a reference to an arrayref for the given hash value. For example,
1498 if you need to execute the Oracle C<to_date> function on a value, you can
1499 say something like this:
1503 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1506 The first value in the array is the actual SQL. Any other values are
1507 optional and would be included in the bind values array. This gives
1510 my($stmt, @bind) = $sql->insert('people', \%data);
1512 $stmt = "INSERT INTO people (name, date_entered)
1513 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1514 @bind = ('Bill', '03/02/2003');
1516 An UPDATE is just as easy, all you change is the name of the function:
1518 my($stmt, @bind) = $sql->update('people', \%data);
1520 Notice that your C<%data> isn't touched; the module will generate
1521 the appropriately quirky SQL for you automatically. Usually you'll
1522 want to specify a WHERE clause for your UPDATE, though, which is
1523 where handling C<%where> hashes comes in handy...
1525 =head2 Complex where statements
1527 This module can generate pretty complicated WHERE statements
1528 easily. For example, simple C<key=value> pairs are taken to mean
1529 equality, and if you want to see if a field is within a set
1530 of values, you can use an arrayref. Let's say we wanted to
1531 SELECT some data based on this criteria:
1534 requestor => 'inna',
1535 worker => ['nwiger', 'rcwe', 'sfz'],
1536 status => { '!=', 'completed' }
1539 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1541 The above would give you something like this:
1543 $stmt = "SELECT * FROM tickets WHERE
1544 ( requestor = ? ) AND ( status != ? )
1545 AND ( worker = ? OR worker = ? OR worker = ? )";
1546 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1548 Which you could then use in DBI code like so:
1550 my $sth = $dbh->prepare($stmt);
1551 $sth->execute(@bind);
1557 The methods are simple. There's one for every major SQL operation,
1558 and a constructor you use first. The arguments are specified in a
1559 similar order for each method (table, then fields, then a where
1560 clause) to try and simplify things.
1562 =head2 new(option => 'value')
1564 The C<new()> function takes a list of options and values, and returns
1565 a new B<SQL::Abstract> object which can then be used to generate SQL
1566 through the methods below. The options accepted are:
1572 If set to 'lower', then SQL will be generated in all lowercase. By
1573 default SQL is generated in "textbook" case meaning something like:
1575 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1577 Any setting other than 'lower' is ignored.
1581 This determines what the default comparison operator is. By default
1582 it is C<=>, meaning that a hash like this:
1584 %where = (name => 'nwiger', email => 'nate@wiger.org');
1586 Will generate SQL like this:
1588 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1590 However, you may want loose comparisons by default, so if you set
1591 C<cmp> to C<like> you would get SQL such as:
1593 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1595 You can also override the comparison on an individual basis - see
1596 the huge section on L</"WHERE CLAUSES"> at the bottom.
1598 =item sqltrue, sqlfalse
1600 Expressions for inserting boolean values within SQL statements.
1601 By default these are C<1=1> and C<1=0>. They are used
1602 by the special operators C<-in> and C<-not_in> for generating
1603 correct SQL even when the argument is an empty array (see below).
1607 This determines the default logical operator for multiple WHERE
1608 statements in arrays or hashes. If absent, the default logic is "or"
1609 for arrays, and "and" for hashes. This means that a WHERE
1613 event_date => {'>=', '2/13/99'},
1614 event_date => {'<=', '4/24/03'},
1617 will generate SQL like this:
1619 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1621 This is probably not what you want given this query, though (look
1622 at the dates). To change the "OR" to an "AND", simply specify:
1624 my $sql = SQL::Abstract->new(logic => 'and');
1626 Which will change the above C<WHERE> to:
1628 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1630 The logic can also be changed locally by inserting
1631 a modifier in front of an arrayref:
1633 @where = (-and => [event_date => {'>=', '2/13/99'},
1634 event_date => {'<=', '4/24/03'} ]);
1636 See the L</"WHERE CLAUSES"> section for explanations.
1640 This will automatically convert comparisons using the specified SQL
1641 function for both column and value. This is mostly used with an argument
1642 of C<upper> or C<lower>, so that the SQL will have the effect of
1643 case-insensitive "searches". For example, this:
1645 $sql = SQL::Abstract->new(convert => 'upper');
1646 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1648 Will turn out the following SQL:
1650 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1652 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1653 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1654 not validate this option; it will just pass through what you specify verbatim).
1658 This is a kludge because many databases suck. For example, you can't
1659 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1660 Instead, you have to use C<bind_param()>:
1662 $sth->bind_param(1, 'reg data');
1663 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1665 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1666 which loses track of which field each slot refers to. Fear not.
1668 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1669 Currently, you can specify either C<normal> (default) or C<columns>. If you
1670 specify C<columns>, you will get an array that looks like this:
1672 my $sql = SQL::Abstract->new(bindtype => 'columns');
1673 my($stmt, @bind) = $sql->insert(...);
1676 [ 'column1', 'value1' ],
1677 [ 'column2', 'value2' ],
1678 [ 'column3', 'value3' ],
1681 You can then iterate through this manually, using DBI's C<bind_param()>.
1683 $sth->prepare($stmt);
1686 my($col, $data) = @$_;
1687 if ($col eq 'details' || $col eq 'comments') {
1688 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1689 } elsif ($col eq 'image') {
1690 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1692 $sth->bind_param($i, $data);
1696 $sth->execute; # execute without @bind now
1698 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1699 Basically, the advantage is still that you don't have to care which fields
1700 are or are not included. You could wrap that above C<for> loop in a simple
1701 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1702 get a layer of abstraction over manual SQL specification.
1704 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1705 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1706 will expect the bind values in this format.
1710 This is the character that a table or column name will be quoted
1711 with. By default this is an empty string, but you could set it to
1712 the character C<`>, to generate SQL like this:
1714 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1716 Alternatively, you can supply an array ref of two items, the first being the left
1717 hand quote character, and the second the right hand quote character. For
1718 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1719 that generates SQL like this:
1721 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1723 Quoting is useful if you have tables or columns names that are reserved
1724 words in your database's SQL dialect.
1728 This is the character that will be used to escape L</quote_char>s appearing
1729 in an identifier before it has been quoted.
1731 The parameter default in case of a single L</quote_char> character is the quote
1734 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
1735 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
1736 of the B<opening (left)> L</quote_char> within the identifier are currently left
1737 untouched. The default for opening-closing-style quotes may change in future
1738 versions, thus you are B<strongly encouraged> to specify the escape character
1743 This is the character that separates a table and column name. It is
1744 necessary to specify this when the C<quote_char> option is selected,
1745 so that tables and column names can be individually quoted like this:
1747 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1749 =item injection_guard
1751 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1752 column name specified in a query structure. This is a safety mechanism to avoid
1753 injection attacks when mishandling user input e.g.:
1755 my %condition_as_column_value_pairs = get_values_from_user();
1756 $sqla->select( ... , \%condition_as_column_value_pairs );
1758 If the expression matches an exception is thrown. Note that literal SQL
1759 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1761 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1763 =item array_datatypes
1765 When this option is true, arrayrefs in INSERT or UPDATE are
1766 interpreted as array datatypes and are passed directly
1768 When this option is false, arrayrefs are interpreted
1769 as literal SQL, just like refs to arrayrefs
1770 (but this behavior is for backwards compatibility; when writing
1771 new queries, use the "reference to arrayref" syntax
1777 Takes a reference to a list of "special operators"
1778 to extend the syntax understood by L<SQL::Abstract>.
1779 See section L</"SPECIAL OPERATORS"> for details.
1783 Takes a reference to a list of "unary operators"
1784 to extend the syntax understood by L<SQL::Abstract>.
1785 See section L</"UNARY OPERATORS"> for details.
1791 =head2 insert($table, \@values || \%fieldvals, \%options)
1793 This is the simplest function. You simply give it a table name
1794 and either an arrayref of values or hashref of field/value pairs.
1795 It returns an SQL INSERT statement and a list of bind values.
1796 See the sections on L</"Inserting and Updating Arrays"> and
1797 L</"Inserting and Updating SQL"> for information on how to insert
1798 with those data types.
1800 The optional C<\%options> hash reference may contain additional
1801 options to generate the insert SQL. Currently supported options
1808 Takes either a scalar of raw SQL fields, or an array reference of
1809 field names, and adds on an SQL C<RETURNING> statement at the end.
1810 This allows you to return data generated by the insert statement
1811 (such as row IDs) without performing another C<SELECT> statement.
1812 Note, however, this is not part of the SQL standard and may not
1813 be supported by all database engines.
1817 =head2 update($table, \%fieldvals, \%where, \%options)
1819 This takes a table, hashref of field/value pairs, and an optional
1820 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1822 See the sections on L</"Inserting and Updating Arrays"> and
1823 L</"Inserting and Updating SQL"> for information on how to insert
1824 with those data types.
1826 The optional C<\%options> hash reference may contain additional
1827 options to generate the update SQL. Currently supported options
1834 See the C<returning> option to
1835 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1839 =head2 select($source, $fields, $where, $order)
1841 This returns a SQL SELECT statement and associated list of bind values, as
1842 specified by the arguments:
1848 Specification of the 'FROM' part of the statement.
1849 The argument can be either a plain scalar (interpreted as a table
1850 name, will be quoted), or an arrayref (interpreted as a list
1851 of table names, joined by commas, quoted), or a scalarref
1852 (literal SQL, not quoted).
1856 Specification of the list of fields to retrieve from
1858 The argument can be either an arrayref (interpreted as a list
1859 of field names, will be joined by commas and quoted), or a
1860 plain scalar (literal SQL, not quoted).
1861 Please observe that this API is not as flexible as that of
1862 the first argument C<$source>, for backwards compatibility reasons.
1866 Optional argument to specify the WHERE part of the query.
1867 The argument is most often a hashref, but can also be
1868 an arrayref or plain scalar --
1869 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1873 Optional argument to specify the ORDER BY part of the query.
1874 The argument can be a scalar, a hashref or an arrayref
1875 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1881 =head2 delete($table, \%where, \%options)
1883 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1884 It returns an SQL DELETE statement and list of bind values.
1886 The optional C<\%options> hash reference may contain additional
1887 options to generate the delete SQL. Currently supported options
1894 See the C<returning> option to
1895 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1899 =head2 where(\%where, $order)
1901 This is used to generate just the WHERE clause. For example,
1902 if you have an arbitrary data structure and know what the
1903 rest of your SQL is going to look like, but want an easy way
1904 to produce a WHERE clause, use this. It returns an SQL WHERE
1905 clause and list of bind values.
1908 =head2 values(\%data)
1910 This just returns the values from the hash C<%data>, in the same
1911 order that would be returned from any of the other above queries.
1912 Using this allows you to markedly speed up your queries if you
1913 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1915 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1917 Warning: This is an experimental method and subject to change.
1919 This returns arbitrarily generated SQL. It's a really basic shortcut.
1920 It will return two different things, depending on return context:
1922 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1923 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1925 These would return the following:
1927 # First calling form
1928 $stmt = "CREATE TABLE test (?, ?)";
1929 @bind = (field1, field2);
1931 # Second calling form
1932 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1934 Depending on what you're trying to do, it's up to you to choose the correct
1935 format. In this example, the second form is what you would want.
1939 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1943 ALTER SESSION SET nls_date_format = 'MM/YY'
1945 You get the idea. Strings get their case twiddled, but everything
1946 else remains verbatim.
1948 =head1 EXPORTABLE FUNCTIONS
1950 =head2 is_plain_value
1952 Determines if the supplied argument is a plain value as understood by this
1957 =item * The value is C<undef>
1959 =item * The value is a non-reference
1961 =item * The value is an object with stringification overloading
1963 =item * The value is of the form C<< { -value => $anything } >>
1967 On failure returns C<undef>, on success returns a B<scalar> reference
1968 to the original supplied argument.
1974 The stringification overloading detection is rather advanced: it takes
1975 into consideration not only the presence of a C<""> overload, but if that
1976 fails also checks for enabled
1977 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
1978 on either C<0+> or C<bool>.
1980 Unfortunately testing in the field indicates that this
1981 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
1982 but only when very large numbers of stringifying objects are involved.
1983 At the time of writing ( Sep 2014 ) there is no clear explanation of
1984 the direct cause, nor is there a manageably small test case that reliably
1985 reproduces the problem.
1987 If you encounter any of the following exceptions in B<random places within
1988 your application stack> - this module may be to blame:
1990 Operation "ne": no method found,
1991 left argument in overloaded package <something>,
1992 right argument in overloaded package <something>
1996 Stub found while resolving method "???" overloading """" in package <something>
1998 If you fall victim to the above - please attempt to reduce the problem
1999 to something that could be sent to the L<SQL::Abstract developers
2000 |DBIx::Class/GETTING HELP/SUPPORT>
2001 (either publicly or privately). As a workaround in the meantime you can
2002 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2003 value, which will most likely eliminate your problem (at the expense of
2004 not being able to properly detect exotic forms of stringification).
2006 This notice and environment variable will be removed in a future version,
2007 as soon as the underlying problem is found and a reliable workaround is
2012 =head2 is_literal_value
2014 Determines if the supplied argument is a literal value as understood by this
2019 =item * C<\$sql_string>
2021 =item * C<\[ $sql_string, @bind_values ]>
2025 On failure returns C<undef>, on success returns an B<array> reference
2026 containing the unpacked version of the supplied literal SQL and bind values.
2028 =head1 WHERE CLAUSES
2032 This module uses a variation on the idea from L<DBIx::Abstract>. It
2033 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2034 module is that things in arrays are OR'ed, and things in hashes
2037 The easiest way to explain is to show lots of examples. After
2038 each C<%where> hash shown, it is assumed you used:
2040 my($stmt, @bind) = $sql->where(\%where);
2042 However, note that the C<%where> hash can be used directly in any
2043 of the other functions as well, as described above.
2045 =head2 Key-value pairs
2047 So, let's get started. To begin, a simple hash:
2051 status => 'completed'
2054 Is converted to SQL C<key = val> statements:
2056 $stmt = "WHERE user = ? AND status = ?";
2057 @bind = ('nwiger', 'completed');
2059 One common thing I end up doing is having a list of values that
2060 a field can be in. To do this, simply specify a list inside of
2065 status => ['assigned', 'in-progress', 'pending'];
2068 This simple code will create the following:
2070 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2071 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2073 A field associated to an empty arrayref will be considered a
2074 logical false and will generate 0=1.
2076 =head2 Tests for NULL values
2078 If the value part is C<undef> then this is converted to SQL <IS NULL>
2087 $stmt = "WHERE user = ? AND status IS NULL";
2090 To test if a column IS NOT NULL:
2094 status => { '!=', undef },
2097 =head2 Specific comparison operators
2099 If you want to specify a different type of operator for your comparison,
2100 you can use a hashref for a given column:
2104 status => { '!=', 'completed' }
2107 Which would generate:
2109 $stmt = "WHERE user = ? AND status != ?";
2110 @bind = ('nwiger', 'completed');
2112 To test against multiple values, just enclose the values in an arrayref:
2114 status => { '=', ['assigned', 'in-progress', 'pending'] };
2116 Which would give you:
2118 "WHERE status = ? OR status = ? OR status = ?"
2121 The hashref can also contain multiple pairs, in which case it is expanded
2122 into an C<AND> of its elements:
2126 status => { '!=', 'completed', -not_like => 'pending%' }
2129 # Or more dynamically, like from a form
2130 $where{user} = 'nwiger';
2131 $where{status}{'!='} = 'completed';
2132 $where{status}{'-not_like'} = 'pending%';
2134 # Both generate this
2135 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2136 @bind = ('nwiger', 'completed', 'pending%');
2139 To get an OR instead, you can combine it with the arrayref idea:
2143 priority => [ { '=', 2 }, { '>', 5 } ]
2146 Which would generate:
2148 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2149 @bind = ('2', '5', 'nwiger');
2151 If you want to include literal SQL (with or without bind values), just use a
2152 scalar reference or reference to an arrayref as the value:
2155 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2156 date_expires => { '<' => \"now()" }
2159 Which would generate:
2161 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2162 @bind = ('11/26/2008');
2165 =head2 Logic and nesting operators
2167 In the example above,
2168 there is a subtle trap if you want to say something like
2169 this (notice the C<AND>):
2171 WHERE priority != ? AND priority != ?
2173 Because, in Perl you I<can't> do this:
2175 priority => { '!=' => 2, '!=' => 1 }
2177 As the second C<!=> key will obliterate the first. The solution
2178 is to use the special C<-modifier> form inside an arrayref:
2180 priority => [ -and => {'!=', 2},
2184 Normally, these would be joined by C<OR>, but the modifier tells it
2185 to use C<AND> instead. (Hint: You can use this in conjunction with the
2186 C<logic> option to C<new()> in order to change the way your queries
2187 work by default.) B<Important:> Note that the C<-modifier> goes
2188 B<INSIDE> the arrayref, as an extra first element. This will
2189 B<NOT> do what you think it might:
2191 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2193 Here is a quick list of equivalencies, since there is some overlap:
2196 status => {'!=', 'completed', 'not like', 'pending%' }
2197 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2200 status => {'=', ['assigned', 'in-progress']}
2201 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2202 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2206 =head2 Special operators: IN, BETWEEN, etc.
2208 You can also use the hashref format to compare a list of fields using the
2209 C<IN> comparison operator, by specifying the list as an arrayref:
2212 status => 'completed',
2213 reportid => { -in => [567, 2335, 2] }
2216 Which would generate:
2218 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2219 @bind = ('completed', '567', '2335', '2');
2221 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2224 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2225 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2226 'sqltrue' (by default: C<1=1>).
2228 In addition to the array you can supply a chunk of literal sql or
2229 literal sql with bind:
2232 customer => { -in => \[
2233 'SELECT cust_id FROM cust WHERE balance > ?',
2236 status => { -in => \'SELECT status_codes FROM states' },
2242 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2243 AND status IN ( SELECT status_codes FROM states )
2247 Finally, if the argument to C<-in> is not a reference, it will be
2248 treated as a single-element array.
2250 Another pair of operators is C<-between> and C<-not_between>,
2251 used with an arrayref of two values:
2255 completion_date => {
2256 -not_between => ['2002-10-01', '2003-02-06']
2262 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2264 Just like with C<-in> all plausible combinations of literal SQL
2268 start0 => { -between => [ 1, 2 ] },
2269 start1 => { -between => \["? AND ?", 1, 2] },
2270 start2 => { -between => \"lower(x) AND upper(y)" },
2271 start3 => { -between => [
2273 \["upper(?)", 'stuff' ],
2280 ( start0 BETWEEN ? AND ? )
2281 AND ( start1 BETWEEN ? AND ? )
2282 AND ( start2 BETWEEN lower(x) AND upper(y) )
2283 AND ( start3 BETWEEN lower(x) AND upper(?) )
2285 @bind = (1, 2, 1, 2, 'stuff');
2288 These are the two builtin "special operators"; but the
2289 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2291 =head2 Unary operators: bool
2293 If you wish to test against boolean columns or functions within your
2294 database you can use the C<-bool> and C<-not_bool> operators. For
2295 example to test the column C<is_user> being true and the column
2296 C<is_enabled> being false you would use:-
2300 -not_bool => 'is_enabled',
2305 WHERE is_user AND NOT is_enabled
2307 If a more complex combination is required, testing more conditions,
2308 then you should use the and/or operators:-
2313 -not_bool => { two=> { -rlike => 'bar' } },
2314 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2325 (NOT ( three = ? OR three > ? ))
2328 =head2 Nested conditions, -and/-or prefixes
2330 So far, we've seen how multiple conditions are joined with a top-level
2331 C<AND>. We can change this by putting the different conditions we want in
2332 hashes and then putting those hashes in an array. For example:
2337 status => { -like => ['pending%', 'dispatched'] },
2341 status => 'unassigned',
2345 This data structure would create the following:
2347 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2348 OR ( user = ? AND status = ? ) )";
2349 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2352 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2353 to change the logic inside:
2359 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2360 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2367 $stmt = "WHERE ( user = ?
2368 AND ( ( workhrs > ? AND geo = ? )
2369 OR ( workhrs < ? OR geo = ? ) ) )";
2370 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2372 =head3 Algebraic inconsistency, for historical reasons
2374 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2375 operator goes C<outside> of the nested structure; whereas when connecting
2376 several constraints on one column, the C<-and> operator goes
2377 C<inside> the arrayref. Here is an example combining both features:
2380 -and => [a => 1, b => 2],
2381 -or => [c => 3, d => 4],
2382 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2387 WHERE ( ( ( a = ? AND b = ? )
2388 OR ( c = ? OR d = ? )
2389 OR ( e LIKE ? AND e LIKE ? ) ) )
2391 This difference in syntax is unfortunate but must be preserved for
2392 historical reasons. So be careful: the two examples below would
2393 seem algebraically equivalent, but they are not
2396 { -like => 'foo%' },
2397 { -like => '%bar' },
2399 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2402 { col => { -like => 'foo%' } },
2403 { col => { -like => '%bar' } },
2405 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2408 =head2 Literal SQL and value type operators
2410 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2411 side" is a column name and the "right side" is a value (normally rendered as
2412 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2413 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2414 alter this behavior. There are several ways of doing so.
2418 This is a virtual operator that signals the string to its right side is an
2419 identifier (a column name) and not a value. For example to compare two
2420 columns you would write:
2423 priority => { '<', 2 },
2424 requestor => { -ident => 'submitter' },
2429 $stmt = "WHERE priority < ? AND requestor = submitter";
2432 If you are maintaining legacy code you may see a different construct as
2433 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2438 This is a virtual operator that signals that the construct to its right side
2439 is a value to be passed to DBI. This is for example necessary when you want
2440 to write a where clause against an array (for RDBMS that support such
2441 datatypes). For example:
2444 array => { -value => [1, 2, 3] }
2449 $stmt = 'WHERE array = ?';
2450 @bind = ([1, 2, 3]);
2452 Note that if you were to simply say:
2458 the result would probably not be what you wanted:
2460 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2465 Finally, sometimes only literal SQL will do. To include a random snippet
2466 of SQL verbatim, you specify it as a scalar reference. Consider this only
2467 as a last resort. Usually there is a better way. For example:
2470 priority => { '<', 2 },
2471 requestor => { -in => \'(SELECT name FROM hitmen)' },
2476 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2479 Note that in this example, you only get one bind parameter back, since
2480 the verbatim SQL is passed as part of the statement.
2484 Never use untrusted input as a literal SQL argument - this is a massive
2485 security risk (there is no way to check literal snippets for SQL
2486 injections and other nastyness). If you need to deal with untrusted input
2487 use literal SQL with placeholders as described next.
2489 =head3 Literal SQL with placeholders and bind values (subqueries)
2491 If the literal SQL to be inserted has placeholders and bind values,
2492 use a reference to an arrayref (yes this is a double reference --
2493 not so common, but perfectly legal Perl). For example, to find a date
2494 in Postgres you can use something like this:
2497 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2502 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2505 Note that you must pass the bind values in the same format as they are returned
2506 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2507 to C<columns>, you must provide the bind values in the
2508 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2509 scalar value; most commonly the column name, but you can use any scalar value
2510 (including references and blessed references), L<SQL::Abstract> will simply
2511 pass it through intact. So if C<bindtype> is set to C<columns> the above
2512 example will look like:
2515 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2518 Literal SQL is especially useful for nesting parenthesized clauses in the
2519 main SQL query. Here is a first example:
2521 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2525 bar => \["IN ($sub_stmt)" => @sub_bind],
2530 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2531 WHERE c2 < ? AND c3 LIKE ?))";
2532 @bind = (1234, 100, "foo%");
2534 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2535 are expressed in the same way. Of course the C<$sub_stmt> and
2536 its associated bind values can be generated through a former call
2539 my ($sub_stmt, @sub_bind)
2540 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2541 c3 => {-like => "foo%"}});
2544 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2547 In the examples above, the subquery was used as an operator on a column;
2548 but the same principle also applies for a clause within the main C<%where>
2549 hash, like an EXISTS subquery:
2551 my ($sub_stmt, @sub_bind)
2552 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2553 my %where = ( -and => [
2555 \["EXISTS ($sub_stmt)" => @sub_bind],
2560 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2561 WHERE c1 = ? AND c2 > t0.c0))";
2565 Observe that the condition on C<c2> in the subquery refers to
2566 column C<t0.c0> of the main query: this is I<not> a bind
2567 value, so we have to express it through a scalar ref.
2568 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2569 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2570 what we wanted here.
2572 Finally, here is an example where a subquery is used
2573 for expressing unary negation:
2575 my ($sub_stmt, @sub_bind)
2576 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2577 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2579 lname => {like => '%son%'},
2580 \["NOT ($sub_stmt)" => @sub_bind],
2585 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2586 @bind = ('%son%', 10, 20)
2588 =head3 Deprecated usage of Literal SQL
2590 Below are some examples of archaic use of literal SQL. It is shown only as
2591 reference for those who deal with legacy code. Each example has a much
2592 better, cleaner and safer alternative that users should opt for in new code.
2598 my %where = ( requestor => \'IS NOT NULL' )
2600 $stmt = "WHERE requestor IS NOT NULL"
2602 This used to be the way of generating NULL comparisons, before the handling
2603 of C<undef> got formalized. For new code please use the superior syntax as
2604 described in L</Tests for NULL values>.
2608 my %where = ( requestor => \'= submitter' )
2610 $stmt = "WHERE requestor = submitter"
2612 This used to be the only way to compare columns. Use the superior L</-ident>
2613 method for all new code. For example an identifier declared in such a way
2614 will be properly quoted if L</quote_char> is properly set, while the legacy
2615 form will remain as supplied.
2619 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2621 $stmt = "WHERE completed > ? AND is_ready"
2622 @bind = ('2012-12-21')
2624 Using an empty string literal used to be the only way to express a boolean.
2625 For all new code please use the much more readable
2626 L<-bool|/Unary operators: bool> operator.
2632 These pages could go on for a while, since the nesting of the data
2633 structures this module can handle are pretty much unlimited (the
2634 module implements the C<WHERE> expansion as a recursive function
2635 internally). Your best bet is to "play around" with the module a
2636 little to see how the data structures behave, and choose the best
2637 format for your data based on that.
2639 And of course, all the values above will probably be replaced with
2640 variables gotten from forms or the command line. After all, if you
2641 knew everything ahead of time, you wouldn't have to worry about
2642 dynamically-generating SQL and could just hardwire it into your
2645 =head1 ORDER BY CLAUSES
2647 Some functions take an order by clause. This can either be a scalar (just a
2648 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2649 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2652 Given | Will Generate
2653 ---------------------------------------------------------------
2655 'colA' | ORDER BY colA
2657 [qw/colA colB/] | ORDER BY colA, colB
2659 {-asc => 'colA'} | ORDER BY colA ASC
2661 {-desc => 'colB'} | ORDER BY colB DESC
2663 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2665 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2667 \'colA DESC' | ORDER BY colA DESC
2669 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2670 | /* ...with $x bound to ? */
2673 { -asc => 'colA' }, | colA ASC,
2674 { -desc => [qw/colB/] }, | colB DESC,
2675 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2676 \'colE DESC', | colE DESC,
2677 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2678 ] | /* ...with $x bound to ? */
2679 ===============================================================
2683 =head1 SPECIAL OPERATORS
2685 my $sqlmaker = SQL::Abstract->new(special_ops => [
2689 my ($self, $field, $op, $arg) = @_;
2695 handler => 'method_name',
2699 A "special operator" is a SQL syntactic clause that can be
2700 applied to a field, instead of a usual binary operator.
2703 WHERE field IN (?, ?, ?)
2704 WHERE field BETWEEN ? AND ?
2705 WHERE MATCH(field) AGAINST (?, ?)
2707 Special operators IN and BETWEEN are fairly standard and therefore
2708 are builtin within C<SQL::Abstract> (as the overridable methods
2709 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2710 like the MATCH .. AGAINST example above which is specific to MySQL,
2711 you can write your own operator handlers - supply a C<special_ops>
2712 argument to the C<new> method. That argument takes an arrayref of
2713 operator definitions; each operator definition is a hashref with two
2720 the regular expression to match the operator
2724 Either a coderef or a plain scalar method name. In both cases
2725 the expected return is C<< ($sql, @bind) >>.
2727 When supplied with a method name, it is simply called on the
2728 L<SQL::Abstract> object as:
2730 $self->$method_name($field, $op, $arg)
2734 $field is the LHS of the operator
2735 $op is the part that matched the handler regex
2738 When supplied with a coderef, it is called as:
2740 $coderef->($self, $field, $op, $arg)
2745 For example, here is an implementation
2746 of the MATCH .. AGAINST syntax for MySQL
2748 my $sqlmaker = SQL::Abstract->new(special_ops => [
2750 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2751 {regex => qr/^match$/i,
2753 my ($self, $field, $op, $arg) = @_;
2754 $arg = [$arg] if not ref $arg;
2755 my $label = $self->_quote($field);
2756 my ($placeholder) = $self->_convert('?');
2757 my $placeholders = join ", ", (($placeholder) x @$arg);
2758 my $sql = $self->_sqlcase('match') . " ($label) "
2759 . $self->_sqlcase('against') . " ($placeholders) ";
2760 my @bind = $self->_bindtype($field, @$arg);
2761 return ($sql, @bind);
2768 =head1 UNARY OPERATORS
2770 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2774 my ($self, $op, $arg) = @_;
2780 handler => 'method_name',
2784 A "unary operator" is a SQL syntactic clause that can be
2785 applied to a field - the operator goes before the field
2787 You can write your own operator handlers - supply a C<unary_ops>
2788 argument to the C<new> method. That argument takes an arrayref of
2789 operator definitions; each operator definition is a hashref with two
2796 the regular expression to match the operator
2800 Either a coderef or a plain scalar method name. In both cases
2801 the expected return is C<< $sql >>.
2803 When supplied with a method name, it is simply called on the
2804 L<SQL::Abstract> object as:
2806 $self->$method_name($op, $arg)
2810 $op is the part that matched the handler regex
2811 $arg is the RHS or argument of the operator
2813 When supplied with a coderef, it is called as:
2815 $coderef->($self, $op, $arg)
2823 Thanks to some benchmarking by Mark Stosberg, it turns out that
2824 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2825 I must admit this wasn't an intentional design issue, but it's a
2826 byproduct of the fact that you get to control your C<DBI> handles
2829 To maximize performance, use a code snippet like the following:
2831 # prepare a statement handle using the first row
2832 # and then reuse it for the rest of the rows
2834 for my $href (@array_of_hashrefs) {
2835 $stmt ||= $sql->insert('table', $href);
2836 $sth ||= $dbh->prepare($stmt);
2837 $sth->execute($sql->values($href));
2840 The reason this works is because the keys in your C<$href> are sorted
2841 internally by B<SQL::Abstract>. Thus, as long as your data retains
2842 the same structure, you only have to generate the SQL the first time
2843 around. On subsequent queries, simply use the C<values> function provided
2844 by this module to return your values in the correct order.
2846 However this depends on the values having the same type - if, for
2847 example, the values of a where clause may either have values
2848 (resulting in sql of the form C<column = ?> with a single bind
2849 value), or alternatively the values might be C<undef> (resulting in
2850 sql of the form C<column IS NULL> with no bind value) then the
2851 caching technique suggested will not work.
2855 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2856 really like this part (I do, at least). Building up a complex query
2857 can be as simple as the following:
2864 use CGI::FormBuilder;
2867 my $form = CGI::FormBuilder->new(...);
2868 my $sql = SQL::Abstract->new;
2870 if ($form->submitted) {
2871 my $field = $form->field;
2872 my $id = delete $field->{id};
2873 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2876 Of course, you would still have to connect using C<DBI> to run the
2877 query, but the point is that if you make your form look like your
2878 table, the actual query script can be extremely simplistic.
2880 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2881 a fast interface to returning and formatting data. I frequently
2882 use these three modules together to write complex database query
2883 apps in under 50 lines.
2885 =head1 HOW TO CONTRIBUTE
2887 Contributions are always welcome, in all usable forms (we especially
2888 welcome documentation improvements). The delivery methods include git-
2889 or unified-diff formatted patches, GitHub pull requests, or plain bug
2890 reports either via RT or the Mailing list. Contributors are generally
2891 granted full access to the official repository after their first several
2892 patches pass successful review.
2894 This project is maintained in a git repository. The code and related tools are
2895 accessible at the following locations:
2899 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
2901 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
2903 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
2905 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
2911 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2912 Great care has been taken to preserve the I<published> behavior
2913 documented in previous versions in the 1.* family; however,
2914 some features that were previously undocumented, or behaved
2915 differently from the documentation, had to be changed in order
2916 to clarify the semantics. Hence, client code that was relying
2917 on some dark areas of C<SQL::Abstract> v1.*
2918 B<might behave differently> in v1.50.
2920 The main changes are:
2926 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
2930 support for the { operator => \"..." } construct (to embed literal SQL)
2934 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2938 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2942 defensive programming: check arguments
2946 fixed bug with global logic, which was previously implemented
2947 through global variables yielding side-effects. Prior versions would
2948 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2949 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2950 Now this is interpreted
2951 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2956 fixed semantics of _bindtype on array args
2960 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2961 we just avoid shifting arrays within that tree.
2965 dropped the C<_modlogic> function
2969 =head1 ACKNOWLEDGEMENTS
2971 There are a number of individuals that have really helped out with
2972 this module. Unfortunately, most of them submitted bugs via CPAN
2973 so I have no idea who they are! But the people I do know are:
2975 Ash Berlin (order_by hash term support)
2976 Matt Trout (DBIx::Class support)
2977 Mark Stosberg (benchmarking)
2978 Chas Owens (initial "IN" operator support)
2979 Philip Collins (per-field SQL functions)
2980 Eric Kolve (hashref "AND" support)
2981 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2982 Dan Kubb (support for "quote_char" and "name_sep")
2983 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2984 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
2985 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2986 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
2987 Oliver Charles (support for "RETURNING" after "INSERT")
2993 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
2997 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2999 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3001 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3002 While not an official support venue, C<DBIx::Class> makes heavy use of
3003 C<SQL::Abstract>, and as such list members there are very familiar with
3004 how to create queries.
3008 This module is free software; you may copy this under the same
3009 terms as perl itself (either the GNU General Public License or
3010 the Artistic License)