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) = @_;
620 and exists $v->{-value}
621 and not defined $v->{-value}
624 return $self->_expand_expr({ $k => { $self->{cmp} => undef } });
626 my $ik = $self->_expand_ident(-ident => $k);
627 if (!ref($v) or Scalar::Util::blessed($v)) {
628 my $d = our $Default_Scalar_To;
634 ? $self->_expand_expr($d => $v)
635 : { -bind => [ $k, $v ] }
640 if (ref($v) eq 'HASH') {
642 return $self->_expand_op_andor(-and => [
643 map +{ $k => { $_ => $v->{$_} } },
647 return undef unless keys %$v;
649 my $op = join ' ', split '_', (map lc, $vk =~ /^-?(.*)$/)[0];
650 $self->_assert_pass_injection_guard($op);
651 if ($op =~ s/ [_\s]? \d+ $//x ) {
652 return $self->_expand_expr($k, $v);
654 if (my $x = $self->{expand_op}{$op}) {
655 local our $Cur_Col_Meta = $k;
656 return $self->$x($op, $vv, $k);
658 if ($op =~ /^is(?: not)?$/) {
659 puke "$op can only take undef as argument"
663 and exists($vv->{-value})
664 and !defined($vv->{-value})
666 return +{ -op => [ $op.' null', $ik ] };
668 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
669 return { -op => [ $op, $ik, $vv ] };
671 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
675 { -op => [ $op, $vv ] }
678 if (ref($vv) eq 'ARRAY') {
679 my ($logic, @values) = (
680 (defined($vv->[0]) and $vv->[0] =~ /^-(and|or)$/i)
685 $op =~ $self->{inequality_op}
686 or $op =~ $self->{not_like_op}
688 if (lc($logic) eq '-or' and @values > 1) {
689 belch "A multi-element arrayref as an argument to the inequality op '${\uc($op)}' "
690 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
691 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
696 # try to DWIM on equality operators
698 $op =~ $self->{equality_op} ? $self->sqlfalse
699 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
700 : $op =~ $self->{inequality_op} ? $self->sqltrue
701 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
702 : puke "operator '$op' applied on an empty array (field '$k')";
704 return $self->_expand_op_andor($logic => [
705 map +{ $k => { $vk => $_ } },
713 and exists $vv->{-value}
714 and not defined $vv->{-value}
718 $op =~ /^not$/i ? 'is not' # legacy
719 : $op =~ $self->{equality_op} ? 'is'
720 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
721 : $op =~ $self->{inequality_op} ? 'is not'
722 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
723 : puke "unexpected operator '$op' with undef operand";
724 return +{ -op => [ $is.' null', $ik ] };
726 local our $Cur_Col_Meta = $k;
730 $self->_expand_expr($vv)
733 if (ref($v) eq 'ARRAY') {
734 return $self->sqlfalse unless @$v;
735 $self->_debug("ARRAY($k) means distribute over elements");
737 $v->[0] =~ /^-(and|or)$/i
738 ? shift(@{$v = [ @$v ]})
739 : '-'.lc($self->{logic} || 'OR')
741 return $self->_expand_op_andor(
742 $logic => [ map +{ $k => $_ }, @$v ]
745 if (my $literal = is_literal_value($v)) {
747 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
750 my ($sql, @bind) = @$literal;
751 if ($self->{bindtype} eq 'columns') {
753 $self->_assert_bindval_matches_bindtype($_);
756 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
761 sub _expand_expr_hashpair_op {
762 my ($self, $k, $v) = @_;
764 $op =~ s/^-// if length($op) > 1;
765 $self->_assert_pass_injection_guard($op);
766 if (my ($rest) = $op =~/^not[_ ](.*)$/) {
769 $self->_expand_expr({ "-${rest}", $v })
772 # top level special ops are illegal in general
773 # note that, arguably, if it makes no sense at top level, it also
774 # makes no sense on the other side of an = sign or similar but DBIC
775 # gets disappointingly upset if I disallow it
777 (our $Expand_Depth) == 1
778 and List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}
780 puke "Illegal use of top-level '-$op'"
782 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
783 return { -op => [ $op, $v ] };
785 if ($self->{render}{$k}) {
791 and (keys %$v)[0] =~ /^-/
793 my ($func) = $k =~ /^-(.*)$/;
794 if (List::Util::first { $func =~ $_->{regex} } @{$self->{special_ops}}) {
795 return +{ -op => [ $func, $self->_expand_expr($v) ] };
797 return +{ -func => [ $func, $self->_expand_expr($v) ] };
799 if (!ref($v) or is_literal_value($v)) {
800 return +{ -op => [ $op, $self->_expand_expr($v) ] };
806 my ($self, $op, $body) = @_;
807 unless (defined($body) or (ref($body) and ref($body) eq 'ARRAY')) {
808 puke "$op requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
810 my @parts = map split(/\Q${\($self->{name_sep}||'.')}\E/, $_),
811 ref($body) ? @$body : $body;
812 return { -ident => $parts[-1] } if $self->{_dequalify_idents};
813 unless ($self->{quote_char}) {
814 $self->_assert_pass_injection_guard($_) for @parts;
816 return +{ -ident => \@parts };
820 +{ -bind => [ our $Cur_Col_Meta, $_[2] ] };
824 +{ -op => [ 'not', $_[0]->_expand_expr($_[2]) ] };
828 my ($self, undef, $v) = @_;
830 return $self->_expand_expr($v);
832 puke "-bool => undef not supported" unless defined($v);
833 return $self->_expand_ident(-ident => $v);
836 sub _expand_op_andor {
837 my ($self, $logic, $v, $k) = @_;
839 $v = [ map +{ $k, { $_ => $v->{$_} } },
842 my ($logop) = $logic =~ /^-?(.*)$/;
843 if (ref($v) eq 'HASH') {
846 map $self->_expand_expr({ $_ => $v->{$_} }),
850 if (ref($v) eq 'ARRAY') {
851 $logop eq 'and' or $logop eq 'or' or puke "unknown logic: $logop";
854 (ref($_) eq 'ARRAY' and @$_)
855 or (ref($_) eq 'HASH' and %$_)
861 while (my ($el) = splice @expr, 0, 1) {
862 puke "Supplying an empty left hand side argument is not supported in array-pairs"
863 unless defined($el) and length($el);
864 my $elref = ref($el);
866 local our $Expand_Depth = 0;
867 push(@res, grep defined, $self->_expand_expr({ $el, shift(@expr) }));
868 } elsif ($elref eq 'ARRAY') {
869 push(@res, grep defined, $self->_expand_expr($el)) if @$el;
870 } elsif (my $l = is_literal_value($el)) {
871 push @res, { -literal => $l };
872 } elsif ($elref eq 'HASH') {
873 local our $Expand_Depth = 0;
874 push @res, grep defined, $self->_expand_expr($el) if %$el;
880 # return $res[0] if @res == 1;
881 return { -op => [ $logop, @res ] };
886 sub _expand_between {
887 my ($self, $op, $vv, $k) = @_;
888 local our $Cur_Col_Meta = $k;
889 my @rhs = map $self->_expand_expr($_),
890 ref($vv) eq 'ARRAY' ? @$vv : $vv;
892 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
894 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
896 puke "Operator '${\uc($op)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
900 $self->_expand_ident(-ident => $k),
906 my ($self, $op, $vv, $k) = @_;
907 if (my $literal = is_literal_value($vv)) {
908 my ($sql, @bind) = @$literal;
909 my $opened_sql = $self->_open_outer_paren($sql);
911 $op, $self->_expand_ident(-ident => $k),
912 [ { -literal => [ $opened_sql, @bind ] } ]
916 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
917 . "-${\uc($op)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
918 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
919 . 'will emit the logically correct SQL instead of raising this exception)'
921 puke("Argument passed to the '${\uc($op)}' operator can not be undefined")
923 my @rhs = map $self->_expand_expr($_),
924 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
925 map { defined($_) ? $_: puke($undef_err) }
926 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
927 return $self->${\($op =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
931 $self->_expand_ident(-ident => $k),
937 my ($self, $op, $v) = @_;
938 # DBIx::Class requires a nest warning to be emitted once but the private
939 # method it overrode to do so no longer exists
940 if ($self->{is_dbic_sqlmaker}) {
941 unless (our $Nest_Warned) {
943 "-nest in search conditions is deprecated, you most probably wanted:\n"
944 .q|{..., -and => [ \%cond0, \@cond1, \'cond2', \[ 'cond3', [ col => bind ] ], etc. ], ... }|
949 return $self->_expand_expr($v);
953 my ($self, $where, $logic) = @_;
955 # Special case: top level simple string treated as literal
957 my $where_exp = (ref($where)
958 ? $self->_expand_expr($where, $logic)
959 : { -literal => [ $where ] });
961 # dispatch expanded expression
963 my ($sql, @bind) = defined($where_exp) ? $self->render_aqt($where_exp) : (undef);
964 # DBIx::Class used to call _recurse_where in scalar context
965 # something else might too...
967 return ($sql, @bind);
970 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
976 my ($self, $ident) = @_;
978 return $self->_convert($self->_quote($ident));
982 my ($self, $list) = @_;
983 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$list;
984 return join(', ', map $_->[0], @parts), map @{$_}[1..$#$_], @parts;
988 my ($self, $rest) = @_;
989 my ($func, @args) = @$rest;
993 push @arg_sql, shift @x;
995 } map [ $self->render_aqt($_) ], @args;
996 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1000 my ($self, $bind) = @_;
1001 return ($self->_convert('?'), $self->_bindtype(@$bind));
1004 sub _render_literal {
1005 my ($self, $literal) = @_;
1006 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1012 my ($self, $op, $args) = @_;
1013 my ($left, $low, $high) = @$args;
1014 my ($rhsql, @rhbind) = do {
1016 puke "Single arg to between must be a literal"
1017 unless $low->{-literal};
1020 my ($l, $h) = map [ $self->render_aqt($_) ], $low, $high;
1021 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
1022 @{$l}[1..$#$l], @{$h}[1..$#$h])
1025 my ($lhsql, @lhbind) = $self->render_aqt($left);
1027 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
1030 }), 'between', 'not between'),
1032 my ($self, $op, $args) = @_;
1033 my ($lhs, $rhs) = @$args;
1036 my ($sql, @bind) = $self->render_aqt($_);
1037 push @in_bind, @bind;
1040 my ($lhsql, @lbind) = $self->render_aqt($lhs);
1042 $lhsql.' '.$self->_sqlcase($op).' ( '
1043 .join(', ', @in_sql)
1047 }), 'in', 'not in'),
1048 (map +($_ => '_render_unop_postfix'),
1049 'is null', 'is not null', 'asc', 'desc',
1051 (not => '_render_op_not'),
1053 my ($self, $op, $args) = @_;
1054 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$args;
1055 return '' unless @parts;
1056 return @{$parts[0]} if @parts == 1;
1057 my ($final_sql) = join(
1058 ' '.$self->_sqlcase($op).' ',
1063 map @{$_}[1..$#$_], @parts
1069 my ($self, $v) = @_;
1070 my ($op, @args) = @$v;
1071 if (my $r = $self->{render_op}{$op}) {
1072 return $self->$r($op, \@args);
1074 my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
1075 if ($us and @args > 1) {
1076 puke "Special op '${op}' requires first value to be identifier"
1077 unless my ($ident) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
1078 my $k = join(($self->{name_sep}||'.'), @$ident);
1079 local our $Expand_Depth = 1;
1080 return $self->${\($us->{handler})}($k, $op, $args[1]);
1082 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
1083 return $self->${\($us->{handler})}($op, $args[0]);
1086 return $self->_render_unop_prefix($op, \@args);
1088 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @args;
1089 return '' unless @parts;
1090 my ($final_sql) = join(
1091 ' '.$self->_sqlcase($op).' ',
1096 map @{$_}[1..$#$_], @parts
1102 sub _render_op_not {
1103 my ($self, $op, $v) = @_;
1104 my ($sql, @bind) = $self->_render_unop_prefix($op, $v);
1105 return "(${sql})", @bind;
1108 sub _render_unop_prefix {
1109 my ($self, $op, $v) = @_;
1110 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1111 my $op_sql = $self->_sqlcase($op);
1112 return ("${op_sql} ${expr_sql}", @bind);
1115 sub _render_unop_postfix {
1116 my ($self, $op, $v) = @_;
1117 my ($expr_sql, @bind) = $self->render_aqt($v->[0]);
1118 my $op_sql = $self->_sqlcase($op);
1119 return ($expr_sql.' '.$op_sql, @bind);
1122 # Some databases (SQLite) treat col IN (1, 2) different from
1123 # col IN ( (1, 2) ). Use this to strip all outer parens while
1124 # adding them back in the corresponding method
1125 sub _open_outer_paren {
1126 my ($self, $sql) = @_;
1128 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1130 # there are closing parens inside, need the heavy duty machinery
1131 # to reevaluate the extraction starting from $sql (full reevaluation)
1132 if ($inner =~ /\)/) {
1133 require Text::Balanced;
1135 my (undef, $remainder) = do {
1136 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1138 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1141 # the entire expression needs to be a balanced bracketed thing
1142 # (after an extract no remainder sans trailing space)
1143 last if defined $remainder and $remainder =~ /\S/;
1153 #======================================================================
1155 #======================================================================
1157 sub _expand_order_by {
1158 my ($self, $arg) = @_;
1160 return unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
1162 my $expander = sub {
1163 my ($self, $dir, $expr) = @_;
1164 my @to_expand = ref($expr) eq 'ARRAY' ? @$expr : $expr;
1165 foreach my $arg (@to_expand) {
1169 and grep /^-(asc|desc)$/, keys %$arg
1171 puke "ordering direction hash passed to order by must have exactly one key (-asc or -desc)";
1175 defined($dir) ? { -op => [ $dir =~ /^-?(.*)$/ ,=> $_ ] } : $_
1177 map $self->expand_expr($_, -ident),
1178 map ref($_) eq 'ARRAY' ? @$_ : $_, @to_expand;
1179 return (@exp > 1 ? { -list => \@exp } : $exp[0]);
1182 local @{$self->{expand}}{qw(-asc -desc)} = (($expander) x 2);
1184 return $self->$expander(undef, $arg);
1188 my ($self, $arg) = @_;
1190 return '' unless defined(my $expanded = $self->_expand_order_by($arg));
1192 my ($sql, @bind) = $self->render_aqt($expanded);
1194 return '' unless length($sql);
1196 my $final_sql = $self->_sqlcase(' order by ').$sql;
1198 return wantarray ? ($final_sql, @bind) : $final_sql;
1201 # _order_by no longer needs to call this so doesn't but DBIC uses it.
1203 sub _order_by_chunks {
1204 my ($self, $arg) = @_;
1206 return () unless defined(my $expanded = $self->_expand_order_by($arg));
1208 return $self->_chunkify_order_by($expanded);
1211 sub _chunkify_order_by {
1212 my ($self, $expanded) = @_;
1214 return grep length, $self->render_aqt($expanded)
1215 if $expanded->{-ident} or @{$expanded->{-literal}||[]} == 1;
1218 if (ref() eq 'HASH' and my $l = $_->{-list}) {
1219 return map $self->_chunkify_order_by($_), @$l;
1221 return [ $self->render_aqt($_) ];
1225 #======================================================================
1226 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1227 #======================================================================
1233 $self->_expand_maybe_list_expr($from, undef, -ident)
1238 #======================================================================
1240 #======================================================================
1242 sub _expand_maybe_list_expr {
1243 my ($self, $expr, $logic, $default) = @_;
1245 if (ref($expr) eq 'ARRAY') {
1247 map $self->expand_expr($_, $default), @$expr
1254 return $self->expand_expr($e, $default);
1257 # highly optimized, as it's called way too often
1259 # my ($self, $label) = @_;
1261 return '' unless defined $_[1];
1262 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1263 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
1265 unless ($_[0]->{quote_char}) {
1266 if (ref($_[1]) eq 'ARRAY') {
1267 return join($_[0]->{name_sep}||'.', @{$_[1]});
1269 $_[0]->_assert_pass_injection_guard($_[1]);
1274 my $qref = ref $_[0]->{quote_char};
1276 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1277 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1278 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1280 my $esc = $_[0]->{escape_char} || $r;
1282 # parts containing * are naturally unquoted
1284 $_[0]->{name_sep}||'',
1288 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1290 (ref($_[1]) eq 'ARRAY'
1294 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1302 # Conversion, if applicable
1304 #my ($self, $arg) = @_;
1305 if ($_[0]->{convert_where}) {
1306 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
1313 #my ($self, $col, @vals) = @_;
1314 # called often - tighten code
1315 return $_[0]->{bindtype} eq 'columns'
1316 ? map {[$_[1], $_]} @_[2 .. $#_]
1321 # Dies if any element of @bind is not in [colname => value] format
1322 # if bindtype is 'columns'.
1323 sub _assert_bindval_matches_bindtype {
1324 # my ($self, @bind) = @_;
1326 if ($self->{bindtype} eq 'columns') {
1328 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1329 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1335 sub _join_sql_clauses {
1336 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1338 if (@$clauses_aref > 1) {
1339 my $join = " " . $self->_sqlcase($logic) . " ";
1340 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1341 return ($sql, @$bind_aref);
1343 elsif (@$clauses_aref) {
1344 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1347 return (); # if no SQL, ignore @$bind_aref
1352 # Fix SQL case, if so requested
1354 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1355 # don't touch the argument ... crooked logic, but let's not change it!
1356 return $_[0]->{case} ? $_[1] : uc($_[1]);
1360 #======================================================================
1361 # DISPATCHING FROM REFKIND
1362 #======================================================================
1365 my ($self, $data) = @_;
1367 return 'UNDEF' unless defined $data;
1369 # blessed objects are treated like scalars
1370 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1372 return 'SCALAR' unless $ref;
1375 while ($ref eq 'REF') {
1377 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1381 return ($ref||'SCALAR') . ('REF' x $n_steps);
1385 my ($self, $data) = @_;
1386 my @try = ($self->_refkind($data));
1387 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1388 push @try, 'FALLBACK';
1392 sub _METHOD_FOR_refkind {
1393 my ($self, $meth_prefix, $data) = @_;
1396 for (@{$self->_try_refkind($data)}) {
1397 $method = $self->can($meth_prefix."_".$_)
1401 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1405 sub _SWITCH_refkind {
1406 my ($self, $data, $dispatch_table) = @_;
1409 for (@{$self->_try_refkind($data)}) {
1410 $coderef = $dispatch_table->{$_}
1414 puke "no dispatch entry for ".$self->_refkind($data)
1423 #======================================================================
1424 # VALUES, GENERATE, AUTOLOAD
1425 #======================================================================
1427 # LDNOTE: original code from nwiger, didn't touch code in that section
1428 # I feel the AUTOLOAD stuff should not be the default, it should
1429 # only be activated on explicit demand by user.
1433 my $data = shift || return;
1434 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1435 unless ref $data eq 'HASH';
1438 foreach my $k (sort keys %$data) {
1439 my $v = $data->{$k};
1440 $self->_SWITCH_refkind($v, {
1442 if ($self->{array_datatypes}) { # array datatype
1443 push @all_bind, $self->_bindtype($k, $v);
1445 else { # literal SQL with bind
1446 my ($sql, @bind) = @$v;
1447 $self->_assert_bindval_matches_bindtype(@bind);
1448 push @all_bind, @bind;
1451 ARRAYREFREF => sub { # literal SQL with bind
1452 my ($sql, @bind) = @${$v};
1453 $self->_assert_bindval_matches_bindtype(@bind);
1454 push @all_bind, @bind;
1456 SCALARREF => sub { # literal SQL without bind
1458 SCALAR_or_UNDEF => sub {
1459 push @all_bind, $self->_bindtype($k, $v);
1470 my(@sql, @sqlq, @sqlv);
1474 if ($ref eq 'HASH') {
1475 for my $k (sort keys %$_) {
1478 my $label = $self->_quote($k);
1479 if ($r eq 'ARRAY') {
1480 # literal SQL with bind
1481 my ($sql, @bind) = @$v;
1482 $self->_assert_bindval_matches_bindtype(@bind);
1483 push @sqlq, "$label = $sql";
1485 } elsif ($r eq 'SCALAR') {
1486 # literal SQL without bind
1487 push @sqlq, "$label = $$v";
1489 push @sqlq, "$label = ?";
1490 push @sqlv, $self->_bindtype($k, $v);
1493 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1494 } elsif ($ref eq 'ARRAY') {
1495 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1498 if ($r eq 'ARRAY') { # literal SQL with bind
1499 my ($sql, @bind) = @$v;
1500 $self->_assert_bindval_matches_bindtype(@bind);
1503 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1504 # embedded literal SQL
1511 push @sql, '(' . join(', ', @sqlq) . ')';
1512 } elsif ($ref eq 'SCALAR') {
1516 # strings get case twiddled
1517 push @sql, $self->_sqlcase($_);
1521 my $sql = join ' ', @sql;
1523 # this is pretty tricky
1524 # if ask for an array, return ($stmt, @bind)
1525 # otherwise, s/?/shift @sqlv/ to put it inline
1527 return ($sql, @sqlv);
1529 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1530 ref $d ? $d->[1] : $d/e;
1539 # This allows us to check for a local, then _form, attr
1541 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1542 return $self->generate($name, @_);
1553 SQL::Abstract - Generate SQL from Perl data structures
1559 my $sql = SQL::Abstract->new;
1561 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1563 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1565 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1567 my($stmt, @bind) = $sql->delete($table, \%where);
1569 # Then, use these in your DBI statements
1570 my $sth = $dbh->prepare($stmt);
1571 $sth->execute(@bind);
1573 # Just generate the WHERE clause
1574 my($stmt, @bind) = $sql->where(\%where, $order);
1576 # Return values in the same order, for hashed queries
1577 # See PERFORMANCE section for more details
1578 my @bind = $sql->values(\%fieldvals);
1582 This module was inspired by the excellent L<DBIx::Abstract>.
1583 However, in using that module I found that what I really wanted
1584 to do was generate SQL, but still retain complete control over my
1585 statement handles and use the DBI interface. So, I set out to
1586 create an abstract SQL generation module.
1588 While based on the concepts used by L<DBIx::Abstract>, there are
1589 several important differences, especially when it comes to WHERE
1590 clauses. I have modified the concepts used to make the SQL easier
1591 to generate from Perl data structures and, IMO, more intuitive.
1592 The underlying idea is for this module to do what you mean, based
1593 on the data structures you provide it. The big advantage is that
1594 you don't have to modify your code every time your data changes,
1595 as this module figures it out.
1597 To begin with, an SQL INSERT is as easy as just specifying a hash
1598 of C<key=value> pairs:
1601 name => 'Jimbo Bobson',
1602 phone => '123-456-7890',
1603 address => '42 Sister Lane',
1604 city => 'St. Louis',
1605 state => 'Louisiana',
1608 The SQL can then be generated with this:
1610 my($stmt, @bind) = $sql->insert('people', \%data);
1612 Which would give you something like this:
1614 $stmt = "INSERT INTO people
1615 (address, city, name, phone, state)
1616 VALUES (?, ?, ?, ?, ?)";
1617 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1618 '123-456-7890', 'Louisiana');
1620 These are then used directly in your DBI code:
1622 my $sth = $dbh->prepare($stmt);
1623 $sth->execute(@bind);
1625 =head2 Inserting and Updating Arrays
1627 If your database has array types (like for example Postgres),
1628 activate the special option C<< array_datatypes => 1 >>
1629 when creating the C<SQL::Abstract> object.
1630 Then you may use an arrayref to insert and update database array types:
1632 my $sql = SQL::Abstract->new(array_datatypes => 1);
1634 planets => [qw/Mercury Venus Earth Mars/]
1637 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1641 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1643 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1646 =head2 Inserting and Updating SQL
1648 In order to apply SQL functions to elements of your C<%data> you may
1649 specify a reference to an arrayref for the given hash value. For example,
1650 if you need to execute the Oracle C<to_date> function on a value, you can
1651 say something like this:
1655 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1658 The first value in the array is the actual SQL. Any other values are
1659 optional and would be included in the bind values array. This gives
1662 my($stmt, @bind) = $sql->insert('people', \%data);
1664 $stmt = "INSERT INTO people (name, date_entered)
1665 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1666 @bind = ('Bill', '03/02/2003');
1668 An UPDATE is just as easy, all you change is the name of the function:
1670 my($stmt, @bind) = $sql->update('people', \%data);
1672 Notice that your C<%data> isn't touched; the module will generate
1673 the appropriately quirky SQL for you automatically. Usually you'll
1674 want to specify a WHERE clause for your UPDATE, though, which is
1675 where handling C<%where> hashes comes in handy...
1677 =head2 Complex where statements
1679 This module can generate pretty complicated WHERE statements
1680 easily. For example, simple C<key=value> pairs are taken to mean
1681 equality, and if you want to see if a field is within a set
1682 of values, you can use an arrayref. Let's say we wanted to
1683 SELECT some data based on this criteria:
1686 requestor => 'inna',
1687 worker => ['nwiger', 'rcwe', 'sfz'],
1688 status => { '!=', 'completed' }
1691 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1693 The above would give you something like this:
1695 $stmt = "SELECT * FROM tickets WHERE
1696 ( requestor = ? ) AND ( status != ? )
1697 AND ( worker = ? OR worker = ? OR worker = ? )";
1698 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1700 Which you could then use in DBI code like so:
1702 my $sth = $dbh->prepare($stmt);
1703 $sth->execute(@bind);
1709 The methods are simple. There's one for every major SQL operation,
1710 and a constructor you use first. The arguments are specified in a
1711 similar order for each method (table, then fields, then a where
1712 clause) to try and simplify things.
1714 =head2 new(option => 'value')
1716 The C<new()> function takes a list of options and values, and returns
1717 a new B<SQL::Abstract> object which can then be used to generate SQL
1718 through the methods below. The options accepted are:
1724 If set to 'lower', then SQL will be generated in all lowercase. By
1725 default SQL is generated in "textbook" case meaning something like:
1727 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1729 Any setting other than 'lower' is ignored.
1733 This determines what the default comparison operator is. By default
1734 it is C<=>, meaning that a hash like this:
1736 %where = (name => 'nwiger', email => 'nate@wiger.org');
1738 Will generate SQL like this:
1740 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1742 However, you may want loose comparisons by default, so if you set
1743 C<cmp> to C<like> you would get SQL such as:
1745 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1747 You can also override the comparison on an individual basis - see
1748 the huge section on L</"WHERE CLAUSES"> at the bottom.
1750 =item sqltrue, sqlfalse
1752 Expressions for inserting boolean values within SQL statements.
1753 By default these are C<1=1> and C<1=0>. They are used
1754 by the special operators C<-in> and C<-not_in> for generating
1755 correct SQL even when the argument is an empty array (see below).
1759 This determines the default logical operator for multiple WHERE
1760 statements in arrays or hashes. If absent, the default logic is "or"
1761 for arrays, and "and" for hashes. This means that a WHERE
1765 event_date => {'>=', '2/13/99'},
1766 event_date => {'<=', '4/24/03'},
1769 will generate SQL like this:
1771 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1773 This is probably not what you want given this query, though (look
1774 at the dates). To change the "OR" to an "AND", simply specify:
1776 my $sql = SQL::Abstract->new(logic => 'and');
1778 Which will change the above C<WHERE> to:
1780 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1782 The logic can also be changed locally by inserting
1783 a modifier in front of an arrayref:
1785 @where = (-and => [event_date => {'>=', '2/13/99'},
1786 event_date => {'<=', '4/24/03'} ]);
1788 See the L</"WHERE CLAUSES"> section for explanations.
1792 This will automatically convert comparisons using the specified SQL
1793 function for both column and value. This is mostly used with an argument
1794 of C<upper> or C<lower>, so that the SQL will have the effect of
1795 case-insensitive "searches". For example, this:
1797 $sql = SQL::Abstract->new(convert => 'upper');
1798 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1800 Will turn out the following SQL:
1802 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1804 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1805 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1806 not validate this option; it will just pass through what you specify verbatim).
1810 This is a kludge because many databases suck. For example, you can't
1811 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1812 Instead, you have to use C<bind_param()>:
1814 $sth->bind_param(1, 'reg data');
1815 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1817 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1818 which loses track of which field each slot refers to. Fear not.
1820 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1821 Currently, you can specify either C<normal> (default) or C<columns>. If you
1822 specify C<columns>, you will get an array that looks like this:
1824 my $sql = SQL::Abstract->new(bindtype => 'columns');
1825 my($stmt, @bind) = $sql->insert(...);
1828 [ 'column1', 'value1' ],
1829 [ 'column2', 'value2' ],
1830 [ 'column3', 'value3' ],
1833 You can then iterate through this manually, using DBI's C<bind_param()>.
1835 $sth->prepare($stmt);
1838 my($col, $data) = @$_;
1839 if ($col eq 'details' || $col eq 'comments') {
1840 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1841 } elsif ($col eq 'image') {
1842 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1844 $sth->bind_param($i, $data);
1848 $sth->execute; # execute without @bind now
1850 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1851 Basically, the advantage is still that you don't have to care which fields
1852 are or are not included. You could wrap that above C<for> loop in a simple
1853 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1854 get a layer of abstraction over manual SQL specification.
1856 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1857 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1858 will expect the bind values in this format.
1862 This is the character that a table or column name will be quoted
1863 with. By default this is an empty string, but you could set it to
1864 the character C<`>, to generate SQL like this:
1866 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1868 Alternatively, you can supply an array ref of two items, the first being the left
1869 hand quote character, and the second the right hand quote character. For
1870 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1871 that generates SQL like this:
1873 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1875 Quoting is useful if you have tables or columns names that are reserved
1876 words in your database's SQL dialect.
1880 This is the character that will be used to escape L</quote_char>s appearing
1881 in an identifier before it has been quoted.
1883 The parameter default in case of a single L</quote_char> character is the quote
1886 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
1887 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
1888 of the B<opening (left)> L</quote_char> within the identifier are currently left
1889 untouched. The default for opening-closing-style quotes may change in future
1890 versions, thus you are B<strongly encouraged> to specify the escape character
1895 This is the character that separates a table and column name. It is
1896 necessary to specify this when the C<quote_char> option is selected,
1897 so that tables and column names can be individually quoted like this:
1899 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1901 =item injection_guard
1903 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1904 column name specified in a query structure. This is a safety mechanism to avoid
1905 injection attacks when mishandling user input e.g.:
1907 my %condition_as_column_value_pairs = get_values_from_user();
1908 $sqla->select( ... , \%condition_as_column_value_pairs );
1910 If the expression matches an exception is thrown. Note that literal SQL
1911 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1913 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1915 =item array_datatypes
1917 When this option is true, arrayrefs in INSERT or UPDATE are
1918 interpreted as array datatypes and are passed directly
1920 When this option is false, arrayrefs are interpreted
1921 as literal SQL, just like refs to arrayrefs
1922 (but this behavior is for backwards compatibility; when writing
1923 new queries, use the "reference to arrayref" syntax
1929 Takes a reference to a list of "special operators"
1930 to extend the syntax understood by L<SQL::Abstract>.
1931 See section L</"SPECIAL OPERATORS"> for details.
1935 Takes a reference to a list of "unary operators"
1936 to extend the syntax understood by L<SQL::Abstract>.
1937 See section L</"UNARY OPERATORS"> for details.
1943 =head2 insert($table, \@values || \%fieldvals, \%options)
1945 This is the simplest function. You simply give it a table name
1946 and either an arrayref of values or hashref of field/value pairs.
1947 It returns an SQL INSERT statement and a list of bind values.
1948 See the sections on L</"Inserting and Updating Arrays"> and
1949 L</"Inserting and Updating SQL"> for information on how to insert
1950 with those data types.
1952 The optional C<\%options> hash reference may contain additional
1953 options to generate the insert SQL. Currently supported options
1960 Takes either a scalar of raw SQL fields, or an array reference of
1961 field names, and adds on an SQL C<RETURNING> statement at the end.
1962 This allows you to return data generated by the insert statement
1963 (such as row IDs) without performing another C<SELECT> statement.
1964 Note, however, this is not part of the SQL standard and may not
1965 be supported by all database engines.
1969 =head2 update($table, \%fieldvals, \%where, \%options)
1971 This takes a table, hashref of field/value pairs, and an optional
1972 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1974 See the sections on L</"Inserting and Updating Arrays"> and
1975 L</"Inserting and Updating SQL"> for information on how to insert
1976 with those data types.
1978 The optional C<\%options> hash reference may contain additional
1979 options to generate the update SQL. Currently supported options
1986 See the C<returning> option to
1987 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1991 =head2 select($source, $fields, $where, $order)
1993 This returns a SQL SELECT statement and associated list of bind values, as
1994 specified by the arguments:
2000 Specification of the 'FROM' part of the statement.
2001 The argument can be either a plain scalar (interpreted as a table
2002 name, will be quoted), or an arrayref (interpreted as a list
2003 of table names, joined by commas, quoted), or a scalarref
2004 (literal SQL, not quoted).
2008 Specification of the list of fields to retrieve from
2010 The argument can be either an arrayref (interpreted as a list
2011 of field names, will be joined by commas and quoted), or a
2012 plain scalar (literal SQL, not quoted).
2013 Please observe that this API is not as flexible as that of
2014 the first argument C<$source>, for backwards compatibility reasons.
2018 Optional argument to specify the WHERE part of the query.
2019 The argument is most often a hashref, but can also be
2020 an arrayref or plain scalar --
2021 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
2025 Optional argument to specify the ORDER BY part of the query.
2026 The argument can be a scalar, a hashref or an arrayref
2027 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
2033 =head2 delete($table, \%where, \%options)
2035 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
2036 It returns an SQL DELETE statement and list of bind values.
2038 The optional C<\%options> hash reference may contain additional
2039 options to generate the delete SQL. Currently supported options
2046 See the C<returning> option to
2047 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2051 =head2 where(\%where, $order)
2053 This is used to generate just the WHERE clause. For example,
2054 if you have an arbitrary data structure and know what the
2055 rest of your SQL is going to look like, but want an easy way
2056 to produce a WHERE clause, use this. It returns an SQL WHERE
2057 clause and list of bind values.
2060 =head2 values(\%data)
2062 This just returns the values from the hash C<%data>, in the same
2063 order that would be returned from any of the other above queries.
2064 Using this allows you to markedly speed up your queries if you
2065 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
2067 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
2069 Warning: This is an experimental method and subject to change.
2071 This returns arbitrarily generated SQL. It's a really basic shortcut.
2072 It will return two different things, depending on return context:
2074 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
2075 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2077 These would return the following:
2079 # First calling form
2080 $stmt = "CREATE TABLE test (?, ?)";
2081 @bind = (field1, field2);
2083 # Second calling form
2084 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2086 Depending on what you're trying to do, it's up to you to choose the correct
2087 format. In this example, the second form is what you would want.
2091 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2095 ALTER SESSION SET nls_date_format = 'MM/YY'
2097 You get the idea. Strings get their case twiddled, but everything
2098 else remains verbatim.
2100 =head1 EXPORTABLE FUNCTIONS
2102 =head2 is_plain_value
2104 Determines if the supplied argument is a plain value as understood by this
2109 =item * The value is C<undef>
2111 =item * The value is a non-reference
2113 =item * The value is an object with stringification overloading
2115 =item * The value is of the form C<< { -value => $anything } >>
2119 On failure returns C<undef>, on success returns a B<scalar> reference
2120 to the original supplied argument.
2126 The stringification overloading detection is rather advanced: it takes
2127 into consideration not only the presence of a C<""> overload, but if that
2128 fails also checks for enabled
2129 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2130 on either C<0+> or C<bool>.
2132 Unfortunately testing in the field indicates that this
2133 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2134 but only when very large numbers of stringifying objects are involved.
2135 At the time of writing ( Sep 2014 ) there is no clear explanation of
2136 the direct cause, nor is there a manageably small test case that reliably
2137 reproduces the problem.
2139 If you encounter any of the following exceptions in B<random places within
2140 your application stack> - this module may be to blame:
2142 Operation "ne": no method found,
2143 left argument in overloaded package <something>,
2144 right argument in overloaded package <something>
2148 Stub found while resolving method "???" overloading """" in package <something>
2150 If you fall victim to the above - please attempt to reduce the problem
2151 to something that could be sent to the L<SQL::Abstract developers
2152 |DBIx::Class/GETTING HELP/SUPPORT>
2153 (either publicly or privately). As a workaround in the meantime you can
2154 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2155 value, which will most likely eliminate your problem (at the expense of
2156 not being able to properly detect exotic forms of stringification).
2158 This notice and environment variable will be removed in a future version,
2159 as soon as the underlying problem is found and a reliable workaround is
2164 =head2 is_literal_value
2166 Determines if the supplied argument is a literal value as understood by this
2171 =item * C<\$sql_string>
2173 =item * C<\[ $sql_string, @bind_values ]>
2177 On failure returns C<undef>, on success returns an B<array> reference
2178 containing the unpacked version of the supplied literal SQL and bind values.
2180 =head1 WHERE CLAUSES
2184 This module uses a variation on the idea from L<DBIx::Abstract>. It
2185 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2186 module is that things in arrays are OR'ed, and things in hashes
2189 The easiest way to explain is to show lots of examples. After
2190 each C<%where> hash shown, it is assumed you used:
2192 my($stmt, @bind) = $sql->where(\%where);
2194 However, note that the C<%where> hash can be used directly in any
2195 of the other functions as well, as described above.
2197 =head2 Key-value pairs
2199 So, let's get started. To begin, a simple hash:
2203 status => 'completed'
2206 Is converted to SQL C<key = val> statements:
2208 $stmt = "WHERE user = ? AND status = ?";
2209 @bind = ('nwiger', 'completed');
2211 One common thing I end up doing is having a list of values that
2212 a field can be in. To do this, simply specify a list inside of
2217 status => ['assigned', 'in-progress', 'pending'];
2220 This simple code will create the following:
2222 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2223 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2225 A field associated to an empty arrayref will be considered a
2226 logical false and will generate 0=1.
2228 =head2 Tests for NULL values
2230 If the value part is C<undef> then this is converted to SQL <IS NULL>
2239 $stmt = "WHERE user = ? AND status IS NULL";
2242 To test if a column IS NOT NULL:
2246 status => { '!=', undef },
2249 =head2 Specific comparison operators
2251 If you want to specify a different type of operator for your comparison,
2252 you can use a hashref for a given column:
2256 status => { '!=', 'completed' }
2259 Which would generate:
2261 $stmt = "WHERE user = ? AND status != ?";
2262 @bind = ('nwiger', 'completed');
2264 To test against multiple values, just enclose the values in an arrayref:
2266 status => { '=', ['assigned', 'in-progress', 'pending'] };
2268 Which would give you:
2270 "WHERE status = ? OR status = ? OR status = ?"
2273 The hashref can also contain multiple pairs, in which case it is expanded
2274 into an C<AND> of its elements:
2278 status => { '!=', 'completed', -not_like => 'pending%' }
2281 # Or more dynamically, like from a form
2282 $where{user} = 'nwiger';
2283 $where{status}{'!='} = 'completed';
2284 $where{status}{'-not_like'} = 'pending%';
2286 # Both generate this
2287 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2288 @bind = ('nwiger', 'completed', 'pending%');
2291 To get an OR instead, you can combine it with the arrayref idea:
2295 priority => [ { '=', 2 }, { '>', 5 } ]
2298 Which would generate:
2300 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2301 @bind = ('2', '5', 'nwiger');
2303 If you want to include literal SQL (with or without bind values), just use a
2304 scalar reference or reference to an arrayref as the value:
2307 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2308 date_expires => { '<' => \"now()" }
2311 Which would generate:
2313 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2314 @bind = ('11/26/2008');
2317 =head2 Logic and nesting operators
2319 In the example above,
2320 there is a subtle trap if you want to say something like
2321 this (notice the C<AND>):
2323 WHERE priority != ? AND priority != ?
2325 Because, in Perl you I<can't> do this:
2327 priority => { '!=' => 2, '!=' => 1 }
2329 As the second C<!=> key will obliterate the first. The solution
2330 is to use the special C<-modifier> form inside an arrayref:
2332 priority => [ -and => {'!=', 2},
2336 Normally, these would be joined by C<OR>, but the modifier tells it
2337 to use C<AND> instead. (Hint: You can use this in conjunction with the
2338 C<logic> option to C<new()> in order to change the way your queries
2339 work by default.) B<Important:> Note that the C<-modifier> goes
2340 B<INSIDE> the arrayref, as an extra first element. This will
2341 B<NOT> do what you think it might:
2343 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2345 Here is a quick list of equivalencies, since there is some overlap:
2348 status => {'!=', 'completed', 'not like', 'pending%' }
2349 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2352 status => {'=', ['assigned', 'in-progress']}
2353 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2354 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2358 =head2 Special operators: IN, BETWEEN, etc.
2360 You can also use the hashref format to compare a list of fields using the
2361 C<IN> comparison operator, by specifying the list as an arrayref:
2364 status => 'completed',
2365 reportid => { -in => [567, 2335, 2] }
2368 Which would generate:
2370 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2371 @bind = ('completed', '567', '2335', '2');
2373 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2376 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2377 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2378 'sqltrue' (by default: C<1=1>).
2380 In addition to the array you can supply a chunk of literal sql or
2381 literal sql with bind:
2384 customer => { -in => \[
2385 'SELECT cust_id FROM cust WHERE balance > ?',
2388 status => { -in => \'SELECT status_codes FROM states' },
2394 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2395 AND status IN ( SELECT status_codes FROM states )
2399 Finally, if the argument to C<-in> is not a reference, it will be
2400 treated as a single-element array.
2402 Another pair of operators is C<-between> and C<-not_between>,
2403 used with an arrayref of two values:
2407 completion_date => {
2408 -not_between => ['2002-10-01', '2003-02-06']
2414 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2416 Just like with C<-in> all plausible combinations of literal SQL
2420 start0 => { -between => [ 1, 2 ] },
2421 start1 => { -between => \["? AND ?", 1, 2] },
2422 start2 => { -between => \"lower(x) AND upper(y)" },
2423 start3 => { -between => [
2425 \["upper(?)", 'stuff' ],
2432 ( start0 BETWEEN ? AND ? )
2433 AND ( start1 BETWEEN ? AND ? )
2434 AND ( start2 BETWEEN lower(x) AND upper(y) )
2435 AND ( start3 BETWEEN lower(x) AND upper(?) )
2437 @bind = (1, 2, 1, 2, 'stuff');
2440 These are the two builtin "special operators"; but the
2441 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2443 =head2 Unary operators: bool
2445 If you wish to test against boolean columns or functions within your
2446 database you can use the C<-bool> and C<-not_bool> operators. For
2447 example to test the column C<is_user> being true and the column
2448 C<is_enabled> being false you would use:-
2452 -not_bool => 'is_enabled',
2457 WHERE is_user AND NOT is_enabled
2459 If a more complex combination is required, testing more conditions,
2460 then you should use the and/or operators:-
2465 -not_bool => { two=> { -rlike => 'bar' } },
2466 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2477 (NOT ( three = ? OR three > ? ))
2480 =head2 Nested conditions, -and/-or prefixes
2482 So far, we've seen how multiple conditions are joined with a top-level
2483 C<AND>. We can change this by putting the different conditions we want in
2484 hashes and then putting those hashes in an array. For example:
2489 status => { -like => ['pending%', 'dispatched'] },
2493 status => 'unassigned',
2497 This data structure would create the following:
2499 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2500 OR ( user = ? AND status = ? ) )";
2501 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2504 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2505 to change the logic inside:
2511 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2512 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2519 $stmt = "WHERE ( user = ?
2520 AND ( ( workhrs > ? AND geo = ? )
2521 OR ( workhrs < ? OR geo = ? ) ) )";
2522 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2524 =head3 Algebraic inconsistency, for historical reasons
2526 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2527 operator goes C<outside> of the nested structure; whereas when connecting
2528 several constraints on one column, the C<-and> operator goes
2529 C<inside> the arrayref. Here is an example combining both features:
2532 -and => [a => 1, b => 2],
2533 -or => [c => 3, d => 4],
2534 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2539 WHERE ( ( ( a = ? AND b = ? )
2540 OR ( c = ? OR d = ? )
2541 OR ( e LIKE ? AND e LIKE ? ) ) )
2543 This difference in syntax is unfortunate but must be preserved for
2544 historical reasons. So be careful: the two examples below would
2545 seem algebraically equivalent, but they are not
2548 { -like => 'foo%' },
2549 { -like => '%bar' },
2551 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2554 { col => { -like => 'foo%' } },
2555 { col => { -like => '%bar' } },
2557 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2560 =head2 Literal SQL and value type operators
2562 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2563 side" is a column name and the "right side" is a value (normally rendered as
2564 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2565 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2566 alter this behavior. There are several ways of doing so.
2570 This is a virtual operator that signals the string to its right side is an
2571 identifier (a column name) and not a value. For example to compare two
2572 columns you would write:
2575 priority => { '<', 2 },
2576 requestor => { -ident => 'submitter' },
2581 $stmt = "WHERE priority < ? AND requestor = submitter";
2584 If you are maintaining legacy code you may see a different construct as
2585 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2590 This is a virtual operator that signals that the construct to its right side
2591 is a value to be passed to DBI. This is for example necessary when you want
2592 to write a where clause against an array (for RDBMS that support such
2593 datatypes). For example:
2596 array => { -value => [1, 2, 3] }
2601 $stmt = 'WHERE array = ?';
2602 @bind = ([1, 2, 3]);
2604 Note that if you were to simply say:
2610 the result would probably not be what you wanted:
2612 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2617 Finally, sometimes only literal SQL will do. To include a random snippet
2618 of SQL verbatim, you specify it as a scalar reference. Consider this only
2619 as a last resort. Usually there is a better way. For example:
2622 priority => { '<', 2 },
2623 requestor => { -in => \'(SELECT name FROM hitmen)' },
2628 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2631 Note that in this example, you only get one bind parameter back, since
2632 the verbatim SQL is passed as part of the statement.
2636 Never use untrusted input as a literal SQL argument - this is a massive
2637 security risk (there is no way to check literal snippets for SQL
2638 injections and other nastyness). If you need to deal with untrusted input
2639 use literal SQL with placeholders as described next.
2641 =head3 Literal SQL with placeholders and bind values (subqueries)
2643 If the literal SQL to be inserted has placeholders and bind values,
2644 use a reference to an arrayref (yes this is a double reference --
2645 not so common, but perfectly legal Perl). For example, to find a date
2646 in Postgres you can use something like this:
2649 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2654 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2657 Note that you must pass the bind values in the same format as they are returned
2658 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2659 to C<columns>, you must provide the bind values in the
2660 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2661 scalar value; most commonly the column name, but you can use any scalar value
2662 (including references and blessed references), L<SQL::Abstract> will simply
2663 pass it through intact. So if C<bindtype> is set to C<columns> the above
2664 example will look like:
2667 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2670 Literal SQL is especially useful for nesting parenthesized clauses in the
2671 main SQL query. Here is a first example:
2673 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2677 bar => \["IN ($sub_stmt)" => @sub_bind],
2682 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2683 WHERE c2 < ? AND c3 LIKE ?))";
2684 @bind = (1234, 100, "foo%");
2686 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2687 are expressed in the same way. Of course the C<$sub_stmt> and
2688 its associated bind values can be generated through a former call
2691 my ($sub_stmt, @sub_bind)
2692 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2693 c3 => {-like => "foo%"}});
2696 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2699 In the examples above, the subquery was used as an operator on a column;
2700 but the same principle also applies for a clause within the main C<%where>
2701 hash, like an EXISTS subquery:
2703 my ($sub_stmt, @sub_bind)
2704 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2705 my %where = ( -and => [
2707 \["EXISTS ($sub_stmt)" => @sub_bind],
2712 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2713 WHERE c1 = ? AND c2 > t0.c0))";
2717 Observe that the condition on C<c2> in the subquery refers to
2718 column C<t0.c0> of the main query: this is I<not> a bind
2719 value, so we have to express it through a scalar ref.
2720 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2721 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2722 what we wanted here.
2724 Finally, here is an example where a subquery is used
2725 for expressing unary negation:
2727 my ($sub_stmt, @sub_bind)
2728 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2729 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2731 lname => {like => '%son%'},
2732 \["NOT ($sub_stmt)" => @sub_bind],
2737 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2738 @bind = ('%son%', 10, 20)
2740 =head3 Deprecated usage of Literal SQL
2742 Below are some examples of archaic use of literal SQL. It is shown only as
2743 reference for those who deal with legacy code. Each example has a much
2744 better, cleaner and safer alternative that users should opt for in new code.
2750 my %where = ( requestor => \'IS NOT NULL' )
2752 $stmt = "WHERE requestor IS NOT NULL"
2754 This used to be the way of generating NULL comparisons, before the handling
2755 of C<undef> got formalized. For new code please use the superior syntax as
2756 described in L</Tests for NULL values>.
2760 my %where = ( requestor => \'= submitter' )
2762 $stmt = "WHERE requestor = submitter"
2764 This used to be the only way to compare columns. Use the superior L</-ident>
2765 method for all new code. For example an identifier declared in such a way
2766 will be properly quoted if L</quote_char> is properly set, while the legacy
2767 form will remain as supplied.
2771 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2773 $stmt = "WHERE completed > ? AND is_ready"
2774 @bind = ('2012-12-21')
2776 Using an empty string literal used to be the only way to express a boolean.
2777 For all new code please use the much more readable
2778 L<-bool|/Unary operators: bool> operator.
2784 These pages could go on for a while, since the nesting of the data
2785 structures this module can handle are pretty much unlimited (the
2786 module implements the C<WHERE> expansion as a recursive function
2787 internally). Your best bet is to "play around" with the module a
2788 little to see how the data structures behave, and choose the best
2789 format for your data based on that.
2791 And of course, all the values above will probably be replaced with
2792 variables gotten from forms or the command line. After all, if you
2793 knew everything ahead of time, you wouldn't have to worry about
2794 dynamically-generating SQL and could just hardwire it into your
2797 =head1 ORDER BY CLAUSES
2799 Some functions take an order by clause. This can either be a scalar (just a
2800 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2801 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2804 Given | Will Generate
2805 ---------------------------------------------------------------
2807 'colA' | ORDER BY colA
2809 [qw/colA colB/] | ORDER BY colA, colB
2811 {-asc => 'colA'} | ORDER BY colA ASC
2813 {-desc => 'colB'} | ORDER BY colB DESC
2815 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2817 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2819 \'colA DESC' | ORDER BY colA DESC
2821 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2822 | /* ...with $x bound to ? */
2825 { -asc => 'colA' }, | colA ASC,
2826 { -desc => [qw/colB/] }, | colB DESC,
2827 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2828 \'colE DESC', | colE DESC,
2829 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2830 ] | /* ...with $x bound to ? */
2831 ===============================================================
2835 =head1 SPECIAL OPERATORS
2837 my $sqlmaker = SQL::Abstract->new(special_ops => [
2841 my ($self, $field, $op, $arg) = @_;
2847 handler => 'method_name',
2851 A "special operator" is a SQL syntactic clause that can be
2852 applied to a field, instead of a usual binary operator.
2855 WHERE field IN (?, ?, ?)
2856 WHERE field BETWEEN ? AND ?
2857 WHERE MATCH(field) AGAINST (?, ?)
2859 Special operators IN and BETWEEN are fairly standard and therefore
2860 are builtin within C<SQL::Abstract> (as the overridable methods
2861 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2862 like the MATCH .. AGAINST example above which is specific to MySQL,
2863 you can write your own operator handlers - supply a C<special_ops>
2864 argument to the C<new> method. That argument takes an arrayref of
2865 operator definitions; each operator definition is a hashref with two
2872 the regular expression to match the operator
2876 Either a coderef or a plain scalar method name. In both cases
2877 the expected return is C<< ($sql, @bind) >>.
2879 When supplied with a method name, it is simply called on the
2880 L<SQL::Abstract> object as:
2882 $self->$method_name($field, $op, $arg)
2886 $field is the LHS of the operator
2887 $op is the part that matched the handler regex
2890 When supplied with a coderef, it is called as:
2892 $coderef->($self, $field, $op, $arg)
2897 For example, here is an implementation
2898 of the MATCH .. AGAINST syntax for MySQL
2900 my $sqlmaker = SQL::Abstract->new(special_ops => [
2902 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2903 {regex => qr/^match$/i,
2905 my ($self, $field, $op, $arg) = @_;
2906 $arg = [$arg] if not ref $arg;
2907 my $label = $self->_quote($field);
2908 my ($placeholder) = $self->_convert('?');
2909 my $placeholders = join ", ", (($placeholder) x @$arg);
2910 my $sql = $self->_sqlcase('match') . " ($label) "
2911 . $self->_sqlcase('against') . " ($placeholders) ";
2912 my @bind = $self->_bindtype($field, @$arg);
2913 return ($sql, @bind);
2920 =head1 UNARY OPERATORS
2922 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2926 my ($self, $op, $arg) = @_;
2932 handler => 'method_name',
2936 A "unary operator" is a SQL syntactic clause that can be
2937 applied to a field - the operator goes before the field
2939 You can write your own operator handlers - supply a C<unary_ops>
2940 argument to the C<new> method. That argument takes an arrayref of
2941 operator definitions; each operator definition is a hashref with two
2948 the regular expression to match the operator
2952 Either a coderef or a plain scalar method name. In both cases
2953 the expected return is C<< $sql >>.
2955 When supplied with a method name, it is simply called on the
2956 L<SQL::Abstract> object as:
2958 $self->$method_name($op, $arg)
2962 $op is the part that matched the handler regex
2963 $arg is the RHS or argument of the operator
2965 When supplied with a coderef, it is called as:
2967 $coderef->($self, $op, $arg)
2975 Thanks to some benchmarking by Mark Stosberg, it turns out that
2976 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2977 I must admit this wasn't an intentional design issue, but it's a
2978 byproduct of the fact that you get to control your C<DBI> handles
2981 To maximize performance, use a code snippet like the following:
2983 # prepare a statement handle using the first row
2984 # and then reuse it for the rest of the rows
2986 for my $href (@array_of_hashrefs) {
2987 $stmt ||= $sql->insert('table', $href);
2988 $sth ||= $dbh->prepare($stmt);
2989 $sth->execute($sql->values($href));
2992 The reason this works is because the keys in your C<$href> are sorted
2993 internally by B<SQL::Abstract>. Thus, as long as your data retains
2994 the same structure, you only have to generate the SQL the first time
2995 around. On subsequent queries, simply use the C<values> function provided
2996 by this module to return your values in the correct order.
2998 However this depends on the values having the same type - if, for
2999 example, the values of a where clause may either have values
3000 (resulting in sql of the form C<column = ?> with a single bind
3001 value), or alternatively the values might be C<undef> (resulting in
3002 sql of the form C<column IS NULL> with no bind value) then the
3003 caching technique suggested will not work.
3007 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
3008 really like this part (I do, at least). Building up a complex query
3009 can be as simple as the following:
3016 use CGI::FormBuilder;
3019 my $form = CGI::FormBuilder->new(...);
3020 my $sql = SQL::Abstract->new;
3022 if ($form->submitted) {
3023 my $field = $form->field;
3024 my $id = delete $field->{id};
3025 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
3028 Of course, you would still have to connect using C<DBI> to run the
3029 query, but the point is that if you make your form look like your
3030 table, the actual query script can be extremely simplistic.
3032 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
3033 a fast interface to returning and formatting data. I frequently
3034 use these three modules together to write complex database query
3035 apps in under 50 lines.
3037 =head1 HOW TO CONTRIBUTE
3039 Contributions are always welcome, in all usable forms (we especially
3040 welcome documentation improvements). The delivery methods include git-
3041 or unified-diff formatted patches, GitHub pull requests, or plain bug
3042 reports either via RT or the Mailing list. Contributors are generally
3043 granted full access to the official repository after their first several
3044 patches pass successful review.
3046 This project is maintained in a git repository. The code and related tools are
3047 accessible at the following locations:
3051 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
3053 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
3055 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
3057 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
3063 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
3064 Great care has been taken to preserve the I<published> behavior
3065 documented in previous versions in the 1.* family; however,
3066 some features that were previously undocumented, or behaved
3067 differently from the documentation, had to be changed in order
3068 to clarify the semantics. Hence, client code that was relying
3069 on some dark areas of C<SQL::Abstract> v1.*
3070 B<might behave differently> in v1.50.
3072 The main changes are:
3078 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
3082 support for the { operator => \"..." } construct (to embed literal SQL)
3086 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
3090 optional support for L<array datatypes|/"Inserting and Updating Arrays">
3094 defensive programming: check arguments
3098 fixed bug with global logic, which was previously implemented
3099 through global variables yielding side-effects. Prior versions would
3100 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3101 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3102 Now this is interpreted
3103 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3108 fixed semantics of _bindtype on array args
3112 dropped the C<_anoncopy> of the %where tree. No longer necessary,
3113 we just avoid shifting arrays within that tree.
3117 dropped the C<_modlogic> function
3121 =head1 ACKNOWLEDGEMENTS
3123 There are a number of individuals that have really helped out with
3124 this module. Unfortunately, most of them submitted bugs via CPAN
3125 so I have no idea who they are! But the people I do know are:
3127 Ash Berlin (order_by hash term support)
3128 Matt Trout (DBIx::Class support)
3129 Mark Stosberg (benchmarking)
3130 Chas Owens (initial "IN" operator support)
3131 Philip Collins (per-field SQL functions)
3132 Eric Kolve (hashref "AND" support)
3133 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3134 Dan Kubb (support for "quote_char" and "name_sep")
3135 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
3136 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
3137 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
3138 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
3139 Oliver Charles (support for "RETURNING" after "INSERT")
3145 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
3149 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3151 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3153 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3154 While not an official support venue, C<DBIx::Class> makes heavy use of
3155 C<SQL::Abstract>, and as such list members there are very familiar with
3156 how to create queries.
3160 This module is free software; you may copy this under the same
3161 terms as perl itself (either the GNU General Public License or
3162 the Artistic License)