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.87';
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/^ is (?: \s+ not )? $/ix, handler => sub { die "NOPE" }},
42 {regex => qr/^ (?: not \s )? in $/ix, handler => sub { die "NOPE" }},
43 {regex => qr/^ ident $/ix, handler => sub { die "NOPE" }},
44 {regex => qr/^ value $/ix, handler => sub { die "NOPE" }},
47 #======================================================================
48 # DEBUGGING AND ERROR REPORTING
49 #======================================================================
52 return unless $_[0]->{debug}; shift; # a little faster
53 my $func = (caller(1))[3];
54 warn "[$func] ", @_, "\n";
58 my($func) = (caller(1))[3];
59 Carp::carp "[$func] Warning: ", @_;
63 my($func) = (caller(1))[3];
64 Carp::croak "[$func] Fatal: ", @_;
67 sub is_literal_value ($) {
68 ref $_[0] eq 'SCALAR' ? [ ${$_[0]} ]
69 : ( ref $_[0] eq 'REF' and ref ${$_[0]} eq 'ARRAY' ) ? [ @${ $_[0] } ]
73 sub is_undef_value ($) {
77 and exists $_[0]->{-value}
78 and not defined $_[0]->{-value}
82 # FIXME XSify - this can be done so much more efficiently
83 sub is_plain_value ($) {
85 ! length ref $_[0] ? \($_[0])
87 ref $_[0] eq 'HASH' and keys %{$_[0]} == 1
89 exists $_[0]->{-value}
90 ) ? \($_[0]->{-value})
92 # reuse @_ for even moar speedz
93 defined ( $_[1] = Scalar::Util::blessed $_[0] )
95 # deliberately not using Devel::OverloadInfo - the checks we are
96 # intersted in are much more limited than the fullblown thing, and
97 # this is a very hot piece of code
99 # simply using ->can('(""') can leave behind stub methods that
100 # break actually using the overload later (see L<perldiag/Stub
101 # found while resolving method "%s" overloading "%s" in package
102 # "%s"> and the source of overload::mycan())
104 # either has stringification which DBI SHOULD prefer out of the box
105 grep { *{ (qq[${_}::(""]) }{CODE} } @{ $_[2] = mro::get_linear_isa( $_[1] ) }
107 # has nummification or boolification, AND fallback is *not* disabled
109 SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION
112 grep { *{"${_}::(0+"}{CODE} } @{$_[2]}
114 grep { *{"${_}::(bool"}{CODE} } @{$_[2]}
118 # no fallback specified at all
119 ! ( ($_[3]) = grep { *{"${_}::()"}{CODE} } @{$_[2]} )
121 # fallback explicitly undef
122 ! defined ${"$_[3]::()"}
135 #======================================================================
137 #======================================================================
141 my $class = ref($self) || $self;
142 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
144 # choose our case by keeping an option around
145 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
147 # default logic for interpreting arrayrefs
148 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
150 # how to return bind vars
151 $opt{bindtype} ||= 'normal';
153 # default comparison is "=", but can be overridden
156 # try to recognize which are the 'equality' and 'inequality' ops
157 # (temporary quickfix (in 2007), should go through a more seasoned API)
158 $opt{equality_op} = qr/^( \Q$opt{cmp}\E | \= )$/ix;
159 $opt{inequality_op} = qr/^( != | <> )$/ix;
161 $opt{like_op} = qr/^ (is_)?r?like $/xi;
162 $opt{not_like_op} = qr/^ (is_)?not_r?like $/xi;
165 $opt{sqltrue} ||= '1=1';
166 $opt{sqlfalse} ||= '0=1';
169 $opt{special_ops} ||= [];
171 # regexes are applied in order, thus push after user-defines
172 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
174 if ($class->isa('DBIx::Class::SQLMaker')) {
175 $opt{is_dbic_sqlmaker} = 1;
176 $opt{disable_old_special_ops} = 1;
180 $opt{unary_ops} ||= [];
182 # rudimentary sanity-check for user supplied bits treated as functions/operators
183 # If a purported function matches this regular expression, an exception is thrown.
184 # Literal SQL is *NOT* subject to this check, only functions (and column names
185 # when quoting is not in effect)
188 # need to guard against ()'s in column names too, but this will break tons of
189 # hacks... ideas anyone?
190 $opt{injection_guard} ||= qr/
196 $opt{expand_unary} = {};
199 -not => '_expand_not',
200 -bool => '_expand_bool',
201 -and => '_expand_op_andor',
202 -or => '_expand_op_andor',
203 -nest => '_expand_nest',
204 -bind => sub { shift; +{ @_ } },
206 -not_in => '_expand_in',
208 my ($self, $node, $args) = @_;
209 +{ $node => [ map $self->expand_expr($_), @$args ] };
211 -between => '_expand_between',
212 -not_between => '_expand_between',
214 my ($self, $node, $args) = @_;
215 my ($op, @opargs) = @$args;
216 +{ $node => [ $op, map $self->expand_expr($_), @opargs ] };
218 (map +($_ => '_expand_op_is'), ('-is', '-is_not')),
222 'between' => '_expand_between',
223 'not_between' => '_expand_between',
224 'in' => '_expand_in',
225 'not_in' => '_expand_in',
226 'nest' => '_expand_nest',
227 (map +($_ => '_expand_op_andor'), ('and', 'or')),
228 (map +($_ => '_expand_op_is'), ('is', 'is_not')),
231 # placeholder for _expand_unop system
233 my %unops = (-ident => '_expand_ident', -value => '_expand_value');
234 foreach my $name (keys %unops) {
235 $opt{expand}{$name} = $unops{$name};
236 my ($op) = $name =~ /^-(.*)$/;
237 $opt{expand_op}{$op} = sub {
238 my ($self, $op, $arg, $k) = @_;
239 return $self->_expand_expr_hashpair_cmp(
240 $k, { "-${op}" => $arg }
247 (map +("-$_", "_render_$_"), qw(op func bind ident literal tuple)),
252 (map +($_ => '_render_op_between'), 'between', 'not_between'),
253 (map +($_ => '_render_op_in'), 'in', 'not_in'),
254 (map +($_ => '_render_unop_postfix'),
255 'is_null', 'is_not_null', 'asc', 'desc',
257 (not => '_render_op_not'),
258 (map +($_ => '_render_op_andor'), qw(and or)),
259 ',' => '_render_op_multop',
262 return bless \%opt, $class;
265 sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
266 sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
268 sub _assert_pass_injection_guard {
269 if ($_[1] =~ $_[0]->{injection_guard}) {
270 my $class = ref $_[0];
271 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
272 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
273 . "{injection_guard} attribute to ${class}->new()"
278 #======================================================================
280 #======================================================================
284 my $table = $self->_table(shift);
285 my $data = shift || return;
288 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
289 my ($sql, @bind) = $self->$method($data);
290 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
292 if ($options->{returning}) {
293 my ($s, @b) = $self->_insert_returning($options);
298 return wantarray ? ($sql, @bind) : $sql;
301 # So that subclasses can override INSERT ... RETURNING separately from
302 # UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
303 sub _insert_returning { shift->_returning(@_) }
306 my ($self, $options) = @_;
308 my $f = $options->{returning};
310 my ($sql, @bind) = $self->render_aqt(
311 $self->_expand_maybe_list_expr($f, -ident)
314 ? $self->_sqlcase(' returning ') . $sql
315 : ($self->_sqlcase(' returning ').$sql, @bind);
318 sub _insert_HASHREF { # explicit list of fields and then values
319 my ($self, $data) = @_;
321 my @fields = sort keys %$data;
323 my ($sql, @bind) = $self->_insert_values($data);
326 $_ = $self->_quote($_) foreach @fields;
327 $sql = "( ".join(", ", @fields).") ".$sql;
329 return ($sql, @bind);
332 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
333 my ($self, $data) = @_;
335 # no names (arrayref) so can't generate bindtype
336 $self->{bindtype} ne 'columns'
337 or belch "can't do 'columns' bindtype when called with arrayref";
339 my (@values, @all_bind);
340 foreach my $value (@$data) {
341 my ($values, @bind) = $self->_insert_value(undef, $value);
342 push @values, $values;
343 push @all_bind, @bind;
345 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
346 return ($sql, @all_bind);
349 sub _insert_ARRAYREFREF { # literal SQL with bind
350 my ($self, $data) = @_;
352 my ($sql, @bind) = @${$data};
353 $self->_assert_bindval_matches_bindtype(@bind);
355 return ($sql, @bind);
359 sub _insert_SCALARREF { # literal SQL without bind
360 my ($self, $data) = @_;
366 my ($self, $data) = @_;
368 my (@values, @all_bind);
369 foreach my $column (sort keys %$data) {
370 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
371 push @values, $values;
372 push @all_bind, @bind;
374 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
375 return ($sql, @all_bind);
379 my ($self, $column, $v) = @_;
381 return $self->render_aqt(
382 $self->_expand_insert_value($column, $v)
386 sub _expand_insert_value {
387 my ($self, $column, $v) = @_;
389 if (ref($v) eq 'ARRAY') {
390 if ($self->{array_datatypes}) {
391 return +{ -bind => [ $column, $v ] };
393 my ($sql, @bind) = @$v;
394 $self->_assert_bindval_matches_bindtype(@bind);
395 return +{ -literal => $v };
397 if (ref($v) eq 'HASH') {
398 if (grep !/^-/, keys %$v) {
399 belch "HASH ref as bind value in insert is not supported";
400 return +{ -bind => [ $column, $v ] };
404 return +{ -bind => [ $column, undef ] };
406 local our $Cur_Col_Meta = $column;
407 return $self->expand_expr($v);
412 #======================================================================
414 #======================================================================
419 my $table = $self->_table(shift);
420 my $data = shift || return;
424 # first build the 'SET' part of the sql statement
425 puke "Unsupported data type specified to \$sql->update"
426 unless ref $data eq 'HASH';
428 my ($sql, @all_bind) = $self->_update_set_values($data);
429 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
433 my($where_sql, @where_bind) = $self->where($where);
435 push @all_bind, @where_bind;
438 if ($options->{returning}) {
439 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
440 $sql .= $returning_sql;
441 push @all_bind, @returning_bind;
444 return wantarray ? ($sql, @all_bind) : $sql;
447 sub _update_set_values {
448 my ($self, $data) = @_;
450 return $self->render_aqt(
451 $self->_expand_update_set_values($data),
455 sub _expand_update_set_values {
456 my ($self, $data) = @_;
457 $self->_expand_maybe_list_expr( [
460 $set = { -bind => $_ } unless defined $set;
461 +{ -op => [ '=', $self->_expand_ident(-ident => $k), $set ] };
467 ? ($self->{array_datatypes}
468 ? [ $k, +{ -bind => [ $k, $v ] } ]
469 : [ $k, +{ -literal => $v } ])
471 local our $Cur_Col_Meta = $k;
472 [ $k, $self->_expand_expr($v) ]
479 # So that subclasses can override UPDATE ... RETURNING separately from
481 sub _update_returning { shift->_returning(@_) }
485 #======================================================================
487 #======================================================================
492 my $table = $self->_table(shift);
493 my $fields = shift || '*';
497 my ($fields_sql, @bind) = $self->_select_fields($fields);
499 my ($where_sql, @where_bind) = $self->where($where, $order);
500 push @bind, @where_bind;
502 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
503 $self->_sqlcase('from'), $table)
506 return wantarray ? ($sql, @bind) : $sql;
510 my ($self, $fields) = @_;
511 return $fields unless ref($fields);
512 return $self->render_aqt(
513 $self->_expand_maybe_list_expr($fields, '-ident')
517 #======================================================================
519 #======================================================================
524 my $table = $self->_table(shift);
528 my($where_sql, @bind) = $self->where($where);
529 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
531 if ($options->{returning}) {
532 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
533 $sql .= $returning_sql;
534 push @bind, @returning_bind;
537 return wantarray ? ($sql, @bind) : $sql;
540 # So that subclasses can override DELETE ... RETURNING separately from
542 sub _delete_returning { shift->_returning(@_) }
546 #======================================================================
548 #======================================================================
552 # Finally, a separate routine just to handle WHERE clauses
554 my ($self, $where, $order) = @_;
556 local $self->{convert_where} = $self->{convert};
559 my ($sql, @bind) = defined($where)
560 ? $self->_recurse_where($where)
562 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
566 my ($order_sql, @order_bind) = $self->_order_by($order);
568 push @bind, @order_bind;
571 return wantarray ? ($sql, @bind) : $sql;
574 { our $Default_Scalar_To = -value }
577 my ($self, $expr, $default_scalar_to) = @_;
578 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
579 $self->_expand_expr($expr);
583 my ($self, $aqt) = @_;
584 my ($k, $v, @rest) = %$aqt;
586 if (my $meth = $self->{render}{$k}) {
587 return $self->$meth($v);
589 die "notreached: $k";
593 my ($self, $expr) = @_;
594 $self->render_aqt($self->expand_expr($expr));
598 my ($self, $raw) = @_;
599 s/^-(?=.)//, s/\s+/_/g for my $op = lc $raw;
604 my ($self, $expr) = @_;
605 our $Expand_Depth ||= 0; local $Expand_Depth = $Expand_Depth + 1;
606 return undef unless defined($expr);
607 if (ref($expr) eq 'HASH') {
608 return undef unless my $kc = keys %$expr;
610 return $self->_expand_op_andor(-and => $expr);
612 my ($key, $value) = %$expr;
613 if ($key =~ /^-/ and $key =~ s/ [_\s]? \d+ $//x ) {
614 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
615 . "You probably wanted ...-and => [ $key => COND1, $key => COND2 ... ]";
617 if (my $exp = $self->{expand}{$key}) {
618 return $self->$exp($key, $value);
620 return $self->_expand_expr_hashpair($key, $value);
622 if (ref($expr) eq 'ARRAY') {
623 my $logic = '-'.lc($self->{logic});
624 return $self->_expand_op_andor($logic, $expr);
626 if (my $literal = is_literal_value($expr)) {
627 return +{ -literal => $literal };
629 if (!ref($expr) or Scalar::Util::blessed($expr)) {
630 return $self->_expand_expr_scalar($expr);
635 sub _expand_expr_hashpair {
636 my ($self, $k, $v) = @_;
637 unless (defined($k) and length($k)) {
638 if (defined($k) and my $literal = is_literal_value($v)) {
639 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
640 return { -literal => $literal };
642 puke "Supplying an empty left hand side argument is not supported";
645 return $self->_expand_expr_hashpair_op($k, $v);
647 return $self->_expand_expr_hashpair_ident($k, $v);
650 sub _expand_expr_hashpair_ident {
651 my ($self, $k, $v) = @_;
653 local our $Cur_Col_Meta = $k;
655 # hash with multiple or no elements is andor
657 if (ref($v) eq 'HASH' and keys %$v != 1) {
658 return $self->_expand_op_andor(-and => $v, $k);
661 # undef needs to be re-sent with cmp to achieve IS/IS NOT NULL
663 if (is_undef_value($v)) {
664 return $self->_expand_expr_hashpair_cmp($k => undef);
667 # scalars and objects get expanded as whatever requested or values
669 if (!ref($v) or Scalar::Util::blessed($v)) {
670 return $self->_expand_expr_hashpair_scalar($k, $v);
673 # single key hashref is a hashtriple
675 if (ref($v) eq 'HASH') {
676 return $self->_expand_expr_hashtriple($k, %$v);
679 # arrayref needs re-engineering over the elements
681 if (ref($v) eq 'ARRAY') {
682 return $self->sqlfalse unless @$v;
683 $self->_debug("ARRAY($k) means distribute over elements");
685 $v->[0] =~ /^-(and|or)$/i
686 ? shift(@{$v = [ @$v ]})
687 : '-'.lc($self->{logic} || 'OR')
689 return $self->_expand_op_andor(
694 if (my $literal = is_literal_value($v)) {
696 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
699 my ($sql, @bind) = @$literal;
700 if ($self->{bindtype} eq 'columns') {
702 $self->_assert_bindval_matches_bindtype($_);
705 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
710 sub _expand_expr_scalar {
711 my ($self, $expr) = @_;
713 return $self->_expand_expr({ (our $Default_Scalar_To) => $expr });
716 sub _expand_expr_hashpair_scalar {
717 my ($self, $k, $v) = @_;
719 return $self->_expand_expr_hashpair_cmp(
720 $k, $self->_expand_expr_scalar($v),
724 sub _expand_expr_hashpair_op {
725 my ($self, $k, $v) = @_;
727 $self->_assert_pass_injection_guard($k =~ /\A-(.*)\Z/s);
729 my $op = $self->_normalize_op($k);
731 # Ops prefixed with -not_ get converted
733 if (my ($rest) = $op =~/^not_(.*)$/) {
736 $self->_expand_expr({ "-${rest}", $v })
742 my $op = join(' ', split '_', $op);
744 # the old special op system requires illegality for top-level use
747 (our $Expand_Depth) == 1
748 and $self->{disable_old_special_ops}
749 and List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}
751 puke "Illegal use of top-level '-$op'"
754 # the old unary op system means we should touch nothing and let it work
756 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
757 return { -op => [ $op, $v ] };
761 # an explicit node type is currently assumed to be expanded (this is almost
762 # certainly wrong and there should be expansion anyway)
764 if ($self->{render}{$k}) {
768 # hashref RHS values get expanded and used as op/func args
773 and (keys %$v)[0] =~ /^-/
775 my ($func) = $k =~ /^-(.*)$/;
777 if (List::Util::first { $func =~ $_->{regex} } @{$self->{special_ops}}) {
778 return +{ -op => [ $func, $self->_expand_expr($v) ] };
781 return +{ -func => [ $func, $self->_expand_expr($v) ] };
784 # scalars and literals get simply expanded
786 if (!ref($v) or is_literal_value($v)) {
787 return +{ -op => [ $op, $self->_expand_expr($v) ] };
793 sub _expand_expr_hashpair_cmp {
794 my ($self, $k, $v) = @_;
795 $self->_expand_expr_hashtriple($k, $self->{cmp}, $v);
798 sub _expand_expr_hashtriple {
799 my ($self, $k, $vk, $vv) = @_;
801 my $ik = $self->_expand_ident(-ident => $k);
803 my $op = $self->_normalize_op($vk);
804 $self->_assert_pass_injection_guard($op);
806 if ($op =~ s/ _? \d+ $//x ) {
807 return $self->_expand_expr($k, { $vk, $vv });
809 if (my $x = $self->{expand_op}{$op}) {
810 local our $Cur_Col_Meta = $k;
811 return $self->$x($op, $vv, $k);
815 my $op = join(' ', split '_', $op);
817 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
818 return { -op => [ $op, $ik, $vv ] };
820 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
824 { -op => [ $op, $vv ] }
828 if (ref($vv) eq 'ARRAY') {
830 my $logic = (defined($raw[0]) and $raw[0] =~ /^-(and|or)$/i)
831 ? shift @raw : '-or';
832 my @values = map +{ $vk => $_ }, @raw;
834 $op =~ $self->{inequality_op}
835 or $op =~ $self->{not_like_op}
837 if (lc($logic) eq '-or' and @values > 1) {
838 belch "A multi-element arrayref as an argument to the inequality op '${\uc(join ' ', split '_', $op)}' "
839 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
840 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
845 # try to DWIM on equality operators
846 return ($self->_dwim_op_to_is($op,
847 "Supplying an empty arrayref to '%s' is deprecated",
848 "operator '%s' applied on an empty array (field '$k')"
849 ) ? $self->sqlfalse : $self->sqltrue);
851 return $self->_expand_op_andor($logic => \@values, $k);
853 if (is_undef_value($vv)) {
854 my $is = ($self->_dwim_op_to_is($op,
855 "Supplying an undefined argument to '%s' is deprecated",
856 "unexpected operator '%s' with undef operand",
857 ) ? 'is' : 'is not');
859 return $self->_expand_expr_hashpair($k => { $is, undef });
861 local our $Cur_Col_Meta = $k;
865 $self->_expand_expr($vv)
870 my ($self, $raw, $empty, $fail) = @_;
872 my $op = $self->_normalize_op($raw);
874 if ($op =~ /^not$/i) {
877 if ($op =~ $self->{equality_op}) {
880 if ($op =~ $self->{like_op}) {
881 belch(sprintf $empty, uc(join ' ', split '_', $op));
884 if ($op =~ $self->{inequality_op}) {
887 if ($op =~ $self->{not_like_op}) {
888 belch(sprintf $empty, uc(join ' ', split '_', $op));
891 puke(sprintf $fail, $op);
895 my ($self, $op, $body) = @_;
896 unless (defined($body) or (ref($body) and ref($body) eq 'ARRAY')) {
897 puke "$op requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
899 my @parts = map split(/\Q${\($self->{name_sep}||'.')}\E/, $_),
900 ref($body) ? @$body : $body;
901 return { -ident => $parts[-1] } if $self->{_dequalify_idents};
902 unless ($self->{quote_char}) {
903 $self->_assert_pass_injection_guard($_) for @parts;
905 return +{ -ident => \@parts };
909 +{ -bind => [ our $Cur_Col_Meta, $_[2] ] };
913 +{ -op => [ 'not', $_[0]->_expand_expr($_[2]) ] };
917 my ($self, undef, $v) = @_;
919 return $self->_expand_expr($v);
921 puke "-bool => undef not supported" unless defined($v);
922 return $self->_expand_ident(-ident => $v);
925 sub _expand_op_andor {
926 my ($self, $logic, $v, $k) = @_;
928 $v = [ map +{ $k, $_ },
930 ? (map +{ $_ => $v->{$_} }, sort keys %$v)
934 my ($logop) = $logic =~ /^-?(.*)$/;
935 if (ref($v) eq 'HASH') {
936 return undef unless keys %$v;
939 map $self->_expand_expr({ $_ => $v->{$_} }),
943 if (ref($v) eq 'ARRAY') {
944 $logop eq 'and' or $logop eq 'or' or puke "unknown logic: $logop";
947 (ref($_) eq 'ARRAY' and @$_)
948 or (ref($_) eq 'HASH' and %$_)
954 while (my ($el) = splice @expr, 0, 1) {
955 puke "Supplying an empty left hand side argument is not supported in array-pairs"
956 unless defined($el) and length($el);
957 my $elref = ref($el);
959 local our $Expand_Depth = 0;
960 push(@res, grep defined, $self->_expand_expr({ $el, shift(@expr) }));
961 } elsif ($elref eq 'ARRAY') {
962 push(@res, grep defined, $self->_expand_expr($el)) if @$el;
963 } elsif (my $l = is_literal_value($el)) {
964 push @res, { -literal => $l };
965 } elsif ($elref eq 'HASH') {
966 local our $Expand_Depth = 0;
967 push @res, grep defined, $self->_expand_expr($el) if %$el;
973 # return $res[0] if @res == 1;
974 return { -op => [ $logop, @res ] };
980 my ($self, $op, $vv, $k) = @_;
982 ($k, $vv) = @$vv unless defined $k;
983 puke "$op can only take undef as argument"
987 and exists($vv->{-value})
988 and !defined($vv->{-value})
990 return +{ -op => [ $op.'_null', $self->expand_expr($k, -ident) ] };
993 sub _expand_between {
994 my ($self, $op, $vv, $k) = @_;
996 $k = shift @{$vv = [ @$vv ]} unless defined $k;
997 my @rhs = map $self->_expand_expr($_),
998 ref($vv) eq 'ARRAY' ? @$vv : $vv;
1000 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
1002 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
1004 puke "Operator '${\uc($op)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
1008 $self->expand_expr(ref($k) ? $k : { -ident => $k }),
1014 my ($self, $raw, $vv, $k) = @_;
1015 $k = shift @{$vv = [ @$vv ]} unless defined $k;
1016 my $op = $self->_normalize_op($raw);
1017 if (my $literal = is_literal_value($vv)) {
1018 my ($sql, @bind) = @$literal;
1019 my $opened_sql = $self->_open_outer_paren($sql);
1021 $op, $self->expand_expr($k, -ident),
1022 [ { -literal => [ $opened_sql, @bind ] } ]
1026 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
1027 . "-${\uc($op)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
1028 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
1029 . 'will emit the logically correct SQL instead of raising this exception)'
1031 puke("Argument passed to the '${\uc($op)}' operator can not be undefined")
1033 my @rhs = map $self->expand_expr($_, -value),
1034 map { defined($_) ? $_: puke($undef_err) }
1035 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
1036 return $self->${\($op =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
1040 $self->expand_expr($k, -ident),
1046 my ($self, $op, $v) = @_;
1047 # DBIx::Class requires a nest warning to be emitted once but the private
1048 # method it overrode to do so no longer exists
1049 if ($self->{is_dbic_sqlmaker}) {
1050 unless (our $Nest_Warned) {
1052 "-nest in search conditions is deprecated, you most probably wanted:\n"
1053 .q|{..., -and => [ \%cond0, \@cond1, \'cond2', \[ 'cond3', [ col => bind ] ], etc. ], ... }|
1058 return $self->_expand_expr($v);
1061 sub _recurse_where {
1062 my ($self, $where, $logic) = @_;
1064 # Special case: top level simple string treated as literal
1066 my $where_exp = (ref($where)
1067 ? $self->_expand_expr($where, $logic)
1068 : { -literal => [ $where ] });
1070 # dispatch expanded expression
1072 my ($sql, @bind) = defined($where_exp) ? $self->render_aqt($where_exp) : (undef);
1073 # DBIx::Class used to call _recurse_where in scalar context
1074 # something else might too...
1076 return ($sql, @bind);
1079 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
1085 my ($self, $ident) = @_;
1087 return $self->_convert($self->_quote($ident));
1091 my ($self, $values) = @_;
1092 my ($sql, @bind) = $self->_render_op([ ',', @$values ]);
1093 return "($sql)", @bind;
1097 my ($self, $rest) = @_;
1098 my ($func, @args) = @$rest;
1102 push @arg_sql, shift @x;
1104 } map [ $self->render_aqt($_) ], @args;
1105 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1109 my ($self, $bind) = @_;
1110 return ($self->_convert('?'), $self->_bindtype(@$bind));
1113 sub _render_literal {
1114 my ($self, $literal) = @_;
1115 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1120 my ($self, $v) = @_;
1121 my ($op, @args) = @$v;
1122 if (my $r = $self->{render_op}{$op}) {
1123 return $self->$r($op, \@args);
1128 my $op = join(' ', split '_', $op);
1130 my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
1131 if ($us and @args > 1) {
1132 puke "Special op '${op}' requires first value to be identifier"
1133 unless my ($ident) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
1134 my $k = join(($self->{name_sep}||'.'), @$ident);
1135 local our $Expand_Depth = 1;
1136 return $self->${\($us->{handler})}($k, $op, $args[1]);
1138 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
1139 return $self->${\($us->{handler})}($op, $args[0]);
1144 return $self->_render_unop_prefix($op, \@args);
1146 return $self->_render_op_multop($op, \@args);
1152 sub _render_op_between {
1153 my ($self, $op, $args) = @_;
1154 my ($left, $low, $high) = @$args;
1155 my ($rhsql, @rhbind) = do {
1157 puke "Single arg to between must be a literal"
1158 unless $low->{-literal};
1161 my ($l, $h) = map [ $self->render_aqt($_) ], $low, $high;
1162 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
1163 @{$l}[1..$#$l], @{$h}[1..$#$h])
1166 my ($lhsql, @lhbind) = $self->render_aqt($left);
1170 $self->_sqlcase(join ' ', split '_', $op),
1178 my ($self, $op, $args) = @_;
1179 my ($lhs, $rhs) = @$args;
1182 my ($sql, @bind) = $self->render_aqt($_);
1183 push @in_bind, @bind;
1186 my ($lhsql, @lbind) = $self->render_aqt($lhs);
1188 $lhsql.' '.$self->_sqlcase(join ' ', split '_', $op).' ( '
1189 .join(', ', @in_sql)
1195 sub _render_op_andor {
1196 my ($self, $op, $args) = @_;
1197 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$args;
1198 return '' unless @parts;
1199 return @{$parts[0]} if @parts == 1;
1200 my ($sql, @bind) = $self->_render_op_multop($op, $args);
1201 return '( '.$sql.' )', @bind;
1204 sub _render_op_multop {
1205 my ($self, $op, $args) = @_;
1206 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$args;
1207 return '' unless @parts;
1208 return @{$parts[0]} if @parts == 1;
1209 my ($final_sql) = join(
1210 ($op eq ',' ? '' : ' ').$self->_sqlcase(join ' ', split '_', $op).' ',
1215 map @{$_}[1..$#$_], @parts
1218 sub _render_op_not {
1219 my ($self, $op, $v) = @_;
1220 my ($sql, @bind) = $self->_render_unop_prefix($op, $v);
1221 return "(${sql})", @bind;
1224 sub _render_unop_prefix {
1225 my ($self, $op, $v) = @_;
1226 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1228 my $op_sql = $self->_sqlcase($op); # join ' ', split '_', $op);
1229 return ("${op_sql} ${expr_sql}", @bind);
1232 sub _render_unop_postfix {
1233 my ($self, $op, $v) = @_;
1234 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1235 my $op_sql = $self->_sqlcase(join ' ', split '_', $op);
1236 return ($expr_sql.' '.$op_sql, @bind);
1239 # Some databases (SQLite) treat col IN (1, 2) different from
1240 # col IN ( (1, 2) ). Use this to strip all outer parens while
1241 # adding them back in the corresponding method
1242 sub _open_outer_paren {
1243 my ($self, $sql) = @_;
1245 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1247 # there are closing parens inside, need the heavy duty machinery
1248 # to reevaluate the extraction starting from $sql (full reevaluation)
1249 if ($inner =~ /\)/) {
1250 require Text::Balanced;
1252 my (undef, $remainder) = do {
1253 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1255 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1258 # the entire expression needs to be a balanced bracketed thing
1259 # (after an extract no remainder sans trailing space)
1260 last if defined $remainder and $remainder =~ /\S/;
1270 #======================================================================
1272 #======================================================================
1274 sub _expand_order_by {
1275 my ($self, $arg) = @_;
1277 return unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
1279 my $expander = sub {
1280 my ($self, $dir, $expr) = @_;
1281 my @to_expand = ref($expr) eq 'ARRAY' ? @$expr : $expr;
1282 foreach my $arg (@to_expand) {
1286 and grep /^-(asc|desc)$/, keys %$arg
1288 puke "ordering direction hash passed to order by must have exactly one key (-asc or -desc)";
1292 defined($dir) ? { -op => [ $dir =~ /^-?(.*)$/ ,=> $_ ] } : $_
1294 map $self->expand_expr($_, -ident),
1295 map ref($_) eq 'ARRAY' ? @$_ : $_, @to_expand;
1296 return undef unless @exp;
1297 return undef if @exp == 1 and not defined($exp[0]);
1298 return +{ -op => [ ',', @exp ] };
1301 local @{$self->{expand}}{qw(-asc -desc)} = (($expander) x 2);
1303 return $self->$expander(undef, $arg);
1307 my ($self, $arg) = @_;
1309 return '' unless defined(my $expanded = $self->_expand_order_by($arg));
1311 my ($sql, @bind) = $self->render_aqt($expanded);
1313 return '' unless length($sql);
1315 my $final_sql = $self->_sqlcase(' order by ').$sql;
1317 return wantarray ? ($final_sql, @bind) : $final_sql;
1320 # _order_by no longer needs to call this so doesn't but DBIC uses it.
1322 sub _order_by_chunks {
1323 my ($self, $arg) = @_;
1325 return () unless defined(my $expanded = $self->_expand_order_by($arg));
1327 return $self->_chunkify_order_by($expanded);
1330 sub _chunkify_order_by {
1331 my ($self, $expanded) = @_;
1333 return grep length, $self->render_aqt($expanded)
1334 if $expanded->{-ident} or @{$expanded->{-literal}||[]} == 1;
1337 if (ref() eq 'HASH' and $_->{-op} and $_->{-op}[0] eq ',') {
1338 my ($comma, @list) = @{$_->{-op}};
1339 return map $self->_chunkify_order_by($_), @list;
1341 return [ $self->render_aqt($_) ];
1345 #======================================================================
1346 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1347 #======================================================================
1353 $self->_expand_maybe_list_expr($from, -ident)
1358 #======================================================================
1360 #======================================================================
1362 sub _expand_maybe_list_expr {
1363 my ($self, $expr, $default) = @_;
1364 return +{ -op => [ ',',
1365 map $self->expand_expr($_, $default),
1366 ref($expr) eq 'ARRAY' ? @$expr : $expr
1370 # highly optimized, as it's called way too often
1372 # my ($self, $label) = @_;
1374 return '' unless defined $_[1];
1375 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1376 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
1378 unless ($_[0]->{quote_char}) {
1379 if (ref($_[1]) eq 'ARRAY') {
1380 return join($_[0]->{name_sep}||'.', @{$_[1]});
1382 $_[0]->_assert_pass_injection_guard($_[1]);
1387 my $qref = ref $_[0]->{quote_char};
1389 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1390 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1391 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1393 my $esc = $_[0]->{escape_char} || $r;
1395 # parts containing * are naturally unquoted
1397 $_[0]->{name_sep}||'',
1401 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1403 (ref($_[1]) eq 'ARRAY'
1407 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1415 # Conversion, if applicable
1417 #my ($self, $arg) = @_;
1418 if ($_[0]->{convert_where}) {
1419 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
1426 #my ($self, $col, @vals) = @_;
1427 # called often - tighten code
1428 return $_[0]->{bindtype} eq 'columns'
1429 ? map {[$_[1], $_]} @_[2 .. $#_]
1434 # Dies if any element of @bind is not in [colname => value] format
1435 # if bindtype is 'columns'.
1436 sub _assert_bindval_matches_bindtype {
1437 # my ($self, @bind) = @_;
1439 if ($self->{bindtype} eq 'columns') {
1441 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1442 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1448 sub _join_sql_clauses {
1449 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1451 if (@$clauses_aref > 1) {
1452 my $join = " " . $self->_sqlcase($logic) . " ";
1453 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1454 return ($sql, @$bind_aref);
1456 elsif (@$clauses_aref) {
1457 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1460 return (); # if no SQL, ignore @$bind_aref
1465 # Fix SQL case, if so requested
1467 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1468 # don't touch the argument ... crooked logic, but let's not change it!
1469 return $_[0]->{case} ? $_[1] : uc($_[1]);
1473 #======================================================================
1474 # DISPATCHING FROM REFKIND
1475 #======================================================================
1478 my ($self, $data) = @_;
1480 return 'UNDEF' unless defined $data;
1482 # blessed objects are treated like scalars
1483 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1485 return 'SCALAR' unless $ref;
1488 while ($ref eq 'REF') {
1490 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1494 return ($ref||'SCALAR') . ('REF' x $n_steps);
1498 my ($self, $data) = @_;
1499 my @try = ($self->_refkind($data));
1500 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1501 push @try, 'FALLBACK';
1505 sub _METHOD_FOR_refkind {
1506 my ($self, $meth_prefix, $data) = @_;
1509 for (@{$self->_try_refkind($data)}) {
1510 $method = $self->can($meth_prefix."_".$_)
1514 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1518 sub _SWITCH_refkind {
1519 my ($self, $data, $dispatch_table) = @_;
1522 for (@{$self->_try_refkind($data)}) {
1523 $coderef = $dispatch_table->{$_}
1527 puke "no dispatch entry for ".$self->_refkind($data)
1536 #======================================================================
1537 # VALUES, GENERATE, AUTOLOAD
1538 #======================================================================
1540 # LDNOTE: original code from nwiger, didn't touch code in that section
1541 # I feel the AUTOLOAD stuff should not be the default, it should
1542 # only be activated on explicit demand by user.
1546 my $data = shift || return;
1547 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1548 unless ref $data eq 'HASH';
1551 foreach my $k (sort keys %$data) {
1552 my $v = $data->{$k};
1553 $self->_SWITCH_refkind($v, {
1555 if ($self->{array_datatypes}) { # array datatype
1556 push @all_bind, $self->_bindtype($k, $v);
1558 else { # literal SQL with bind
1559 my ($sql, @bind) = @$v;
1560 $self->_assert_bindval_matches_bindtype(@bind);
1561 push @all_bind, @bind;
1564 ARRAYREFREF => sub { # literal SQL with bind
1565 my ($sql, @bind) = @${$v};
1566 $self->_assert_bindval_matches_bindtype(@bind);
1567 push @all_bind, @bind;
1569 SCALARREF => sub { # literal SQL without bind
1571 SCALAR_or_UNDEF => sub {
1572 push @all_bind, $self->_bindtype($k, $v);
1583 my(@sql, @sqlq, @sqlv);
1587 if ($ref eq 'HASH') {
1588 for my $k (sort keys %$_) {
1591 my $label = $self->_quote($k);
1592 if ($r eq 'ARRAY') {
1593 # literal SQL with bind
1594 my ($sql, @bind) = @$v;
1595 $self->_assert_bindval_matches_bindtype(@bind);
1596 push @sqlq, "$label = $sql";
1598 } elsif ($r eq 'SCALAR') {
1599 # literal SQL without bind
1600 push @sqlq, "$label = $$v";
1602 push @sqlq, "$label = ?";
1603 push @sqlv, $self->_bindtype($k, $v);
1606 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1607 } elsif ($ref eq 'ARRAY') {
1608 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1611 if ($r eq 'ARRAY') { # literal SQL with bind
1612 my ($sql, @bind) = @$v;
1613 $self->_assert_bindval_matches_bindtype(@bind);
1616 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1617 # embedded literal SQL
1624 push @sql, '(' . join(', ', @sqlq) . ')';
1625 } elsif ($ref eq 'SCALAR') {
1629 # strings get case twiddled
1630 push @sql, $self->_sqlcase($_);
1634 my $sql = join ' ', @sql;
1636 # this is pretty tricky
1637 # if ask for an array, return ($stmt, @bind)
1638 # otherwise, s/?/shift @sqlv/ to put it inline
1640 return ($sql, @sqlv);
1642 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1643 ref $d ? $d->[1] : $d/e;
1652 # This allows us to check for a local, then _form, attr
1654 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1655 return $self->generate($name, @_);
1666 SQL::Abstract - Generate SQL from Perl data structures
1672 my $sql = SQL::Abstract->new;
1674 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1676 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1678 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1680 my($stmt, @bind) = $sql->delete($table, \%where);
1682 # Then, use these in your DBI statements
1683 my $sth = $dbh->prepare($stmt);
1684 $sth->execute(@bind);
1686 # Just generate the WHERE clause
1687 my($stmt, @bind) = $sql->where(\%where, $order);
1689 # Return values in the same order, for hashed queries
1690 # See PERFORMANCE section for more details
1691 my @bind = $sql->values(\%fieldvals);
1695 This module was inspired by the excellent L<DBIx::Abstract>.
1696 However, in using that module I found that what I really wanted
1697 to do was generate SQL, but still retain complete control over my
1698 statement handles and use the DBI interface. So, I set out to
1699 create an abstract SQL generation module.
1701 While based on the concepts used by L<DBIx::Abstract>, there are
1702 several important differences, especially when it comes to WHERE
1703 clauses. I have modified the concepts used to make the SQL easier
1704 to generate from Perl data structures and, IMO, more intuitive.
1705 The underlying idea is for this module to do what you mean, based
1706 on the data structures you provide it. The big advantage is that
1707 you don't have to modify your code every time your data changes,
1708 as this module figures it out.
1710 To begin with, an SQL INSERT is as easy as just specifying a hash
1711 of C<key=value> pairs:
1714 name => 'Jimbo Bobson',
1715 phone => '123-456-7890',
1716 address => '42 Sister Lane',
1717 city => 'St. Louis',
1718 state => 'Louisiana',
1721 The SQL can then be generated with this:
1723 my($stmt, @bind) = $sql->insert('people', \%data);
1725 Which would give you something like this:
1727 $stmt = "INSERT INTO people
1728 (address, city, name, phone, state)
1729 VALUES (?, ?, ?, ?, ?)";
1730 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1731 '123-456-7890', 'Louisiana');
1733 These are then used directly in your DBI code:
1735 my $sth = $dbh->prepare($stmt);
1736 $sth->execute(@bind);
1738 =head2 Inserting and Updating Arrays
1740 If your database has array types (like for example Postgres),
1741 activate the special option C<< array_datatypes => 1 >>
1742 when creating the C<SQL::Abstract> object.
1743 Then you may use an arrayref to insert and update database array types:
1745 my $sql = SQL::Abstract->new(array_datatypes => 1);
1747 planets => [qw/Mercury Venus Earth Mars/]
1750 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1754 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1756 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1759 =head2 Inserting and Updating SQL
1761 In order to apply SQL functions to elements of your C<%data> you may
1762 specify a reference to an arrayref for the given hash value. For example,
1763 if you need to execute the Oracle C<to_date> function on a value, you can
1764 say something like this:
1768 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1771 The first value in the array is the actual SQL. Any other values are
1772 optional and would be included in the bind values array. This gives
1775 my($stmt, @bind) = $sql->insert('people', \%data);
1777 $stmt = "INSERT INTO people (name, date_entered)
1778 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1779 @bind = ('Bill', '03/02/2003');
1781 An UPDATE is just as easy, all you change is the name of the function:
1783 my($stmt, @bind) = $sql->update('people', \%data);
1785 Notice that your C<%data> isn't touched; the module will generate
1786 the appropriately quirky SQL for you automatically. Usually you'll
1787 want to specify a WHERE clause for your UPDATE, though, which is
1788 where handling C<%where> hashes comes in handy...
1790 =head2 Complex where statements
1792 This module can generate pretty complicated WHERE statements
1793 easily. For example, simple C<key=value> pairs are taken to mean
1794 equality, and if you want to see if a field is within a set
1795 of values, you can use an arrayref. Let's say we wanted to
1796 SELECT some data based on this criteria:
1799 requestor => 'inna',
1800 worker => ['nwiger', 'rcwe', 'sfz'],
1801 status => { '!=', 'completed' }
1804 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1806 The above would give you something like this:
1808 $stmt = "SELECT * FROM tickets WHERE
1809 ( requestor = ? ) AND ( status != ? )
1810 AND ( worker = ? OR worker = ? OR worker = ? )";
1811 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1813 Which you could then use in DBI code like so:
1815 my $sth = $dbh->prepare($stmt);
1816 $sth->execute(@bind);
1822 The methods are simple. There's one for every major SQL operation,
1823 and a constructor you use first. The arguments are specified in a
1824 similar order for each method (table, then fields, then a where
1825 clause) to try and simplify things.
1827 =head2 new(option => 'value')
1829 The C<new()> function takes a list of options and values, and returns
1830 a new B<SQL::Abstract> object which can then be used to generate SQL
1831 through the methods below. The options accepted are:
1837 If set to 'lower', then SQL will be generated in all lowercase. By
1838 default SQL is generated in "textbook" case meaning something like:
1840 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1842 Any setting other than 'lower' is ignored.
1846 This determines what the default comparison operator is. By default
1847 it is C<=>, meaning that a hash like this:
1849 %where = (name => 'nwiger', email => 'nate@wiger.org');
1851 Will generate SQL like this:
1853 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1855 However, you may want loose comparisons by default, so if you set
1856 C<cmp> to C<like> you would get SQL such as:
1858 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1860 You can also override the comparison on an individual basis - see
1861 the huge section on L</"WHERE CLAUSES"> at the bottom.
1863 =item sqltrue, sqlfalse
1865 Expressions for inserting boolean values within SQL statements.
1866 By default these are C<1=1> and C<1=0>. They are used
1867 by the special operators C<-in> and C<-not_in> for generating
1868 correct SQL even when the argument is an empty array (see below).
1872 This determines the default logical operator for multiple WHERE
1873 statements in arrays or hashes. If absent, the default logic is "or"
1874 for arrays, and "and" for hashes. This means that a WHERE
1878 event_date => {'>=', '2/13/99'},
1879 event_date => {'<=', '4/24/03'},
1882 will generate SQL like this:
1884 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1886 This is probably not what you want given this query, though (look
1887 at the dates). To change the "OR" to an "AND", simply specify:
1889 my $sql = SQL::Abstract->new(logic => 'and');
1891 Which will change the above C<WHERE> to:
1893 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1895 The logic can also be changed locally by inserting
1896 a modifier in front of an arrayref:
1898 @where = (-and => [event_date => {'>=', '2/13/99'},
1899 event_date => {'<=', '4/24/03'} ]);
1901 See the L</"WHERE CLAUSES"> section for explanations.
1905 This will automatically convert comparisons using the specified SQL
1906 function for both column and value. This is mostly used with an argument
1907 of C<upper> or C<lower>, so that the SQL will have the effect of
1908 case-insensitive "searches". For example, this:
1910 $sql = SQL::Abstract->new(convert => 'upper');
1911 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1913 Will turn out the following SQL:
1915 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1917 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1918 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1919 not validate this option; it will just pass through what you specify verbatim).
1923 This is a kludge because many databases suck. For example, you can't
1924 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1925 Instead, you have to use C<bind_param()>:
1927 $sth->bind_param(1, 'reg data');
1928 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1930 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1931 which loses track of which field each slot refers to. Fear not.
1933 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1934 Currently, you can specify either C<normal> (default) or C<columns>. If you
1935 specify C<columns>, you will get an array that looks like this:
1937 my $sql = SQL::Abstract->new(bindtype => 'columns');
1938 my($stmt, @bind) = $sql->insert(...);
1941 [ 'column1', 'value1' ],
1942 [ 'column2', 'value2' ],
1943 [ 'column3', 'value3' ],
1946 You can then iterate through this manually, using DBI's C<bind_param()>.
1948 $sth->prepare($stmt);
1951 my($col, $data) = @$_;
1952 if ($col eq 'details' || $col eq 'comments') {
1953 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1954 } elsif ($col eq 'image') {
1955 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1957 $sth->bind_param($i, $data);
1961 $sth->execute; # execute without @bind now
1963 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1964 Basically, the advantage is still that you don't have to care which fields
1965 are or are not included. You could wrap that above C<for> loop in a simple
1966 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1967 get a layer of abstraction over manual SQL specification.
1969 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1970 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1971 will expect the bind values in this format.
1975 This is the character that a table or column name will be quoted
1976 with. By default this is an empty string, but you could set it to
1977 the character C<`>, to generate SQL like this:
1979 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1981 Alternatively, you can supply an array ref of two items, the first being the left
1982 hand quote character, and the second the right hand quote character. For
1983 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1984 that generates SQL like this:
1986 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1988 Quoting is useful if you have tables or columns names that are reserved
1989 words in your database's SQL dialect.
1993 This is the character that will be used to escape L</quote_char>s appearing
1994 in an identifier before it has been quoted.
1996 The parameter default in case of a single L</quote_char> character is the quote
1999 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
2000 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
2001 of the B<opening (left)> L</quote_char> within the identifier are currently left
2002 untouched. The default for opening-closing-style quotes may change in future
2003 versions, thus you are B<strongly encouraged> to specify the escape character
2008 This is the character that separates a table and column name. It is
2009 necessary to specify this when the C<quote_char> option is selected,
2010 so that tables and column names can be individually quoted like this:
2012 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
2014 =item injection_guard
2016 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
2017 column name specified in a query structure. This is a safety mechanism to avoid
2018 injection attacks when mishandling user input e.g.:
2020 my %condition_as_column_value_pairs = get_values_from_user();
2021 $sqla->select( ... , \%condition_as_column_value_pairs );
2023 If the expression matches an exception is thrown. Note that literal SQL
2024 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
2026 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
2028 =item array_datatypes
2030 When this option is true, arrayrefs in INSERT or UPDATE are
2031 interpreted as array datatypes and are passed directly
2033 When this option is false, arrayrefs are interpreted
2034 as literal SQL, just like refs to arrayrefs
2035 (but this behavior is for backwards compatibility; when writing
2036 new queries, use the "reference to arrayref" syntax
2042 Takes a reference to a list of "special operators"
2043 to extend the syntax understood by L<SQL::Abstract>.
2044 See section L</"SPECIAL OPERATORS"> for details.
2048 Takes a reference to a list of "unary operators"
2049 to extend the syntax understood by L<SQL::Abstract>.
2050 See section L</"UNARY OPERATORS"> for details.
2056 =head2 insert($table, \@values || \%fieldvals, \%options)
2058 This is the simplest function. You simply give it a table name
2059 and either an arrayref of values or hashref of field/value pairs.
2060 It returns an SQL INSERT statement and a list of bind values.
2061 See the sections on L</"Inserting and Updating Arrays"> and
2062 L</"Inserting and Updating SQL"> for information on how to insert
2063 with those data types.
2065 The optional C<\%options> hash reference may contain additional
2066 options to generate the insert SQL. Currently supported options
2073 Takes either a scalar of raw SQL fields, or an array reference of
2074 field names, and adds on an SQL C<RETURNING> statement at the end.
2075 This allows you to return data generated by the insert statement
2076 (such as row IDs) without performing another C<SELECT> statement.
2077 Note, however, this is not part of the SQL standard and may not
2078 be supported by all database engines.
2082 =head2 update($table, \%fieldvals, \%where, \%options)
2084 This takes a table, hashref of field/value pairs, and an optional
2085 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
2087 See the sections on L</"Inserting and Updating Arrays"> and
2088 L</"Inserting and Updating SQL"> for information on how to insert
2089 with those data types.
2091 The optional C<\%options> hash reference may contain additional
2092 options to generate the update SQL. Currently supported options
2099 See the C<returning> option to
2100 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2104 =head2 select($source, $fields, $where, $order)
2106 This returns a SQL SELECT statement and associated list of bind values, as
2107 specified by the arguments:
2113 Specification of the 'FROM' part of the statement.
2114 The argument can be either a plain scalar (interpreted as a table
2115 name, will be quoted), or an arrayref (interpreted as a list
2116 of table names, joined by commas, quoted), or a scalarref
2117 (literal SQL, not quoted).
2121 Specification of the list of fields to retrieve from
2123 The argument can be either an arrayref (interpreted as a list
2124 of field names, will be joined by commas and quoted), or a
2125 plain scalar (literal SQL, not quoted).
2126 Please observe that this API is not as flexible as that of
2127 the first argument C<$source>, for backwards compatibility reasons.
2131 Optional argument to specify the WHERE part of the query.
2132 The argument is most often a hashref, but can also be
2133 an arrayref or plain scalar --
2134 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
2138 Optional argument to specify the ORDER BY part of the query.
2139 The argument can be a scalar, a hashref or an arrayref
2140 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
2146 =head2 delete($table, \%where, \%options)
2148 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
2149 It returns an SQL DELETE statement and list of bind values.
2151 The optional C<\%options> hash reference may contain additional
2152 options to generate the delete SQL. Currently supported options
2159 See the C<returning> option to
2160 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2164 =head2 where(\%where, $order)
2166 This is used to generate just the WHERE clause. For example,
2167 if you have an arbitrary data structure and know what the
2168 rest of your SQL is going to look like, but want an easy way
2169 to produce a WHERE clause, use this. It returns an SQL WHERE
2170 clause and list of bind values.
2173 =head2 values(\%data)
2175 This just returns the values from the hash C<%data>, in the same
2176 order that would be returned from any of the other above queries.
2177 Using this allows you to markedly speed up your queries if you
2178 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
2180 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
2182 Warning: This is an experimental method and subject to change.
2184 This returns arbitrarily generated SQL. It's a really basic shortcut.
2185 It will return two different things, depending on return context:
2187 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
2188 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2190 These would return the following:
2192 # First calling form
2193 $stmt = "CREATE TABLE test (?, ?)";
2194 @bind = (field1, field2);
2196 # Second calling form
2197 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2199 Depending on what you're trying to do, it's up to you to choose the correct
2200 format. In this example, the second form is what you would want.
2204 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2208 ALTER SESSION SET nls_date_format = 'MM/YY'
2210 You get the idea. Strings get their case twiddled, but everything
2211 else remains verbatim.
2213 =head1 EXPORTABLE FUNCTIONS
2215 =head2 is_plain_value
2217 Determines if the supplied argument is a plain value as understood by this
2222 =item * The value is C<undef>
2224 =item * The value is a non-reference
2226 =item * The value is an object with stringification overloading
2228 =item * The value is of the form C<< { -value => $anything } >>
2232 On failure returns C<undef>, on success returns a B<scalar> reference
2233 to the original supplied argument.
2239 The stringification overloading detection is rather advanced: it takes
2240 into consideration not only the presence of a C<""> overload, but if that
2241 fails also checks for enabled
2242 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2243 on either C<0+> or C<bool>.
2245 Unfortunately testing in the field indicates that this
2246 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2247 but only when very large numbers of stringifying objects are involved.
2248 At the time of writing ( Sep 2014 ) there is no clear explanation of
2249 the direct cause, nor is there a manageably small test case that reliably
2250 reproduces the problem.
2252 If you encounter any of the following exceptions in B<random places within
2253 your application stack> - this module may be to blame:
2255 Operation "ne": no method found,
2256 left argument in overloaded package <something>,
2257 right argument in overloaded package <something>
2261 Stub found while resolving method "???" overloading """" in package <something>
2263 If you fall victim to the above - please attempt to reduce the problem
2264 to something that could be sent to the L<SQL::Abstract developers
2265 |DBIx::Class/GETTING HELP/SUPPORT>
2266 (either publicly or privately). As a workaround in the meantime you can
2267 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2268 value, which will most likely eliminate your problem (at the expense of
2269 not being able to properly detect exotic forms of stringification).
2271 This notice and environment variable will be removed in a future version,
2272 as soon as the underlying problem is found and a reliable workaround is
2277 =head2 is_literal_value
2279 Determines if the supplied argument is a literal value as understood by this
2284 =item * C<\$sql_string>
2286 =item * C<\[ $sql_string, @bind_values ]>
2290 On failure returns C<undef>, on success returns an B<array> reference
2291 containing the unpacked version of the supplied literal SQL and bind values.
2293 =head1 WHERE CLAUSES
2297 This module uses a variation on the idea from L<DBIx::Abstract>. It
2298 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2299 module is that things in arrays are OR'ed, and things in hashes
2302 The easiest way to explain is to show lots of examples. After
2303 each C<%where> hash shown, it is assumed you used:
2305 my($stmt, @bind) = $sql->where(\%where);
2307 However, note that the C<%where> hash can be used directly in any
2308 of the other functions as well, as described above.
2310 =head2 Key-value pairs
2312 So, let's get started. To begin, a simple hash:
2316 status => 'completed'
2319 Is converted to SQL C<key = val> statements:
2321 $stmt = "WHERE user = ? AND status = ?";
2322 @bind = ('nwiger', 'completed');
2324 One common thing I end up doing is having a list of values that
2325 a field can be in. To do this, simply specify a list inside of
2330 status => ['assigned', 'in-progress', 'pending'];
2333 This simple code will create the following:
2335 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2336 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2338 A field associated to an empty arrayref will be considered a
2339 logical false and will generate 0=1.
2341 =head2 Tests for NULL values
2343 If the value part is C<undef> then this is converted to SQL <IS NULL>
2352 $stmt = "WHERE user = ? AND status IS NULL";
2355 To test if a column IS NOT NULL:
2359 status => { '!=', undef },
2362 =head2 Specific comparison operators
2364 If you want to specify a different type of operator for your comparison,
2365 you can use a hashref for a given column:
2369 status => { '!=', 'completed' }
2372 Which would generate:
2374 $stmt = "WHERE user = ? AND status != ?";
2375 @bind = ('nwiger', 'completed');
2377 To test against multiple values, just enclose the values in an arrayref:
2379 status => { '=', ['assigned', 'in-progress', 'pending'] };
2381 Which would give you:
2383 "WHERE status = ? OR status = ? OR status = ?"
2386 The hashref can also contain multiple pairs, in which case it is expanded
2387 into an C<AND> of its elements:
2391 status => { '!=', 'completed', -not_like => 'pending%' }
2394 # Or more dynamically, like from a form
2395 $where{user} = 'nwiger';
2396 $where{status}{'!='} = 'completed';
2397 $where{status}{'-not_like'} = 'pending%';
2399 # Both generate this
2400 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2401 @bind = ('nwiger', 'completed', 'pending%');
2404 To get an OR instead, you can combine it with the arrayref idea:
2408 priority => [ { '=', 2 }, { '>', 5 } ]
2411 Which would generate:
2413 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2414 @bind = ('2', '5', 'nwiger');
2416 If you want to include literal SQL (with or without bind values), just use a
2417 scalar reference or reference to an arrayref as the value:
2420 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2421 date_expires => { '<' => \"now()" }
2424 Which would generate:
2426 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2427 @bind = ('11/26/2008');
2430 =head2 Logic and nesting operators
2432 In the example above,
2433 there is a subtle trap if you want to say something like
2434 this (notice the C<AND>):
2436 WHERE priority != ? AND priority != ?
2438 Because, in Perl you I<can't> do this:
2440 priority => { '!=' => 2, '!=' => 1 }
2442 As the second C<!=> key will obliterate the first. The solution
2443 is to use the special C<-modifier> form inside an arrayref:
2445 priority => [ -and => {'!=', 2},
2449 Normally, these would be joined by C<OR>, but the modifier tells it
2450 to use C<AND> instead. (Hint: You can use this in conjunction with the
2451 C<logic> option to C<new()> in order to change the way your queries
2452 work by default.) B<Important:> Note that the C<-modifier> goes
2453 B<INSIDE> the arrayref, as an extra first element. This will
2454 B<NOT> do what you think it might:
2456 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2458 Here is a quick list of equivalencies, since there is some overlap:
2461 status => {'!=', 'completed', 'not like', 'pending%' }
2462 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2465 status => {'=', ['assigned', 'in-progress']}
2466 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2467 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2471 =head2 Special operators: IN, BETWEEN, etc.
2473 You can also use the hashref format to compare a list of fields using the
2474 C<IN> comparison operator, by specifying the list as an arrayref:
2477 status => 'completed',
2478 reportid => { -in => [567, 2335, 2] }
2481 Which would generate:
2483 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2484 @bind = ('completed', '567', '2335', '2');
2486 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2489 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2490 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2491 'sqltrue' (by default: C<1=1>).
2493 In addition to the array you can supply a chunk of literal sql or
2494 literal sql with bind:
2497 customer => { -in => \[
2498 'SELECT cust_id FROM cust WHERE balance > ?',
2501 status => { -in => \'SELECT status_codes FROM states' },
2507 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2508 AND status IN ( SELECT status_codes FROM states )
2512 Finally, if the argument to C<-in> is not a reference, it will be
2513 treated as a single-element array.
2515 Another pair of operators is C<-between> and C<-not_between>,
2516 used with an arrayref of two values:
2520 completion_date => {
2521 -not_between => ['2002-10-01', '2003-02-06']
2527 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2529 Just like with C<-in> all plausible combinations of literal SQL
2533 start0 => { -between => [ 1, 2 ] },
2534 start1 => { -between => \["? AND ?", 1, 2] },
2535 start2 => { -between => \"lower(x) AND upper(y)" },
2536 start3 => { -between => [
2538 \["upper(?)", 'stuff' ],
2545 ( start0 BETWEEN ? AND ? )
2546 AND ( start1 BETWEEN ? AND ? )
2547 AND ( start2 BETWEEN lower(x) AND upper(y) )
2548 AND ( start3 BETWEEN lower(x) AND upper(?) )
2550 @bind = (1, 2, 1, 2, 'stuff');
2553 These are the two builtin "special operators"; but the
2554 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2556 =head2 Unary operators: bool
2558 If you wish to test against boolean columns or functions within your
2559 database you can use the C<-bool> and C<-not_bool> operators. For
2560 example to test the column C<is_user> being true and the column
2561 C<is_enabled> being false you would use:-
2565 -not_bool => 'is_enabled',
2570 WHERE is_user AND NOT is_enabled
2572 If a more complex combination is required, testing more conditions,
2573 then you should use the and/or operators:-
2578 -not_bool => { two=> { -rlike => 'bar' } },
2579 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2590 (NOT ( three = ? OR three > ? ))
2593 =head2 Nested conditions, -and/-or prefixes
2595 So far, we've seen how multiple conditions are joined with a top-level
2596 C<AND>. We can change this by putting the different conditions we want in
2597 hashes and then putting those hashes in an array. For example:
2602 status => { -like => ['pending%', 'dispatched'] },
2606 status => 'unassigned',
2610 This data structure would create the following:
2612 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2613 OR ( user = ? AND status = ? ) )";
2614 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2617 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2618 to change the logic inside:
2624 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2625 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2632 $stmt = "WHERE ( user = ?
2633 AND ( ( workhrs > ? AND geo = ? )
2634 OR ( workhrs < ? OR geo = ? ) ) )";
2635 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2637 =head3 Algebraic inconsistency, for historical reasons
2639 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2640 operator goes C<outside> of the nested structure; whereas when connecting
2641 several constraints on one column, the C<-and> operator goes
2642 C<inside> the arrayref. Here is an example combining both features:
2645 -and => [a => 1, b => 2],
2646 -or => [c => 3, d => 4],
2647 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2652 WHERE ( ( ( a = ? AND b = ? )
2653 OR ( c = ? OR d = ? )
2654 OR ( e LIKE ? AND e LIKE ? ) ) )
2656 This difference in syntax is unfortunate but must be preserved for
2657 historical reasons. So be careful: the two examples below would
2658 seem algebraically equivalent, but they are not
2661 { -like => 'foo%' },
2662 { -like => '%bar' },
2664 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2667 { col => { -like => 'foo%' } },
2668 { col => { -like => '%bar' } },
2670 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2673 =head2 Literal SQL and value type operators
2675 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2676 side" is a column name and the "right side" is a value (normally rendered as
2677 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2678 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2679 alter this behavior. There are several ways of doing so.
2683 This is a virtual operator that signals the string to its right side is an
2684 identifier (a column name) and not a value. For example to compare two
2685 columns you would write:
2688 priority => { '<', 2 },
2689 requestor => { -ident => 'submitter' },
2694 $stmt = "WHERE priority < ? AND requestor = submitter";
2697 If you are maintaining legacy code you may see a different construct as
2698 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2703 This is a virtual operator that signals that the construct to its right side
2704 is a value to be passed to DBI. This is for example necessary when you want
2705 to write a where clause against an array (for RDBMS that support such
2706 datatypes). For example:
2709 array => { -value => [1, 2, 3] }
2714 $stmt = 'WHERE array = ?';
2715 @bind = ([1, 2, 3]);
2717 Note that if you were to simply say:
2723 the result would probably not be what you wanted:
2725 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2730 Finally, sometimes only literal SQL will do. To include a random snippet
2731 of SQL verbatim, you specify it as a scalar reference. Consider this only
2732 as a last resort. Usually there is a better way. For example:
2735 priority => { '<', 2 },
2736 requestor => { -in => \'(SELECT name FROM hitmen)' },
2741 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2744 Note that in this example, you only get one bind parameter back, since
2745 the verbatim SQL is passed as part of the statement.
2749 Never use untrusted input as a literal SQL argument - this is a massive
2750 security risk (there is no way to check literal snippets for SQL
2751 injections and other nastyness). If you need to deal with untrusted input
2752 use literal SQL with placeholders as described next.
2754 =head3 Literal SQL with placeholders and bind values (subqueries)
2756 If the literal SQL to be inserted has placeholders and bind values,
2757 use a reference to an arrayref (yes this is a double reference --
2758 not so common, but perfectly legal Perl). For example, to find a date
2759 in Postgres you can use something like this:
2762 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2767 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2770 Note that you must pass the bind values in the same format as they are returned
2771 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2772 to C<columns>, you must provide the bind values in the
2773 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2774 scalar value; most commonly the column name, but you can use any scalar value
2775 (including references and blessed references), L<SQL::Abstract> will simply
2776 pass it through intact. So if C<bindtype> is set to C<columns> the above
2777 example will look like:
2780 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2783 Literal SQL is especially useful for nesting parenthesized clauses in the
2784 main SQL query. Here is a first example:
2786 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2790 bar => \["IN ($sub_stmt)" => @sub_bind],
2795 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2796 WHERE c2 < ? AND c3 LIKE ?))";
2797 @bind = (1234, 100, "foo%");
2799 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2800 are expressed in the same way. Of course the C<$sub_stmt> and
2801 its associated bind values can be generated through a former call
2804 my ($sub_stmt, @sub_bind)
2805 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2806 c3 => {-like => "foo%"}});
2809 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2812 In the examples above, the subquery was used as an operator on a column;
2813 but the same principle also applies for a clause within the main C<%where>
2814 hash, like an EXISTS subquery:
2816 my ($sub_stmt, @sub_bind)
2817 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2818 my %where = ( -and => [
2820 \["EXISTS ($sub_stmt)" => @sub_bind],
2825 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2826 WHERE c1 = ? AND c2 > t0.c0))";
2830 Observe that the condition on C<c2> in the subquery refers to
2831 column C<t0.c0> of the main query: this is I<not> a bind
2832 value, so we have to express it through a scalar ref.
2833 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2834 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2835 what we wanted here.
2837 Finally, here is an example where a subquery is used
2838 for expressing unary negation:
2840 my ($sub_stmt, @sub_bind)
2841 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2842 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2844 lname => {like => '%son%'},
2845 \["NOT ($sub_stmt)" => @sub_bind],
2850 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2851 @bind = ('%son%', 10, 20)
2853 =head3 Deprecated usage of Literal SQL
2855 Below are some examples of archaic use of literal SQL. It is shown only as
2856 reference for those who deal with legacy code. Each example has a much
2857 better, cleaner and safer alternative that users should opt for in new code.
2863 my %where = ( requestor => \'IS NOT NULL' )
2865 $stmt = "WHERE requestor IS NOT NULL"
2867 This used to be the way of generating NULL comparisons, before the handling
2868 of C<undef> got formalized. For new code please use the superior syntax as
2869 described in L</Tests for NULL values>.
2873 my %where = ( requestor => \'= submitter' )
2875 $stmt = "WHERE requestor = submitter"
2877 This used to be the only way to compare columns. Use the superior L</-ident>
2878 method for all new code. For example an identifier declared in such a way
2879 will be properly quoted if L</quote_char> is properly set, while the legacy
2880 form will remain as supplied.
2884 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2886 $stmt = "WHERE completed > ? AND is_ready"
2887 @bind = ('2012-12-21')
2889 Using an empty string literal used to be the only way to express a boolean.
2890 For all new code please use the much more readable
2891 L<-bool|/Unary operators: bool> operator.
2897 These pages could go on for a while, since the nesting of the data
2898 structures this module can handle are pretty much unlimited (the
2899 module implements the C<WHERE> expansion as a recursive function
2900 internally). Your best bet is to "play around" with the module a
2901 little to see how the data structures behave, and choose the best
2902 format for your data based on that.
2904 And of course, all the values above will probably be replaced with
2905 variables gotten from forms or the command line. After all, if you
2906 knew everything ahead of time, you wouldn't have to worry about
2907 dynamically-generating SQL and could just hardwire it into your
2910 =head1 ORDER BY CLAUSES
2912 Some functions take an order by clause. This can either be a scalar (just a
2913 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2914 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2917 Given | Will Generate
2918 ---------------------------------------------------------------
2920 'colA' | ORDER BY colA
2922 [qw/colA colB/] | ORDER BY colA, colB
2924 {-asc => 'colA'} | ORDER BY colA ASC
2926 {-desc => 'colB'} | ORDER BY colB DESC
2928 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2930 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2932 \'colA DESC' | ORDER BY colA DESC
2934 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2935 | /* ...with $x bound to ? */
2938 { -asc => 'colA' }, | colA ASC,
2939 { -desc => [qw/colB/] }, | colB DESC,
2940 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2941 \'colE DESC', | colE DESC,
2942 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2943 ] | /* ...with $x bound to ? */
2944 ===============================================================
2948 =head1 SPECIAL OPERATORS
2950 my $sqlmaker = SQL::Abstract->new(special_ops => [
2954 my ($self, $field, $op, $arg) = @_;
2960 handler => 'method_name',
2964 A "special operator" is a SQL syntactic clause that can be
2965 applied to a field, instead of a usual binary operator.
2968 WHERE field IN (?, ?, ?)
2969 WHERE field BETWEEN ? AND ?
2970 WHERE MATCH(field) AGAINST (?, ?)
2972 Special operators IN and BETWEEN are fairly standard and therefore
2973 are builtin within C<SQL::Abstract> (as the overridable methods
2974 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2975 like the MATCH .. AGAINST example above which is specific to MySQL,
2976 you can write your own operator handlers - supply a C<special_ops>
2977 argument to the C<new> method. That argument takes an arrayref of
2978 operator definitions; each operator definition is a hashref with two
2985 the regular expression to match the operator
2989 Either a coderef or a plain scalar method name. In both cases
2990 the expected return is C<< ($sql, @bind) >>.
2992 When supplied with a method name, it is simply called on the
2993 L<SQL::Abstract> object as:
2995 $self->$method_name($field, $op, $arg)
2999 $field is the LHS of the operator
3000 $op is the part that matched the handler regex
3003 When supplied with a coderef, it is called as:
3005 $coderef->($self, $field, $op, $arg)
3010 For example, here is an implementation
3011 of the MATCH .. AGAINST syntax for MySQL
3013 my $sqlmaker = SQL::Abstract->new(special_ops => [
3015 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
3016 {regex => qr/^match$/i,
3018 my ($self, $field, $op, $arg) = @_;
3019 $arg = [$arg] if not ref $arg;
3020 my $label = $self->_quote($field);
3021 my ($placeholder) = $self->_convert('?');
3022 my $placeholders = join ", ", (($placeholder) x @$arg);
3023 my $sql = $self->_sqlcase('match') . " ($label) "
3024 . $self->_sqlcase('against') . " ($placeholders) ";
3025 my @bind = $self->_bindtype($field, @$arg);
3026 return ($sql, @bind);
3033 =head1 UNARY OPERATORS
3035 my $sqlmaker = SQL::Abstract->new(unary_ops => [
3039 my ($self, $op, $arg) = @_;
3045 handler => 'method_name',
3049 A "unary operator" is a SQL syntactic clause that can be
3050 applied to a field - the operator goes before the field
3052 You can write your own operator handlers - supply a C<unary_ops>
3053 argument to the C<new> method. That argument takes an arrayref of
3054 operator definitions; each operator definition is a hashref with two
3061 the regular expression to match the operator
3065 Either a coderef or a plain scalar method name. In both cases
3066 the expected return is C<< $sql >>.
3068 When supplied with a method name, it is simply called on the
3069 L<SQL::Abstract> object as:
3071 $self->$method_name($op, $arg)
3075 $op is the part that matched the handler regex
3076 $arg is the RHS or argument of the operator
3078 When supplied with a coderef, it is called as:
3080 $coderef->($self, $op, $arg)
3088 Thanks to some benchmarking by Mark Stosberg, it turns out that
3089 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
3090 I must admit this wasn't an intentional design issue, but it's a
3091 byproduct of the fact that you get to control your C<DBI> handles
3094 To maximize performance, use a code snippet like the following:
3096 # prepare a statement handle using the first row
3097 # and then reuse it for the rest of the rows
3099 for my $href (@array_of_hashrefs) {
3100 $stmt ||= $sql->insert('table', $href);
3101 $sth ||= $dbh->prepare($stmt);
3102 $sth->execute($sql->values($href));
3105 The reason this works is because the keys in your C<$href> are sorted
3106 internally by B<SQL::Abstract>. Thus, as long as your data retains
3107 the same structure, you only have to generate the SQL the first time
3108 around. On subsequent queries, simply use the C<values> function provided
3109 by this module to return your values in the correct order.
3111 However this depends on the values having the same type - if, for
3112 example, the values of a where clause may either have values
3113 (resulting in sql of the form C<column = ?> with a single bind
3114 value), or alternatively the values might be C<undef> (resulting in
3115 sql of the form C<column IS NULL> with no bind value) then the
3116 caching technique suggested will not work.
3120 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
3121 really like this part (I do, at least). Building up a complex query
3122 can be as simple as the following:
3129 use CGI::FormBuilder;
3132 my $form = CGI::FormBuilder->new(...);
3133 my $sql = SQL::Abstract->new;
3135 if ($form->submitted) {
3136 my $field = $form->field;
3137 my $id = delete $field->{id};
3138 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
3141 Of course, you would still have to connect using C<DBI> to run the
3142 query, but the point is that if you make your form look like your
3143 table, the actual query script can be extremely simplistic.
3145 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
3146 a fast interface to returning and formatting data. I frequently
3147 use these three modules together to write complex database query
3148 apps in under 50 lines.
3150 =head1 HOW TO CONTRIBUTE
3152 Contributions are always welcome, in all usable forms (we especially
3153 welcome documentation improvements). The delivery methods include git-
3154 or unified-diff formatted patches, GitHub pull requests, or plain bug
3155 reports either via RT or the Mailing list. Contributors are generally
3156 granted full access to the official repository after their first several
3157 patches pass successful review.
3159 This project is maintained in a git repository. The code and related tools are
3160 accessible at the following locations:
3164 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
3166 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
3168 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
3170 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
3176 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
3177 Great care has been taken to preserve the I<published> behavior
3178 documented in previous versions in the 1.* family; however,
3179 some features that were previously undocumented, or behaved
3180 differently from the documentation, had to be changed in order
3181 to clarify the semantics. Hence, client code that was relying
3182 on some dark areas of C<SQL::Abstract> v1.*
3183 B<might behave differently> in v1.50.
3185 The main changes are:
3191 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
3195 support for the { operator => \"..." } construct (to embed literal SQL)
3199 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
3203 optional support for L<array datatypes|/"Inserting and Updating Arrays">
3207 defensive programming: check arguments
3211 fixed bug with global logic, which was previously implemented
3212 through global variables yielding side-effects. Prior versions would
3213 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3214 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3215 Now this is interpreted
3216 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3221 fixed semantics of _bindtype on array args
3225 dropped the C<_anoncopy> of the %where tree. No longer necessary,
3226 we just avoid shifting arrays within that tree.
3230 dropped the C<_modlogic> function
3234 =head1 ACKNOWLEDGEMENTS
3236 There are a number of individuals that have really helped out with
3237 this module. Unfortunately, most of them submitted bugs via CPAN
3238 so I have no idea who they are! But the people I do know are:
3240 Ash Berlin (order_by hash term support)
3241 Matt Trout (DBIx::Class support)
3242 Mark Stosberg (benchmarking)
3243 Chas Owens (initial "IN" operator support)
3244 Philip Collins (per-field SQL functions)
3245 Eric Kolve (hashref "AND" support)
3246 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3247 Dan Kubb (support for "quote_char" and "name_sep")
3248 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
3249 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
3250 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
3251 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
3252 Oliver Charles (support for "RETURNING" after "INSERT")
3258 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
3262 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3264 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3266 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3267 While not an official support venue, C<DBIx::Class> makes heavy use of
3268 C<SQL::Abstract>, and as such list members there are very familiar with
3269 how to create queries.
3273 This module is free software; you may copy this under the same
3274 terms as perl itself (either the GNU General Public License or
3275 the Artistic License)