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;
163 if ($class->isa('DBIx::Class::SQLMaker')) {
164 push @{$opt{special_ops}}, our $DBIC_Compat_Op ||= {
165 regex => qr/^(?:ident|value)$/i, handler => sub { die "NOPE" }
167 $opt{is_dbic_sqlmaker} = 1;
171 $opt{unary_ops} ||= [];
173 # rudimentary sanity-check for user supplied bits treated as functions/operators
174 # If a purported function matches this regular expression, an exception is thrown.
175 # Literal SQL is *NOT* subject to this check, only functions (and column names
176 # when quoting is not in effect)
179 # need to guard against ()'s in column names too, but this will break tons of
180 # hacks... ideas anyone?
181 $opt{injection_guard} ||= qr/
187 $opt{expand_unary} = {};
190 -not => '_expand_not',
191 -bool => '_expand_bool',
192 -and => '_expand_op_andor',
193 -or => '_expand_op_andor',
194 -nest => '_expand_nest',
198 'between' => '_expand_between',
199 'not between' => '_expand_between',
200 'in' => '_expand_in',
201 'not in' => '_expand_in',
202 'nest' => '_expand_nest',
203 (map +($_ => '_expand_op_andor'),
207 # placeholder for _expand_unop system
209 my %unops = (-ident => '_expand_ident', -value => '_expand_value');
210 foreach my $name (keys %unops) {
211 $opt{expand}{$name} = $unops{$name};
212 my ($op) = $name =~ /^-(.*)$/;
213 $opt{expand_op}{$op} = sub {
214 my ($self, $op, $arg, $k) = @_;
217 $self->_expand_ident(-ident => $k),
218 $self->_expand_expr({ '-'.$op => $arg }),
225 (map +("-$_", "_render_$_"), qw(op func bind ident literal list)),
229 $opt{render_op} = our $RENDER_OP;
231 return bless \%opt, $class;
234 sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
235 sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
237 sub _assert_pass_injection_guard {
238 if ($_[1] =~ $_[0]->{injection_guard}) {
239 my $class = ref $_[0];
240 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
241 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
242 . "{injection_guard} attribute to ${class}->new()"
247 #======================================================================
249 #======================================================================
253 my $table = $self->_table(shift);
254 my $data = shift || return;
257 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
258 my ($sql, @bind) = $self->$method($data);
259 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
261 if ($options->{returning}) {
262 my ($s, @b) = $self->_insert_returning($options);
267 return wantarray ? ($sql, @bind) : $sql;
270 # So that subclasses can override INSERT ... RETURNING separately from
271 # UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
272 sub _insert_returning { shift->_returning(@_) }
275 my ($self, $options) = @_;
277 my $f = $options->{returning};
279 my ($sql, @bind) = $self->render_aqt(
280 $self->_expand_maybe_list_expr($f, undef, -ident)
283 ? $self->_sqlcase(' returning ') . $sql
284 : ($self->_sqlcase(' returning ').$sql, @bind);
287 sub _insert_HASHREF { # explicit list of fields and then values
288 my ($self, $data) = @_;
290 my @fields = sort keys %$data;
292 my ($sql, @bind) = $self->_insert_values($data);
295 $_ = $self->_quote($_) foreach @fields;
296 $sql = "( ".join(", ", @fields).") ".$sql;
298 return ($sql, @bind);
301 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
302 my ($self, $data) = @_;
304 # no names (arrayref) so can't generate bindtype
305 $self->{bindtype} ne 'columns'
306 or belch "can't do 'columns' bindtype when called with arrayref";
308 my (@values, @all_bind);
309 foreach my $value (@$data) {
310 my ($values, @bind) = $self->_insert_value(undef, $value);
311 push @values, $values;
312 push @all_bind, @bind;
314 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
315 return ($sql, @all_bind);
318 sub _insert_ARRAYREFREF { # literal SQL with bind
319 my ($self, $data) = @_;
321 my ($sql, @bind) = @${$data};
322 $self->_assert_bindval_matches_bindtype(@bind);
324 return ($sql, @bind);
328 sub _insert_SCALARREF { # literal SQL without bind
329 my ($self, $data) = @_;
335 my ($self, $data) = @_;
337 my (@values, @all_bind);
338 foreach my $column (sort keys %$data) {
339 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
340 push @values, $values;
341 push @all_bind, @bind;
343 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
344 return ($sql, @all_bind);
348 my ($self, $column, $v) = @_;
350 return $self->render_aqt(
351 $self->_expand_insert_value($column, $v)
355 sub _expand_insert_value {
356 my ($self, $column, $v) = @_;
358 if (ref($v) eq 'ARRAY') {
359 if ($self->{array_datatypes}) {
360 return +{ -bind => [ $column, $v ] };
362 my ($sql, @bind) = @$v;
363 $self->_assert_bindval_matches_bindtype(@bind);
364 return +{ -literal => $v };
366 if (ref($v) eq 'HASH') {
367 if (grep !/^-/, keys %$v) {
368 belch "HASH ref as bind value in insert is not supported";
369 return +{ -bind => [ $column, $v ] };
373 return +{ -bind => [ $column, undef ] };
375 local our $Cur_Col_Meta = $column;
376 return $self->expand_expr($v);
381 #======================================================================
383 #======================================================================
388 my $table = $self->_table(shift);
389 my $data = shift || return;
393 # first build the 'SET' part of the sql statement
394 puke "Unsupported data type specified to \$sql->update"
395 unless ref $data eq 'HASH';
397 my ($sql, @all_bind) = $self->_update_set_values($data);
398 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
402 my($where_sql, @where_bind) = $self->where($where);
404 push @all_bind, @where_bind;
407 if ($options->{returning}) {
408 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
409 $sql .= $returning_sql;
410 push @all_bind, @returning_bind;
413 return wantarray ? ($sql, @all_bind) : $sql;
416 sub _update_set_values {
417 my ($self, $data) = @_;
419 return $self->render_aqt(
420 $self->_expand_update_set_values($data),
424 sub _expand_update_set_values {
425 my ($self, $data) = @_;
426 $self->_expand_maybe_list_expr( [
429 $set = { -bind => $_ } unless defined $set;
430 +{ -op => [ '=', $self->_expand_ident(-ident => $k), $set ] };
436 ? ($self->{array_datatypes}
437 ? [ $k, +{ -bind => [ $k, $v ] } ]
438 : [ $k, +{ -literal => $v } ])
440 local our $Cur_Col_Meta = $k;
441 [ $k, $self->_expand_expr($v) ]
448 # So that subclasses can override UPDATE ... RETURNING separately from
450 sub _update_returning { shift->_returning(@_) }
454 #======================================================================
456 #======================================================================
461 my $table = $self->_table(shift);
462 my $fields = shift || '*';
466 my ($fields_sql, @bind) = $self->_select_fields($fields);
468 my ($where_sql, @where_bind) = $self->where($where, $order);
469 push @bind, @where_bind;
471 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
472 $self->_sqlcase('from'), $table)
475 return wantarray ? ($sql, @bind) : $sql;
479 my ($self, $fields) = @_;
480 return $fields unless ref($fields);
481 return $self->render_aqt(
482 $self->_expand_maybe_list_expr($fields, undef, '-ident')
486 #======================================================================
488 #======================================================================
493 my $table = $self->_table(shift);
497 my($where_sql, @bind) = $self->where($where);
498 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
500 if ($options->{returning}) {
501 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
502 $sql .= $returning_sql;
503 push @bind, @returning_bind;
506 return wantarray ? ($sql, @bind) : $sql;
509 # So that subclasses can override DELETE ... RETURNING separately from
511 sub _delete_returning { shift->_returning(@_) }
515 #======================================================================
517 #======================================================================
521 # Finally, a separate routine just to handle WHERE clauses
523 my ($self, $where, $order) = @_;
525 local $self->{convert_where} = $self->{convert};
528 my ($sql, @bind) = defined($where)
529 ? $self->_recurse_where($where)
531 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
535 my ($order_sql, @order_bind) = $self->_order_by($order);
537 push @bind, @order_bind;
540 return wantarray ? ($sql, @bind) : $sql;
544 my ($self, $expr, $default_scalar_to) = @_;
545 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
546 $self->_expand_expr($expr);
550 my ($self, $aqt) = @_;
551 my ($k, $v, @rest) = %$aqt;
553 if (my $meth = $self->{render}{$k}) {
554 return $self->$meth($v);
556 die "notreached: $k";
560 my ($self, $expr) = @_;
561 $self->render_aqt($self->expand_expr($expr));
565 my ($self, $expr) = @_;
566 our $Expand_Depth ||= 0; local $Expand_Depth = $Expand_Depth + 1;
567 return undef unless defined($expr);
568 if (ref($expr) eq 'HASH') {
569 return undef unless my $kc = keys %$expr;
571 return $self->_expand_op_andor(-and => $expr);
573 my ($key, $value) = %$expr;
574 if ($key =~ /^-/ and $key =~ s/ [_\s]? \d+ $//x ) {
575 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
576 . "You probably wanted ...-and => [ $key => COND1, $key => COND2 ... ]";
578 if (my $exp = $self->{expand}{$key}) {
579 return $self->$exp($key, $value);
581 return $self->_expand_expr_hashpair($key, $value);
583 if (ref($expr) eq 'ARRAY') {
584 my $logic = '-'.lc($self->{logic});
585 return $self->_expand_op_andor($logic, $expr);
587 if (my $literal = is_literal_value($expr)) {
588 return +{ -literal => $literal };
590 if (!ref($expr) or Scalar::Util::blessed($expr)) {
591 if (my $d = our $Default_Scalar_To) {
592 return $self->_expand_expr({ $d => $expr });
594 return $self->_expand_value(-value => $expr);
599 sub _expand_expr_hashpair {
600 my ($self, $k, $v) = @_;
601 unless (defined($k) and length($k)) {
602 if (defined($k) and my $literal = is_literal_value($v)) {
603 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
604 return { -literal => $literal };
606 puke "Supplying an empty left hand side argument is not supported";
609 return $self->_expand_expr_hashpair_op($k, $v);
611 return $self->_expand_expr_hashpair_ident($k, $v);
614 sub _expand_expr_hashpair_ident {
615 my ($self, $k, $v) = @_;
617 # undef needs to be re-sent with cmp to achieve IS/IS NOT NULL
623 and exists $v->{-value}
624 and not defined $v->{-value}
627 return $self->_expand_expr({ $k => { $self->{cmp} => undef } });
630 my $ik = $self->_expand_ident(-ident => $k);
632 # scalars and objects get expanded as whatever requested or values
634 if (!ref($v) or Scalar::Util::blessed($v)) {
635 my $d = our $Default_Scalar_To;
636 local our $Cur_Col_Meta = $k;
637 return $self->_expand_expr_hashpair_ident(
640 ? $self->_expand_expr($d => $v)
645 if (ref($v) eq 'HASH') {
647 return $self->_expand_op_andor(-and => $v, $k);
649 return undef unless keys %$v;
651 my $op = join ' ', split '_', (map lc, $vk =~ /^-?(.*)$/)[0];
652 $self->_assert_pass_injection_guard($op);
653 if ($op =~ s/ [_\s]? \d+ $//x ) {
654 return $self->_expand_expr($k, $v);
656 if (my $x = $self->{expand_op}{$op}) {
657 local our $Cur_Col_Meta = $k;
658 return $self->$x($op, $vv, $k);
660 if ($op =~ /^is(?: not)?$/) {
661 puke "$op can only take undef as argument"
665 and exists($vv->{-value})
666 and !defined($vv->{-value})
668 return +{ -op => [ $op.' null', $ik ] };
670 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
671 return { -op => [ $op, $ik, $vv ] };
673 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
677 { -op => [ $op, $vv ] }
680 if (ref($vv) eq 'ARRAY') {
682 my $logic = (defined($raw[0]) and $raw[0] =~ /^-(and|or)$/i)
683 ? shift @raw : '-or';
684 my @values = map +{ $vk => $_ }, @raw;
686 $op =~ $self->{inequality_op}
687 or $op =~ $self->{not_like_op}
689 if (lc($logic) eq '-or' and @values > 1) {
690 belch "A multi-element arrayref as an argument to the inequality op '${\uc($op)}' "
691 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
692 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
697 # try to DWIM on equality operators
699 $op =~ $self->{equality_op} ? $self->sqlfalse
700 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
701 : $op =~ $self->{inequality_op} ? $self->sqltrue
702 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
703 : puke "operator '$op' applied on an empty array (field '$k')";
705 return $self->_expand_op_andor($logic => \@values, $k);
711 and exists $vv->{-value}
712 and not defined $vv->{-value}
716 $op =~ /^not$/i ? 'is not' # legacy
717 : $op =~ $self->{equality_op} ? 'is'
718 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
719 : $op =~ $self->{inequality_op} ? 'is not'
720 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
721 : puke "unexpected operator '$op' with undef operand";
722 return +{ -op => [ $is.' null', $ik ] };
724 local our $Cur_Col_Meta = $k;
728 $self->_expand_expr($vv)
731 if (ref($v) eq 'ARRAY') {
732 return $self->sqlfalse unless @$v;
733 $self->_debug("ARRAY($k) means distribute over elements");
735 $v->[0] =~ /^-(and|or)$/i
736 ? shift(@{$v = [ @$v ]})
737 : '-'.lc($self->{logic} || 'OR')
739 return $self->_expand_op_andor(
743 if (my $literal = is_literal_value($v)) {
745 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
748 my ($sql, @bind) = @$literal;
749 if ($self->{bindtype} eq 'columns') {
751 $self->_assert_bindval_matches_bindtype($_);
754 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
759 sub _expand_expr_hashpair_op {
760 my ($self, $k, $v) = @_;
763 $op =~ s/^-// if length($op) > 1;
764 $self->_assert_pass_injection_guard($op);
766 # Ops prefixed with -not_ get converted
768 if (my ($rest) = $op =~/^not[_ ](.*)$/) {
771 $self->_expand_expr({ "-${rest}", $v })
775 # the old special op system requires illegality for top-level use
778 (our $Expand_Depth) == 1
779 and List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}
781 puke "Illegal use of top-level '-$op'"
784 # the old unary op system means we should touch nothing and let it work
786 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
787 return { -op => [ $op, $v ] };
790 # an explicit node type is currently assumed to be expanded (this is almost
791 # certainly wrong and there should be expansion anyway)
793 if ($self->{render}{$k}) {
797 # hashref RHS values get expanded and used as op/func args
802 and (keys %$v)[0] =~ /^-/
804 my ($func) = $k =~ /^-(.*)$/;
805 if (List::Util::first { $func =~ $_->{regex} } @{$self->{special_ops}}) {
806 return +{ -op => [ $func, $self->_expand_expr($v) ] };
808 return +{ -func => [ $func, $self->_expand_expr($v) ] };
811 # scalars and literals get simply expanded
813 if (!ref($v) or is_literal_value($v)) {
814 return +{ -op => [ $op, $self->_expand_expr($v) ] };
821 my ($self, $op, $body) = @_;
822 unless (defined($body) or (ref($body) and ref($body) eq 'ARRAY')) {
823 puke "$op requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
825 my @parts = map split(/\Q${\($self->{name_sep}||'.')}\E/, $_),
826 ref($body) ? @$body : $body;
827 return { -ident => $parts[-1] } if $self->{_dequalify_idents};
828 unless ($self->{quote_char}) {
829 $self->_assert_pass_injection_guard($_) for @parts;
831 return +{ -ident => \@parts };
835 +{ -bind => [ our $Cur_Col_Meta, $_[2] ] };
839 +{ -op => [ 'not', $_[0]->_expand_expr($_[2]) ] };
843 my ($self, undef, $v) = @_;
845 return $self->_expand_expr($v);
847 puke "-bool => undef not supported" unless defined($v);
848 return $self->_expand_ident(-ident => $v);
851 sub _expand_op_andor {
852 my ($self, $logic, $v, $k) = @_;
854 $v = [ map +{ $k, $_ },
856 ? (map +{ $_ => $v->{$_} }, sort keys %$v)
860 my ($logop) = $logic =~ /^-?(.*)$/;
861 if (ref($v) eq 'HASH') {
864 map $self->_expand_expr({ $_ => $v->{$_} }),
868 if (ref($v) eq 'ARRAY') {
869 $logop eq 'and' or $logop eq 'or' or puke "unknown logic: $logop";
872 (ref($_) eq 'ARRAY' and @$_)
873 or (ref($_) eq 'HASH' and %$_)
879 while (my ($el) = splice @expr, 0, 1) {
880 puke "Supplying an empty left hand side argument is not supported in array-pairs"
881 unless defined($el) and length($el);
882 my $elref = ref($el);
884 local our $Expand_Depth = 0;
885 push(@res, grep defined, $self->_expand_expr({ $el, shift(@expr) }));
886 } elsif ($elref eq 'ARRAY') {
887 push(@res, grep defined, $self->_expand_expr($el)) if @$el;
888 } elsif (my $l = is_literal_value($el)) {
889 push @res, { -literal => $l };
890 } elsif ($elref eq 'HASH') {
891 local our $Expand_Depth = 0;
892 push @res, grep defined, $self->_expand_expr($el) if %$el;
898 # return $res[0] if @res == 1;
899 return { -op => [ $logop, @res ] };
904 sub _expand_between {
905 my ($self, $op, $vv, $k) = @_;
906 local our $Cur_Col_Meta = $k;
907 my @rhs = map $self->_expand_expr($_),
908 ref($vv) eq 'ARRAY' ? @$vv : $vv;
910 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
912 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
914 puke "Operator '${\uc($op)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
918 $self->_expand_ident(-ident => $k),
924 my ($self, $op, $vv, $k) = @_;
925 if (my $literal = is_literal_value($vv)) {
926 my ($sql, @bind) = @$literal;
927 my $opened_sql = $self->_open_outer_paren($sql);
929 $op, $self->_expand_ident(-ident => $k),
930 [ { -literal => [ $opened_sql, @bind ] } ]
934 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
935 . "-${\uc($op)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
936 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
937 . 'will emit the logically correct SQL instead of raising this exception)'
939 puke("Argument passed to the '${\uc($op)}' operator can not be undefined")
941 my @rhs = map $self->_expand_expr($_),
942 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
943 map { defined($_) ? $_: puke($undef_err) }
944 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
945 return $self->${\($op =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
949 $self->_expand_ident(-ident => $k),
955 my ($self, $op, $v) = @_;
956 # DBIx::Class requires a nest warning to be emitted once but the private
957 # method it overrode to do so no longer exists
958 if ($self->{is_dbic_sqlmaker}) {
959 unless (our $Nest_Warned) {
961 "-nest in search conditions is deprecated, you most probably wanted:\n"
962 .q|{..., -and => [ \%cond0, \@cond1, \'cond2', \[ 'cond3', [ col => bind ] ], etc. ], ... }|
967 return $self->_expand_expr($v);
971 my ($self, $where, $logic) = @_;
973 # Special case: top level simple string treated as literal
975 my $where_exp = (ref($where)
976 ? $self->_expand_expr($where, $logic)
977 : { -literal => [ $where ] });
979 # dispatch expanded expression
981 my ($sql, @bind) = defined($where_exp) ? $self->render_aqt($where_exp) : (undef);
982 # DBIx::Class used to call _recurse_where in scalar context
983 # something else might too...
985 return ($sql, @bind);
988 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
994 my ($self, $ident) = @_;
996 return $self->_convert($self->_quote($ident));
1000 my ($self, $list) = @_;
1001 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$list;
1002 return join(', ', map $_->[0], @parts), map @{$_}[1..$#$_], @parts;
1006 my ($self, $rest) = @_;
1007 my ($func, @args) = @$rest;
1011 push @arg_sql, shift @x;
1013 } map [ $self->render_aqt($_) ], @args;
1014 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1018 my ($self, $bind) = @_;
1019 return ($self->_convert('?'), $self->_bindtype(@$bind));
1022 sub _render_literal {
1023 my ($self, $literal) = @_;
1024 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1028 sub _render_op_between {
1029 my ($self, $op, $args) = @_;
1030 my ($left, $low, $high) = @$args;
1031 my ($rhsql, @rhbind) = do {
1033 puke "Single arg to between must be a literal"
1034 unless $low->{-literal};
1037 my ($l, $h) = map [ $self->render_aqt($_) ], $low, $high;
1038 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
1039 @{$l}[1..$#$l], @{$h}[1..$#$h])
1042 my ($lhsql, @lhbind) = $self->render_aqt($left);
1044 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
1050 (map +($_ => '_render_op_between'), 'between', 'not between'),
1052 my ($self, $op, $args) = @_;
1053 my ($lhs, $rhs) = @$args;
1056 my ($sql, @bind) = $self->render_aqt($_);
1057 push @in_bind, @bind;
1060 my ($lhsql, @lbind) = $self->render_aqt($lhs);
1062 $lhsql.' '.$self->_sqlcase($op).' ( '
1063 .join(', ', @in_sql)
1067 }), 'in', 'not in'),
1068 (map +($_ => '_render_unop_postfix'),
1069 'is null', 'is not null', 'asc', 'desc',
1071 (not => '_render_op_not'),
1073 my ($self, $op, $args) = @_;
1074 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$args;
1075 return '' unless @parts;
1076 return @{$parts[0]} if @parts == 1;
1077 my ($final_sql) = join(
1078 ' '.$self->_sqlcase($op).' ',
1083 map @{$_}[1..$#$_], @parts
1089 my ($self, $v) = @_;
1090 my ($op, @args) = @$v;
1091 if (my $r = $self->{render_op}{$op}) {
1092 return $self->$r($op, \@args);
1094 my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
1095 if ($us and @args > 1) {
1096 puke "Special op '${op}' requires first value to be identifier"
1097 unless my ($ident) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
1098 my $k = join(($self->{name_sep}||'.'), @$ident);
1099 local our $Expand_Depth = 1;
1100 return $self->${\($us->{handler})}($k, $op, $args[1]);
1102 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
1103 return $self->${\($us->{handler})}($op, $args[0]);
1106 return $self->_render_unop_prefix($op, \@args);
1108 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @args;
1109 return '' unless @parts;
1110 my ($final_sql) = join(
1111 ' '.$self->_sqlcase($op).' ',
1116 map @{$_}[1..$#$_], @parts
1122 sub _render_op_not {
1123 my ($self, $op, $v) = @_;
1124 my ($sql, @bind) = $self->_render_unop_prefix($op, $v);
1125 return "(${sql})", @bind;
1128 sub _render_unop_prefix {
1129 my ($self, $op, $v) = @_;
1130 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1131 my $op_sql = $self->_sqlcase($op);
1132 return ("${op_sql} ${expr_sql}", @bind);
1135 sub _render_unop_postfix {
1136 my ($self, $op, $v) = @_;
1137 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1138 my $op_sql = $self->_sqlcase($op);
1139 return ($expr_sql.' '.$op_sql, @bind);
1142 # Some databases (SQLite) treat col IN (1, 2) different from
1143 # col IN ( (1, 2) ). Use this to strip all outer parens while
1144 # adding them back in the corresponding method
1145 sub _open_outer_paren {
1146 my ($self, $sql) = @_;
1148 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1150 # there are closing parens inside, need the heavy duty machinery
1151 # to reevaluate the extraction starting from $sql (full reevaluation)
1152 if ($inner =~ /\)/) {
1153 require Text::Balanced;
1155 my (undef, $remainder) = do {
1156 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1158 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1161 # the entire expression needs to be a balanced bracketed thing
1162 # (after an extract no remainder sans trailing space)
1163 last if defined $remainder and $remainder =~ /\S/;
1173 #======================================================================
1175 #======================================================================
1177 sub _expand_order_by {
1178 my ($self, $arg) = @_;
1180 return unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
1182 my $expander = sub {
1183 my ($self, $dir, $expr) = @_;
1184 my @to_expand = ref($expr) eq 'ARRAY' ? @$expr : $expr;
1185 foreach my $arg (@to_expand) {
1189 and grep /^-(asc|desc)$/, keys %$arg
1191 puke "ordering direction hash passed to order by must have exactly one key (-asc or -desc)";
1195 defined($dir) ? { -op => [ $dir =~ /^-?(.*)$/ ,=> $_ ] } : $_
1197 map $self->expand_expr($_, -ident),
1198 map ref($_) eq 'ARRAY' ? @$_ : $_, @to_expand;
1199 return (@exp > 1 ? { -list => \@exp } : $exp[0]);
1202 local @{$self->{expand}}{qw(-asc -desc)} = (($expander) x 2);
1204 return $self->$expander(undef, $arg);
1208 my ($self, $arg) = @_;
1210 return '' unless defined(my $expanded = $self->_expand_order_by($arg));
1212 my ($sql, @bind) = $self->render_aqt($expanded);
1214 return '' unless length($sql);
1216 my $final_sql = $self->_sqlcase(' order by ').$sql;
1218 return wantarray ? ($final_sql, @bind) : $final_sql;
1221 # _order_by no longer needs to call this so doesn't but DBIC uses it.
1223 sub _order_by_chunks {
1224 my ($self, $arg) = @_;
1226 return () unless defined(my $expanded = $self->_expand_order_by($arg));
1228 return $self->_chunkify_order_by($expanded);
1231 sub _chunkify_order_by {
1232 my ($self, $expanded) = @_;
1234 return grep length, $self->render_aqt($expanded)
1235 if $expanded->{-ident} or @{$expanded->{-literal}||[]} == 1;
1238 if (ref() eq 'HASH' and my $l = $_->{-list}) {
1239 return map $self->_chunkify_order_by($_), @$l;
1241 return [ $self->render_aqt($_) ];
1245 #======================================================================
1246 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1247 #======================================================================
1253 $self->_expand_maybe_list_expr($from, undef, -ident)
1258 #======================================================================
1260 #======================================================================
1262 sub _expand_maybe_list_expr {
1263 my ($self, $expr, $logic, $default) = @_;
1265 if (ref($expr) eq 'ARRAY') {
1267 map $self->expand_expr($_, $default), @$expr
1274 return $self->expand_expr($e, $default);
1277 # highly optimized, as it's called way too often
1279 # my ($self, $label) = @_;
1281 return '' unless defined $_[1];
1282 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1283 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
1285 unless ($_[0]->{quote_char}) {
1286 if (ref($_[1]) eq 'ARRAY') {
1287 return join($_[0]->{name_sep}||'.', @{$_[1]});
1289 $_[0]->_assert_pass_injection_guard($_[1]);
1294 my $qref = ref $_[0]->{quote_char};
1296 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1297 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1298 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1300 my $esc = $_[0]->{escape_char} || $r;
1302 # parts containing * are naturally unquoted
1304 $_[0]->{name_sep}||'',
1308 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1310 (ref($_[1]) eq 'ARRAY'
1314 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1322 # Conversion, if applicable
1324 #my ($self, $arg) = @_;
1325 if ($_[0]->{convert_where}) {
1326 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
1333 #my ($self, $col, @vals) = @_;
1334 # called often - tighten code
1335 return $_[0]->{bindtype} eq 'columns'
1336 ? map {[$_[1], $_]} @_[2 .. $#_]
1341 # Dies if any element of @bind is not in [colname => value] format
1342 # if bindtype is 'columns'.
1343 sub _assert_bindval_matches_bindtype {
1344 # my ($self, @bind) = @_;
1346 if ($self->{bindtype} eq 'columns') {
1348 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1349 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1355 sub _join_sql_clauses {
1356 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1358 if (@$clauses_aref > 1) {
1359 my $join = " " . $self->_sqlcase($logic) . " ";
1360 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1361 return ($sql, @$bind_aref);
1363 elsif (@$clauses_aref) {
1364 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1367 return (); # if no SQL, ignore @$bind_aref
1372 # Fix SQL case, if so requested
1374 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1375 # don't touch the argument ... crooked logic, but let's not change it!
1376 return $_[0]->{case} ? $_[1] : uc($_[1]);
1380 #======================================================================
1381 # DISPATCHING FROM REFKIND
1382 #======================================================================
1385 my ($self, $data) = @_;
1387 return 'UNDEF' unless defined $data;
1389 # blessed objects are treated like scalars
1390 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1392 return 'SCALAR' unless $ref;
1395 while ($ref eq 'REF') {
1397 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1401 return ($ref||'SCALAR') . ('REF' x $n_steps);
1405 my ($self, $data) = @_;
1406 my @try = ($self->_refkind($data));
1407 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1408 push @try, 'FALLBACK';
1412 sub _METHOD_FOR_refkind {
1413 my ($self, $meth_prefix, $data) = @_;
1416 for (@{$self->_try_refkind($data)}) {
1417 $method = $self->can($meth_prefix."_".$_)
1421 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1425 sub _SWITCH_refkind {
1426 my ($self, $data, $dispatch_table) = @_;
1429 for (@{$self->_try_refkind($data)}) {
1430 $coderef = $dispatch_table->{$_}
1434 puke "no dispatch entry for ".$self->_refkind($data)
1443 #======================================================================
1444 # VALUES, GENERATE, AUTOLOAD
1445 #======================================================================
1447 # LDNOTE: original code from nwiger, didn't touch code in that section
1448 # I feel the AUTOLOAD stuff should not be the default, it should
1449 # only be activated on explicit demand by user.
1453 my $data = shift || return;
1454 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1455 unless ref $data eq 'HASH';
1458 foreach my $k (sort keys %$data) {
1459 my $v = $data->{$k};
1460 $self->_SWITCH_refkind($v, {
1462 if ($self->{array_datatypes}) { # array datatype
1463 push @all_bind, $self->_bindtype($k, $v);
1465 else { # literal SQL with bind
1466 my ($sql, @bind) = @$v;
1467 $self->_assert_bindval_matches_bindtype(@bind);
1468 push @all_bind, @bind;
1471 ARRAYREFREF => sub { # literal SQL with bind
1472 my ($sql, @bind) = @${$v};
1473 $self->_assert_bindval_matches_bindtype(@bind);
1474 push @all_bind, @bind;
1476 SCALARREF => sub { # literal SQL without bind
1478 SCALAR_or_UNDEF => sub {
1479 push @all_bind, $self->_bindtype($k, $v);
1490 my(@sql, @sqlq, @sqlv);
1494 if ($ref eq 'HASH') {
1495 for my $k (sort keys %$_) {
1498 my $label = $self->_quote($k);
1499 if ($r eq 'ARRAY') {
1500 # literal SQL with bind
1501 my ($sql, @bind) = @$v;
1502 $self->_assert_bindval_matches_bindtype(@bind);
1503 push @sqlq, "$label = $sql";
1505 } elsif ($r eq 'SCALAR') {
1506 # literal SQL without bind
1507 push @sqlq, "$label = $$v";
1509 push @sqlq, "$label = ?";
1510 push @sqlv, $self->_bindtype($k, $v);
1513 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1514 } elsif ($ref eq 'ARRAY') {
1515 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1518 if ($r eq 'ARRAY') { # literal SQL with bind
1519 my ($sql, @bind) = @$v;
1520 $self->_assert_bindval_matches_bindtype(@bind);
1523 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1524 # embedded literal SQL
1531 push @sql, '(' . join(', ', @sqlq) . ')';
1532 } elsif ($ref eq 'SCALAR') {
1536 # strings get case twiddled
1537 push @sql, $self->_sqlcase($_);
1541 my $sql = join ' ', @sql;
1543 # this is pretty tricky
1544 # if ask for an array, return ($stmt, @bind)
1545 # otherwise, s/?/shift @sqlv/ to put it inline
1547 return ($sql, @sqlv);
1549 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1550 ref $d ? $d->[1] : $d/e;
1559 # This allows us to check for a local, then _form, attr
1561 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1562 return $self->generate($name, @_);
1573 SQL::Abstract - Generate SQL from Perl data structures
1579 my $sql = SQL::Abstract->new;
1581 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1583 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1585 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1587 my($stmt, @bind) = $sql->delete($table, \%where);
1589 # Then, use these in your DBI statements
1590 my $sth = $dbh->prepare($stmt);
1591 $sth->execute(@bind);
1593 # Just generate the WHERE clause
1594 my($stmt, @bind) = $sql->where(\%where, $order);
1596 # Return values in the same order, for hashed queries
1597 # See PERFORMANCE section for more details
1598 my @bind = $sql->values(\%fieldvals);
1602 This module was inspired by the excellent L<DBIx::Abstract>.
1603 However, in using that module I found that what I really wanted
1604 to do was generate SQL, but still retain complete control over my
1605 statement handles and use the DBI interface. So, I set out to
1606 create an abstract SQL generation module.
1608 While based on the concepts used by L<DBIx::Abstract>, there are
1609 several important differences, especially when it comes to WHERE
1610 clauses. I have modified the concepts used to make the SQL easier
1611 to generate from Perl data structures and, IMO, more intuitive.
1612 The underlying idea is for this module to do what you mean, based
1613 on the data structures you provide it. The big advantage is that
1614 you don't have to modify your code every time your data changes,
1615 as this module figures it out.
1617 To begin with, an SQL INSERT is as easy as just specifying a hash
1618 of C<key=value> pairs:
1621 name => 'Jimbo Bobson',
1622 phone => '123-456-7890',
1623 address => '42 Sister Lane',
1624 city => 'St. Louis',
1625 state => 'Louisiana',
1628 The SQL can then be generated with this:
1630 my($stmt, @bind) = $sql->insert('people', \%data);
1632 Which would give you something like this:
1634 $stmt = "INSERT INTO people
1635 (address, city, name, phone, state)
1636 VALUES (?, ?, ?, ?, ?)";
1637 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1638 '123-456-7890', 'Louisiana');
1640 These are then used directly in your DBI code:
1642 my $sth = $dbh->prepare($stmt);
1643 $sth->execute(@bind);
1645 =head2 Inserting and Updating Arrays
1647 If your database has array types (like for example Postgres),
1648 activate the special option C<< array_datatypes => 1 >>
1649 when creating the C<SQL::Abstract> object.
1650 Then you may use an arrayref to insert and update database array types:
1652 my $sql = SQL::Abstract->new(array_datatypes => 1);
1654 planets => [qw/Mercury Venus Earth Mars/]
1657 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1661 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1663 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1666 =head2 Inserting and Updating SQL
1668 In order to apply SQL functions to elements of your C<%data> you may
1669 specify a reference to an arrayref for the given hash value. For example,
1670 if you need to execute the Oracle C<to_date> function on a value, you can
1671 say something like this:
1675 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1678 The first value in the array is the actual SQL. Any other values are
1679 optional and would be included in the bind values array. This gives
1682 my($stmt, @bind) = $sql->insert('people', \%data);
1684 $stmt = "INSERT INTO people (name, date_entered)
1685 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1686 @bind = ('Bill', '03/02/2003');
1688 An UPDATE is just as easy, all you change is the name of the function:
1690 my($stmt, @bind) = $sql->update('people', \%data);
1692 Notice that your C<%data> isn't touched; the module will generate
1693 the appropriately quirky SQL for you automatically. Usually you'll
1694 want to specify a WHERE clause for your UPDATE, though, which is
1695 where handling C<%where> hashes comes in handy...
1697 =head2 Complex where statements
1699 This module can generate pretty complicated WHERE statements
1700 easily. For example, simple C<key=value> pairs are taken to mean
1701 equality, and if you want to see if a field is within a set
1702 of values, you can use an arrayref. Let's say we wanted to
1703 SELECT some data based on this criteria:
1706 requestor => 'inna',
1707 worker => ['nwiger', 'rcwe', 'sfz'],
1708 status => { '!=', 'completed' }
1711 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1713 The above would give you something like this:
1715 $stmt = "SELECT * FROM tickets WHERE
1716 ( requestor = ? ) AND ( status != ? )
1717 AND ( worker = ? OR worker = ? OR worker = ? )";
1718 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1720 Which you could then use in DBI code like so:
1722 my $sth = $dbh->prepare($stmt);
1723 $sth->execute(@bind);
1729 The methods are simple. There's one for every major SQL operation,
1730 and a constructor you use first. The arguments are specified in a
1731 similar order for each method (table, then fields, then a where
1732 clause) to try and simplify things.
1734 =head2 new(option => 'value')
1736 The C<new()> function takes a list of options and values, and returns
1737 a new B<SQL::Abstract> object which can then be used to generate SQL
1738 through the methods below. The options accepted are:
1744 If set to 'lower', then SQL will be generated in all lowercase. By
1745 default SQL is generated in "textbook" case meaning something like:
1747 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1749 Any setting other than 'lower' is ignored.
1753 This determines what the default comparison operator is. By default
1754 it is C<=>, meaning that a hash like this:
1756 %where = (name => 'nwiger', email => 'nate@wiger.org');
1758 Will generate SQL like this:
1760 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1762 However, you may want loose comparisons by default, so if you set
1763 C<cmp> to C<like> you would get SQL such as:
1765 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1767 You can also override the comparison on an individual basis - see
1768 the huge section on L</"WHERE CLAUSES"> at the bottom.
1770 =item sqltrue, sqlfalse
1772 Expressions for inserting boolean values within SQL statements.
1773 By default these are C<1=1> and C<1=0>. They are used
1774 by the special operators C<-in> and C<-not_in> for generating
1775 correct SQL even when the argument is an empty array (see below).
1779 This determines the default logical operator for multiple WHERE
1780 statements in arrays or hashes. If absent, the default logic is "or"
1781 for arrays, and "and" for hashes. This means that a WHERE
1785 event_date => {'>=', '2/13/99'},
1786 event_date => {'<=', '4/24/03'},
1789 will generate SQL like this:
1791 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1793 This is probably not what you want given this query, though (look
1794 at the dates). To change the "OR" to an "AND", simply specify:
1796 my $sql = SQL::Abstract->new(logic => 'and');
1798 Which will change the above C<WHERE> to:
1800 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1802 The logic can also be changed locally by inserting
1803 a modifier in front of an arrayref:
1805 @where = (-and => [event_date => {'>=', '2/13/99'},
1806 event_date => {'<=', '4/24/03'} ]);
1808 See the L</"WHERE CLAUSES"> section for explanations.
1812 This will automatically convert comparisons using the specified SQL
1813 function for both column and value. This is mostly used with an argument
1814 of C<upper> or C<lower>, so that the SQL will have the effect of
1815 case-insensitive "searches". For example, this:
1817 $sql = SQL::Abstract->new(convert => 'upper');
1818 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1820 Will turn out the following SQL:
1822 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1824 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1825 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1826 not validate this option; it will just pass through what you specify verbatim).
1830 This is a kludge because many databases suck. For example, you can't
1831 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1832 Instead, you have to use C<bind_param()>:
1834 $sth->bind_param(1, 'reg data');
1835 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1837 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1838 which loses track of which field each slot refers to. Fear not.
1840 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1841 Currently, you can specify either C<normal> (default) or C<columns>. If you
1842 specify C<columns>, you will get an array that looks like this:
1844 my $sql = SQL::Abstract->new(bindtype => 'columns');
1845 my($stmt, @bind) = $sql->insert(...);
1848 [ 'column1', 'value1' ],
1849 [ 'column2', 'value2' ],
1850 [ 'column3', 'value3' ],
1853 You can then iterate through this manually, using DBI's C<bind_param()>.
1855 $sth->prepare($stmt);
1858 my($col, $data) = @$_;
1859 if ($col eq 'details' || $col eq 'comments') {
1860 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1861 } elsif ($col eq 'image') {
1862 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1864 $sth->bind_param($i, $data);
1868 $sth->execute; # execute without @bind now
1870 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1871 Basically, the advantage is still that you don't have to care which fields
1872 are or are not included. You could wrap that above C<for> loop in a simple
1873 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1874 get a layer of abstraction over manual SQL specification.
1876 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1877 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1878 will expect the bind values in this format.
1882 This is the character that a table or column name will be quoted
1883 with. By default this is an empty string, but you could set it to
1884 the character C<`>, to generate SQL like this:
1886 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1888 Alternatively, you can supply an array ref of two items, the first being the left
1889 hand quote character, and the second the right hand quote character. For
1890 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1891 that generates SQL like this:
1893 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1895 Quoting is useful if you have tables or columns names that are reserved
1896 words in your database's SQL dialect.
1900 This is the character that will be used to escape L</quote_char>s appearing
1901 in an identifier before it has been quoted.
1903 The parameter default in case of a single L</quote_char> character is the quote
1906 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
1907 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
1908 of the B<opening (left)> L</quote_char> within the identifier are currently left
1909 untouched. The default for opening-closing-style quotes may change in future
1910 versions, thus you are B<strongly encouraged> to specify the escape character
1915 This is the character that separates a table and column name. It is
1916 necessary to specify this when the C<quote_char> option is selected,
1917 so that tables and column names can be individually quoted like this:
1919 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1921 =item injection_guard
1923 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1924 column name specified in a query structure. This is a safety mechanism to avoid
1925 injection attacks when mishandling user input e.g.:
1927 my %condition_as_column_value_pairs = get_values_from_user();
1928 $sqla->select( ... , \%condition_as_column_value_pairs );
1930 If the expression matches an exception is thrown. Note that literal SQL
1931 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1933 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1935 =item array_datatypes
1937 When this option is true, arrayrefs in INSERT or UPDATE are
1938 interpreted as array datatypes and are passed directly
1940 When this option is false, arrayrefs are interpreted
1941 as literal SQL, just like refs to arrayrefs
1942 (but this behavior is for backwards compatibility; when writing
1943 new queries, use the "reference to arrayref" syntax
1949 Takes a reference to a list of "special operators"
1950 to extend the syntax understood by L<SQL::Abstract>.
1951 See section L</"SPECIAL OPERATORS"> for details.
1955 Takes a reference to a list of "unary operators"
1956 to extend the syntax understood by L<SQL::Abstract>.
1957 See section L</"UNARY OPERATORS"> for details.
1963 =head2 insert($table, \@values || \%fieldvals, \%options)
1965 This is the simplest function. You simply give it a table name
1966 and either an arrayref of values or hashref of field/value pairs.
1967 It returns an SQL INSERT statement and a list of bind values.
1968 See the sections on L</"Inserting and Updating Arrays"> and
1969 L</"Inserting and Updating SQL"> for information on how to insert
1970 with those data types.
1972 The optional C<\%options> hash reference may contain additional
1973 options to generate the insert SQL. Currently supported options
1980 Takes either a scalar of raw SQL fields, or an array reference of
1981 field names, and adds on an SQL C<RETURNING> statement at the end.
1982 This allows you to return data generated by the insert statement
1983 (such as row IDs) without performing another C<SELECT> statement.
1984 Note, however, this is not part of the SQL standard and may not
1985 be supported by all database engines.
1989 =head2 update($table, \%fieldvals, \%where, \%options)
1991 This takes a table, hashref of field/value pairs, and an optional
1992 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1994 See the sections on L</"Inserting and Updating Arrays"> and
1995 L</"Inserting and Updating SQL"> for information on how to insert
1996 with those data types.
1998 The optional C<\%options> hash reference may contain additional
1999 options to generate the update SQL. Currently supported options
2006 See the C<returning> option to
2007 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2011 =head2 select($source, $fields, $where, $order)
2013 This returns a SQL SELECT statement and associated list of bind values, as
2014 specified by the arguments:
2020 Specification of the 'FROM' part of the statement.
2021 The argument can be either a plain scalar (interpreted as a table
2022 name, will be quoted), or an arrayref (interpreted as a list
2023 of table names, joined by commas, quoted), or a scalarref
2024 (literal SQL, not quoted).
2028 Specification of the list of fields to retrieve from
2030 The argument can be either an arrayref (interpreted as a list
2031 of field names, will be joined by commas and quoted), or a
2032 plain scalar (literal SQL, not quoted).
2033 Please observe that this API is not as flexible as that of
2034 the first argument C<$source>, for backwards compatibility reasons.
2038 Optional argument to specify the WHERE part of the query.
2039 The argument is most often a hashref, but can also be
2040 an arrayref or plain scalar --
2041 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
2045 Optional argument to specify the ORDER BY part of the query.
2046 The argument can be a scalar, a hashref or an arrayref
2047 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
2053 =head2 delete($table, \%where, \%options)
2055 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
2056 It returns an SQL DELETE statement and list of bind values.
2058 The optional C<\%options> hash reference may contain additional
2059 options to generate the delete SQL. Currently supported options
2066 See the C<returning> option to
2067 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2071 =head2 where(\%where, $order)
2073 This is used to generate just the WHERE clause. For example,
2074 if you have an arbitrary data structure and know what the
2075 rest of your SQL is going to look like, but want an easy way
2076 to produce a WHERE clause, use this. It returns an SQL WHERE
2077 clause and list of bind values.
2080 =head2 values(\%data)
2082 This just returns the values from the hash C<%data>, in the same
2083 order that would be returned from any of the other above queries.
2084 Using this allows you to markedly speed up your queries if you
2085 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
2087 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
2089 Warning: This is an experimental method and subject to change.
2091 This returns arbitrarily generated SQL. It's a really basic shortcut.
2092 It will return two different things, depending on return context:
2094 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
2095 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2097 These would return the following:
2099 # First calling form
2100 $stmt = "CREATE TABLE test (?, ?)";
2101 @bind = (field1, field2);
2103 # Second calling form
2104 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2106 Depending on what you're trying to do, it's up to you to choose the correct
2107 format. In this example, the second form is what you would want.
2111 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2115 ALTER SESSION SET nls_date_format = 'MM/YY'
2117 You get the idea. Strings get their case twiddled, but everything
2118 else remains verbatim.
2120 =head1 EXPORTABLE FUNCTIONS
2122 =head2 is_plain_value
2124 Determines if the supplied argument is a plain value as understood by this
2129 =item * The value is C<undef>
2131 =item * The value is a non-reference
2133 =item * The value is an object with stringification overloading
2135 =item * The value is of the form C<< { -value => $anything } >>
2139 On failure returns C<undef>, on success returns a B<scalar> reference
2140 to the original supplied argument.
2146 The stringification overloading detection is rather advanced: it takes
2147 into consideration not only the presence of a C<""> overload, but if that
2148 fails also checks for enabled
2149 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2150 on either C<0+> or C<bool>.
2152 Unfortunately testing in the field indicates that this
2153 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2154 but only when very large numbers of stringifying objects are involved.
2155 At the time of writing ( Sep 2014 ) there is no clear explanation of
2156 the direct cause, nor is there a manageably small test case that reliably
2157 reproduces the problem.
2159 If you encounter any of the following exceptions in B<random places within
2160 your application stack> - this module may be to blame:
2162 Operation "ne": no method found,
2163 left argument in overloaded package <something>,
2164 right argument in overloaded package <something>
2168 Stub found while resolving method "???" overloading """" in package <something>
2170 If you fall victim to the above - please attempt to reduce the problem
2171 to something that could be sent to the L<SQL::Abstract developers
2172 |DBIx::Class/GETTING HELP/SUPPORT>
2173 (either publicly or privately). As a workaround in the meantime you can
2174 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2175 value, which will most likely eliminate your problem (at the expense of
2176 not being able to properly detect exotic forms of stringification).
2178 This notice and environment variable will be removed in a future version,
2179 as soon as the underlying problem is found and a reliable workaround is
2184 =head2 is_literal_value
2186 Determines if the supplied argument is a literal value as understood by this
2191 =item * C<\$sql_string>
2193 =item * C<\[ $sql_string, @bind_values ]>
2197 On failure returns C<undef>, on success returns an B<array> reference
2198 containing the unpacked version of the supplied literal SQL and bind values.
2200 =head1 WHERE CLAUSES
2204 This module uses a variation on the idea from L<DBIx::Abstract>. It
2205 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2206 module is that things in arrays are OR'ed, and things in hashes
2209 The easiest way to explain is to show lots of examples. After
2210 each C<%where> hash shown, it is assumed you used:
2212 my($stmt, @bind) = $sql->where(\%where);
2214 However, note that the C<%where> hash can be used directly in any
2215 of the other functions as well, as described above.
2217 =head2 Key-value pairs
2219 So, let's get started. To begin, a simple hash:
2223 status => 'completed'
2226 Is converted to SQL C<key = val> statements:
2228 $stmt = "WHERE user = ? AND status = ?";
2229 @bind = ('nwiger', 'completed');
2231 One common thing I end up doing is having a list of values that
2232 a field can be in. To do this, simply specify a list inside of
2237 status => ['assigned', 'in-progress', 'pending'];
2240 This simple code will create the following:
2242 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2243 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2245 A field associated to an empty arrayref will be considered a
2246 logical false and will generate 0=1.
2248 =head2 Tests for NULL values
2250 If the value part is C<undef> then this is converted to SQL <IS NULL>
2259 $stmt = "WHERE user = ? AND status IS NULL";
2262 To test if a column IS NOT NULL:
2266 status => { '!=', undef },
2269 =head2 Specific comparison operators
2271 If you want to specify a different type of operator for your comparison,
2272 you can use a hashref for a given column:
2276 status => { '!=', 'completed' }
2279 Which would generate:
2281 $stmt = "WHERE user = ? AND status != ?";
2282 @bind = ('nwiger', 'completed');
2284 To test against multiple values, just enclose the values in an arrayref:
2286 status => { '=', ['assigned', 'in-progress', 'pending'] };
2288 Which would give you:
2290 "WHERE status = ? OR status = ? OR status = ?"
2293 The hashref can also contain multiple pairs, in which case it is expanded
2294 into an C<AND> of its elements:
2298 status => { '!=', 'completed', -not_like => 'pending%' }
2301 # Or more dynamically, like from a form
2302 $where{user} = 'nwiger';
2303 $where{status}{'!='} = 'completed';
2304 $where{status}{'-not_like'} = 'pending%';
2306 # Both generate this
2307 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2308 @bind = ('nwiger', 'completed', 'pending%');
2311 To get an OR instead, you can combine it with the arrayref idea:
2315 priority => [ { '=', 2 }, { '>', 5 } ]
2318 Which would generate:
2320 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2321 @bind = ('2', '5', 'nwiger');
2323 If you want to include literal SQL (with or without bind values), just use a
2324 scalar reference or reference to an arrayref as the value:
2327 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2328 date_expires => { '<' => \"now()" }
2331 Which would generate:
2333 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2334 @bind = ('11/26/2008');
2337 =head2 Logic and nesting operators
2339 In the example above,
2340 there is a subtle trap if you want to say something like
2341 this (notice the C<AND>):
2343 WHERE priority != ? AND priority != ?
2345 Because, in Perl you I<can't> do this:
2347 priority => { '!=' => 2, '!=' => 1 }
2349 As the second C<!=> key will obliterate the first. The solution
2350 is to use the special C<-modifier> form inside an arrayref:
2352 priority => [ -and => {'!=', 2},
2356 Normally, these would be joined by C<OR>, but the modifier tells it
2357 to use C<AND> instead. (Hint: You can use this in conjunction with the
2358 C<logic> option to C<new()> in order to change the way your queries
2359 work by default.) B<Important:> Note that the C<-modifier> goes
2360 B<INSIDE> the arrayref, as an extra first element. This will
2361 B<NOT> do what you think it might:
2363 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2365 Here is a quick list of equivalencies, since there is some overlap:
2368 status => {'!=', 'completed', 'not like', 'pending%' }
2369 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2372 status => {'=', ['assigned', 'in-progress']}
2373 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2374 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2378 =head2 Special operators: IN, BETWEEN, etc.
2380 You can also use the hashref format to compare a list of fields using the
2381 C<IN> comparison operator, by specifying the list as an arrayref:
2384 status => 'completed',
2385 reportid => { -in => [567, 2335, 2] }
2388 Which would generate:
2390 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2391 @bind = ('completed', '567', '2335', '2');
2393 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2396 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2397 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2398 'sqltrue' (by default: C<1=1>).
2400 In addition to the array you can supply a chunk of literal sql or
2401 literal sql with bind:
2404 customer => { -in => \[
2405 'SELECT cust_id FROM cust WHERE balance > ?',
2408 status => { -in => \'SELECT status_codes FROM states' },
2414 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2415 AND status IN ( SELECT status_codes FROM states )
2419 Finally, if the argument to C<-in> is not a reference, it will be
2420 treated as a single-element array.
2422 Another pair of operators is C<-between> and C<-not_between>,
2423 used with an arrayref of two values:
2427 completion_date => {
2428 -not_between => ['2002-10-01', '2003-02-06']
2434 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2436 Just like with C<-in> all plausible combinations of literal SQL
2440 start0 => { -between => [ 1, 2 ] },
2441 start1 => { -between => \["? AND ?", 1, 2] },
2442 start2 => { -between => \"lower(x) AND upper(y)" },
2443 start3 => { -between => [
2445 \["upper(?)", 'stuff' ],
2452 ( start0 BETWEEN ? AND ? )
2453 AND ( start1 BETWEEN ? AND ? )
2454 AND ( start2 BETWEEN lower(x) AND upper(y) )
2455 AND ( start3 BETWEEN lower(x) AND upper(?) )
2457 @bind = (1, 2, 1, 2, 'stuff');
2460 These are the two builtin "special operators"; but the
2461 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2463 =head2 Unary operators: bool
2465 If you wish to test against boolean columns or functions within your
2466 database you can use the C<-bool> and C<-not_bool> operators. For
2467 example to test the column C<is_user> being true and the column
2468 C<is_enabled> being false you would use:-
2472 -not_bool => 'is_enabled',
2477 WHERE is_user AND NOT is_enabled
2479 If a more complex combination is required, testing more conditions,
2480 then you should use the and/or operators:-
2485 -not_bool => { two=> { -rlike => 'bar' } },
2486 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2497 (NOT ( three = ? OR three > ? ))
2500 =head2 Nested conditions, -and/-or prefixes
2502 So far, we've seen how multiple conditions are joined with a top-level
2503 C<AND>. We can change this by putting the different conditions we want in
2504 hashes and then putting those hashes in an array. For example:
2509 status => { -like => ['pending%', 'dispatched'] },
2513 status => 'unassigned',
2517 This data structure would create the following:
2519 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2520 OR ( user = ? AND status = ? ) )";
2521 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2524 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2525 to change the logic inside:
2531 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2532 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2539 $stmt = "WHERE ( user = ?
2540 AND ( ( workhrs > ? AND geo = ? )
2541 OR ( workhrs < ? OR geo = ? ) ) )";
2542 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2544 =head3 Algebraic inconsistency, for historical reasons
2546 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2547 operator goes C<outside> of the nested structure; whereas when connecting
2548 several constraints on one column, the C<-and> operator goes
2549 C<inside> the arrayref. Here is an example combining both features:
2552 -and => [a => 1, b => 2],
2553 -or => [c => 3, d => 4],
2554 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2559 WHERE ( ( ( a = ? AND b = ? )
2560 OR ( c = ? OR d = ? )
2561 OR ( e LIKE ? AND e LIKE ? ) ) )
2563 This difference in syntax is unfortunate but must be preserved for
2564 historical reasons. So be careful: the two examples below would
2565 seem algebraically equivalent, but they are not
2568 { -like => 'foo%' },
2569 { -like => '%bar' },
2571 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2574 { col => { -like => 'foo%' } },
2575 { col => { -like => '%bar' } },
2577 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2580 =head2 Literal SQL and value type operators
2582 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2583 side" is a column name and the "right side" is a value (normally rendered as
2584 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2585 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2586 alter this behavior. There are several ways of doing so.
2590 This is a virtual operator that signals the string to its right side is an
2591 identifier (a column name) and not a value. For example to compare two
2592 columns you would write:
2595 priority => { '<', 2 },
2596 requestor => { -ident => 'submitter' },
2601 $stmt = "WHERE priority < ? AND requestor = submitter";
2604 If you are maintaining legacy code you may see a different construct as
2605 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2610 This is a virtual operator that signals that the construct to its right side
2611 is a value to be passed to DBI. This is for example necessary when you want
2612 to write a where clause against an array (for RDBMS that support such
2613 datatypes). For example:
2616 array => { -value => [1, 2, 3] }
2621 $stmt = 'WHERE array = ?';
2622 @bind = ([1, 2, 3]);
2624 Note that if you were to simply say:
2630 the result would probably not be what you wanted:
2632 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2637 Finally, sometimes only literal SQL will do. To include a random snippet
2638 of SQL verbatim, you specify it as a scalar reference. Consider this only
2639 as a last resort. Usually there is a better way. For example:
2642 priority => { '<', 2 },
2643 requestor => { -in => \'(SELECT name FROM hitmen)' },
2648 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2651 Note that in this example, you only get one bind parameter back, since
2652 the verbatim SQL is passed as part of the statement.
2656 Never use untrusted input as a literal SQL argument - this is a massive
2657 security risk (there is no way to check literal snippets for SQL
2658 injections and other nastyness). If you need to deal with untrusted input
2659 use literal SQL with placeholders as described next.
2661 =head3 Literal SQL with placeholders and bind values (subqueries)
2663 If the literal SQL to be inserted has placeholders and bind values,
2664 use a reference to an arrayref (yes this is a double reference --
2665 not so common, but perfectly legal Perl). For example, to find a date
2666 in Postgres you can use something like this:
2669 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2674 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2677 Note that you must pass the bind values in the same format as they are returned
2678 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2679 to C<columns>, you must provide the bind values in the
2680 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2681 scalar value; most commonly the column name, but you can use any scalar value
2682 (including references and blessed references), L<SQL::Abstract> will simply
2683 pass it through intact. So if C<bindtype> is set to C<columns> the above
2684 example will look like:
2687 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2690 Literal SQL is especially useful for nesting parenthesized clauses in the
2691 main SQL query. Here is a first example:
2693 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2697 bar => \["IN ($sub_stmt)" => @sub_bind],
2702 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2703 WHERE c2 < ? AND c3 LIKE ?))";
2704 @bind = (1234, 100, "foo%");
2706 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2707 are expressed in the same way. Of course the C<$sub_stmt> and
2708 its associated bind values can be generated through a former call
2711 my ($sub_stmt, @sub_bind)
2712 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2713 c3 => {-like => "foo%"}});
2716 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2719 In the examples above, the subquery was used as an operator on a column;
2720 but the same principle also applies for a clause within the main C<%where>
2721 hash, like an EXISTS subquery:
2723 my ($sub_stmt, @sub_bind)
2724 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2725 my %where = ( -and => [
2727 \["EXISTS ($sub_stmt)" => @sub_bind],
2732 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2733 WHERE c1 = ? AND c2 > t0.c0))";
2737 Observe that the condition on C<c2> in the subquery refers to
2738 column C<t0.c0> of the main query: this is I<not> a bind
2739 value, so we have to express it through a scalar ref.
2740 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2741 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2742 what we wanted here.
2744 Finally, here is an example where a subquery is used
2745 for expressing unary negation:
2747 my ($sub_stmt, @sub_bind)
2748 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2749 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2751 lname => {like => '%son%'},
2752 \["NOT ($sub_stmt)" => @sub_bind],
2757 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2758 @bind = ('%son%', 10, 20)
2760 =head3 Deprecated usage of Literal SQL
2762 Below are some examples of archaic use of literal SQL. It is shown only as
2763 reference for those who deal with legacy code. Each example has a much
2764 better, cleaner and safer alternative that users should opt for in new code.
2770 my %where = ( requestor => \'IS NOT NULL' )
2772 $stmt = "WHERE requestor IS NOT NULL"
2774 This used to be the way of generating NULL comparisons, before the handling
2775 of C<undef> got formalized. For new code please use the superior syntax as
2776 described in L</Tests for NULL values>.
2780 my %where = ( requestor => \'= submitter' )
2782 $stmt = "WHERE requestor = submitter"
2784 This used to be the only way to compare columns. Use the superior L</-ident>
2785 method for all new code. For example an identifier declared in such a way
2786 will be properly quoted if L</quote_char> is properly set, while the legacy
2787 form will remain as supplied.
2791 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2793 $stmt = "WHERE completed > ? AND is_ready"
2794 @bind = ('2012-12-21')
2796 Using an empty string literal used to be the only way to express a boolean.
2797 For all new code please use the much more readable
2798 L<-bool|/Unary operators: bool> operator.
2804 These pages could go on for a while, since the nesting of the data
2805 structures this module can handle are pretty much unlimited (the
2806 module implements the C<WHERE> expansion as a recursive function
2807 internally). Your best bet is to "play around" with the module a
2808 little to see how the data structures behave, and choose the best
2809 format for your data based on that.
2811 And of course, all the values above will probably be replaced with
2812 variables gotten from forms or the command line. After all, if you
2813 knew everything ahead of time, you wouldn't have to worry about
2814 dynamically-generating SQL and could just hardwire it into your
2817 =head1 ORDER BY CLAUSES
2819 Some functions take an order by clause. This can either be a scalar (just a
2820 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2821 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2824 Given | Will Generate
2825 ---------------------------------------------------------------
2827 'colA' | ORDER BY colA
2829 [qw/colA colB/] | ORDER BY colA, colB
2831 {-asc => 'colA'} | ORDER BY colA ASC
2833 {-desc => 'colB'} | ORDER BY colB DESC
2835 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2837 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2839 \'colA DESC' | ORDER BY colA DESC
2841 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2842 | /* ...with $x bound to ? */
2845 { -asc => 'colA' }, | colA ASC,
2846 { -desc => [qw/colB/] }, | colB DESC,
2847 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2848 \'colE DESC', | colE DESC,
2849 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2850 ] | /* ...with $x bound to ? */
2851 ===============================================================
2855 =head1 SPECIAL OPERATORS
2857 my $sqlmaker = SQL::Abstract->new(special_ops => [
2861 my ($self, $field, $op, $arg) = @_;
2867 handler => 'method_name',
2871 A "special operator" is a SQL syntactic clause that can be
2872 applied to a field, instead of a usual binary operator.
2875 WHERE field IN (?, ?, ?)
2876 WHERE field BETWEEN ? AND ?
2877 WHERE MATCH(field) AGAINST (?, ?)
2879 Special operators IN and BETWEEN are fairly standard and therefore
2880 are builtin within C<SQL::Abstract> (as the overridable methods
2881 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2882 like the MATCH .. AGAINST example above which is specific to MySQL,
2883 you can write your own operator handlers - supply a C<special_ops>
2884 argument to the C<new> method. That argument takes an arrayref of
2885 operator definitions; each operator definition is a hashref with two
2892 the regular expression to match the operator
2896 Either a coderef or a plain scalar method name. In both cases
2897 the expected return is C<< ($sql, @bind) >>.
2899 When supplied with a method name, it is simply called on the
2900 L<SQL::Abstract> object as:
2902 $self->$method_name($field, $op, $arg)
2906 $field is the LHS of the operator
2907 $op is the part that matched the handler regex
2910 When supplied with a coderef, it is called as:
2912 $coderef->($self, $field, $op, $arg)
2917 For example, here is an implementation
2918 of the MATCH .. AGAINST syntax for MySQL
2920 my $sqlmaker = SQL::Abstract->new(special_ops => [
2922 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2923 {regex => qr/^match$/i,
2925 my ($self, $field, $op, $arg) = @_;
2926 $arg = [$arg] if not ref $arg;
2927 my $label = $self->_quote($field);
2928 my ($placeholder) = $self->_convert('?');
2929 my $placeholders = join ", ", (($placeholder) x @$arg);
2930 my $sql = $self->_sqlcase('match') . " ($label) "
2931 . $self->_sqlcase('against') . " ($placeholders) ";
2932 my @bind = $self->_bindtype($field, @$arg);
2933 return ($sql, @bind);
2940 =head1 UNARY OPERATORS
2942 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2946 my ($self, $op, $arg) = @_;
2952 handler => 'method_name',
2956 A "unary operator" is a SQL syntactic clause that can be
2957 applied to a field - the operator goes before the field
2959 You can write your own operator handlers - supply a C<unary_ops>
2960 argument to the C<new> method. That argument takes an arrayref of
2961 operator definitions; each operator definition is a hashref with two
2968 the regular expression to match the operator
2972 Either a coderef or a plain scalar method name. In both cases
2973 the expected return is C<< $sql >>.
2975 When supplied with a method name, it is simply called on the
2976 L<SQL::Abstract> object as:
2978 $self->$method_name($op, $arg)
2982 $op is the part that matched the handler regex
2983 $arg is the RHS or argument of the operator
2985 When supplied with a coderef, it is called as:
2987 $coderef->($self, $op, $arg)
2995 Thanks to some benchmarking by Mark Stosberg, it turns out that
2996 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2997 I must admit this wasn't an intentional design issue, but it's a
2998 byproduct of the fact that you get to control your C<DBI> handles
3001 To maximize performance, use a code snippet like the following:
3003 # prepare a statement handle using the first row
3004 # and then reuse it for the rest of the rows
3006 for my $href (@array_of_hashrefs) {
3007 $stmt ||= $sql->insert('table', $href);
3008 $sth ||= $dbh->prepare($stmt);
3009 $sth->execute($sql->values($href));
3012 The reason this works is because the keys in your C<$href> are sorted
3013 internally by B<SQL::Abstract>. Thus, as long as your data retains
3014 the same structure, you only have to generate the SQL the first time
3015 around. On subsequent queries, simply use the C<values> function provided
3016 by this module to return your values in the correct order.
3018 However this depends on the values having the same type - if, for
3019 example, the values of a where clause may either have values
3020 (resulting in sql of the form C<column = ?> with a single bind
3021 value), or alternatively the values might be C<undef> (resulting in
3022 sql of the form C<column IS NULL> with no bind value) then the
3023 caching technique suggested will not work.
3027 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
3028 really like this part (I do, at least). Building up a complex query
3029 can be as simple as the following:
3036 use CGI::FormBuilder;
3039 my $form = CGI::FormBuilder->new(...);
3040 my $sql = SQL::Abstract->new;
3042 if ($form->submitted) {
3043 my $field = $form->field;
3044 my $id = delete $field->{id};
3045 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
3048 Of course, you would still have to connect using C<DBI> to run the
3049 query, but the point is that if you make your form look like your
3050 table, the actual query script can be extremely simplistic.
3052 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
3053 a fast interface to returning and formatting data. I frequently
3054 use these three modules together to write complex database query
3055 apps in under 50 lines.
3057 =head1 HOW TO CONTRIBUTE
3059 Contributions are always welcome, in all usable forms (we especially
3060 welcome documentation improvements). The delivery methods include git-
3061 or unified-diff formatted patches, GitHub pull requests, or plain bug
3062 reports either via RT or the Mailing list. Contributors are generally
3063 granted full access to the official repository after their first several
3064 patches pass successful review.
3066 This project is maintained in a git repository. The code and related tools are
3067 accessible at the following locations:
3071 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
3073 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
3075 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
3077 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
3083 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
3084 Great care has been taken to preserve the I<published> behavior
3085 documented in previous versions in the 1.* family; however,
3086 some features that were previously undocumented, or behaved
3087 differently from the documentation, had to be changed in order
3088 to clarify the semantics. Hence, client code that was relying
3089 on some dark areas of C<SQL::Abstract> v1.*
3090 B<might behave differently> in v1.50.
3092 The main changes are:
3098 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
3102 support for the { operator => \"..." } construct (to embed literal SQL)
3106 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
3110 optional support for L<array datatypes|/"Inserting and Updating Arrays">
3114 defensive programming: check arguments
3118 fixed bug with global logic, which was previously implemented
3119 through global variables yielding side-effects. Prior versions would
3120 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3121 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3122 Now this is interpreted
3123 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3128 fixed semantics of _bindtype on array args
3132 dropped the C<_anoncopy> of the %where tree. No longer necessary,
3133 we just avoid shifting arrays within that tree.
3137 dropped the C<_modlogic> function
3141 =head1 ACKNOWLEDGEMENTS
3143 There are a number of individuals that have really helped out with
3144 this module. Unfortunately, most of them submitted bugs via CPAN
3145 so I have no idea who they are! But the people I do know are:
3147 Ash Berlin (order_by hash term support)
3148 Matt Trout (DBIx::Class support)
3149 Mark Stosberg (benchmarking)
3150 Chas Owens (initial "IN" operator support)
3151 Philip Collins (per-field SQL functions)
3152 Eric Kolve (hashref "AND" support)
3153 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3154 Dan Kubb (support for "quote_char" and "name_sep")
3155 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
3156 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
3157 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
3158 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
3159 Oliver Charles (support for "RETURNING" after "INSERT")
3165 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
3169 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3171 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3173 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3174 While not an official support venue, C<DBIx::Class> makes heavy use of
3175 C<SQL::Abstract>, and as such list members there are very familiar with
3176 how to create queries.
3180 This module is free software; you may copy this under the same
3181 terms as perl itself (either the GNU General Public License or
3182 the Artistic License)