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/^ (?: 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{user_special_ops} = [ @{$opt{special_ops} ||= []} ];
159 # regexes are applied in order, thus push after user-defines
160 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
163 $opt{unary_ops} ||= [];
165 # rudimentary sanity-check for user supplied bits treated as functions/operators
166 # If a purported function matches this regular expression, an exception is thrown.
167 # Literal SQL is *NOT* subject to this check, only functions (and column names
168 # when quoting is not in effect)
171 # need to guard against ()'s in column names too, but this will break tons of
172 # hacks... ideas anyone?
173 $opt{injection_guard} ||= qr/
179 return bless \%opt, $class;
182 sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
183 sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
185 sub _assert_pass_injection_guard {
186 if ($_[1] =~ $_[0]->{injection_guard}) {
187 my $class = ref $_[0];
188 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
189 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
190 . "{injection_guard} attribute to ${class}->new()"
195 #======================================================================
197 #======================================================================
201 my $table = $self->_table(shift);
202 my $data = shift || return;
205 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
206 my ($sql, @bind) = $self->$method($data);
207 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
209 if ($options->{returning}) {
210 my ($s, @b) = $self->_insert_returning($options);
215 return wantarray ? ($sql, @bind) : $sql;
218 # So that subclasses can override INSERT ... RETURNING separately from
219 # UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
220 sub _insert_returning { shift->_returning(@_) }
223 my ($self, $options) = @_;
225 my $f = $options->{returning};
227 my $fieldlist = $self->_SWITCH_refkind($f, {
228 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$f;},
229 SCALAR => sub {$self->_quote($f)},
230 SCALARREF => sub {$$f},
232 return $self->_sqlcase(' returning ') . $fieldlist;
235 sub _insert_HASHREF { # explicit list of fields and then values
236 my ($self, $data) = @_;
238 my @fields = sort keys %$data;
240 my ($sql, @bind) = $self->_insert_values($data);
243 $_ = $self->_quote($_) foreach @fields;
244 $sql = "( ".join(", ", @fields).") ".$sql;
246 return ($sql, @bind);
249 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
250 my ($self, $data) = @_;
252 # no names (arrayref) so can't generate bindtype
253 $self->{bindtype} ne 'columns'
254 or belch "can't do 'columns' bindtype when called with arrayref";
256 my (@values, @all_bind);
257 foreach my $value (@$data) {
258 my ($values, @bind) = $self->_insert_value(undef, $value);
259 push @values, $values;
260 push @all_bind, @bind;
262 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
263 return ($sql, @all_bind);
266 sub _insert_ARRAYREFREF { # literal SQL with bind
267 my ($self, $data) = @_;
269 my ($sql, @bind) = @${$data};
270 $self->_assert_bindval_matches_bindtype(@bind);
272 return ($sql, @bind);
276 sub _insert_SCALARREF { # literal SQL without bind
277 my ($self, $data) = @_;
283 my ($self, $data) = @_;
285 my (@values, @all_bind);
286 foreach my $column (sort keys %$data) {
287 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
288 push @values, $values;
289 push @all_bind, @bind;
291 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
292 return ($sql, @all_bind);
296 my ($self, $column, $v) = @_;
298 my (@values, @all_bind);
299 $self->_SWITCH_refkind($v, {
302 if ($self->{array_datatypes}) { # if array datatype are activated
304 push @all_bind, $self->_bindtype($column, $v);
306 else { # else literal SQL with bind
307 my ($sql, @bind) = @$v;
308 $self->_assert_bindval_matches_bindtype(@bind);
310 push @all_bind, @bind;
314 ARRAYREFREF => sub { # literal SQL with bind
315 my ($sql, @bind) = @${$v};
316 $self->_assert_bindval_matches_bindtype(@bind);
318 push @all_bind, @bind;
321 # THINK: anything useful to do with a HASHREF ?
322 HASHREF => sub { # (nothing, but old SQLA passed it through)
323 #TODO in SQLA >= 2.0 it will die instead
324 belch "HASH ref as bind value in insert is not supported";
326 push @all_bind, $self->_bindtype($column, $v);
329 SCALARREF => sub { # literal SQL without bind
333 SCALAR_or_UNDEF => sub {
335 push @all_bind, $self->_bindtype($column, $v);
340 my $sql = join(", ", @values);
341 return ($sql, @all_bind);
346 #======================================================================
348 #======================================================================
353 my $table = $self->_table(shift);
354 my $data = shift || return;
358 # first build the 'SET' part of the sql statement
359 puke "Unsupported data type specified to \$sql->update"
360 unless ref $data eq 'HASH';
362 my ($sql, @all_bind) = $self->_update_set_values($data);
363 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
367 my($where_sql, @where_bind) = $self->where($where);
369 push @all_bind, @where_bind;
372 if ($options->{returning}) {
373 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
374 $sql .= $returning_sql;
375 push @all_bind, @returning_bind;
378 return wantarray ? ($sql, @all_bind) : $sql;
381 sub _update_set_values {
382 my ($self, $data) = @_;
384 my (@set, @all_bind);
385 for my $k (sort keys %$data) {
388 my $label = $self->_quote($k);
390 $self->_SWITCH_refkind($v, {
392 if ($self->{array_datatypes}) { # array datatype
393 push @set, "$label = ?";
394 push @all_bind, $self->_bindtype($k, $v);
396 else { # literal SQL with bind
397 my ($sql, @bind) = @$v;
398 $self->_assert_bindval_matches_bindtype(@bind);
399 push @set, "$label = $sql";
400 push @all_bind, @bind;
403 ARRAYREFREF => sub { # literal SQL with bind
404 my ($sql, @bind) = @${$v};
405 $self->_assert_bindval_matches_bindtype(@bind);
406 push @set, "$label = $sql";
407 push @all_bind, @bind;
409 SCALARREF => sub { # literal SQL without bind
410 push @set, "$label = $$v";
413 my ($op, $arg, @rest) = %$v;
415 puke 'Operator calls in update must be in the form { -op => $arg }'
416 if (@rest or not $op =~ /^\-(.+)/);
418 local our $Cur_Col_Meta = $k;
419 my ($sql, @bind) = $self->_render_expr(
420 $self->_expand_expr_hashpair($op, $arg)
423 push @set, "$label = $sql";
424 push @all_bind, @bind;
426 SCALAR_or_UNDEF => sub {
427 push @set, "$label = ?";
428 push @all_bind, $self->_bindtype($k, $v);
434 my $sql = join ', ', @set;
436 return ($sql, @all_bind);
439 # So that subclasses can override UPDATE ... RETURNING separately from
441 sub _update_returning { shift->_returning(@_) }
445 #======================================================================
447 #======================================================================
452 my $table = $self->_table(shift);
453 my $fields = shift || '*';
457 my ($fields_sql, @bind) = $self->_select_fields($fields);
459 my ($where_sql, @where_bind) = $self->where($where, $order);
460 push @bind, @where_bind;
462 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
463 $self->_sqlcase('from'), $table)
466 return wantarray ? ($sql, @bind) : $sql;
470 my ($self, $fields) = @_;
471 return ref $fields eq 'ARRAY' ? join ', ', map { $self->_quote($_) } @$fields
475 #======================================================================
477 #======================================================================
482 my $table = $self->_table(shift);
486 my($where_sql, @bind) = $self->where($where);
487 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
489 if ($options->{returning}) {
490 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
491 $sql .= $returning_sql;
492 push @bind, @returning_bind;
495 return wantarray ? ($sql, @bind) : $sql;
498 # So that subclasses can override DELETE ... RETURNING separately from
500 sub _delete_returning { shift->_returning(@_) }
504 #======================================================================
506 #======================================================================
510 # Finally, a separate routine just to handle WHERE clauses
512 my ($self, $where, $order) = @_;
515 my ($sql, @bind) = defined($where)
516 ? $self->_recurse_where($where)
518 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
522 my ($order_sql, @order_bind) = $self->_order_by($order);
524 push @bind, @order_bind;
527 return wantarray ? ($sql, @bind) : $sql;
531 my ($self, $expr, $logic, $default_scalar_to) = @_;
532 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
533 return undef unless defined($expr);
534 if (ref($expr) eq 'HASH') {
535 if (keys %$expr > 1) {
539 map $self->_expand_expr_hashpair($_ => $expr->{$_}, $logic),
543 return unless %$expr;
544 return $self->_expand_expr_hashpair(%$expr, $logic);
546 if (ref($expr) eq 'ARRAY') {
547 my $logic = lc($logic || $self->{logic});
548 $logic eq 'and' or $logic eq 'or' or puke "unknown logic: $logic";
554 while (my ($el) = splice @expr, 0, 1) {
555 puke "Supplying an empty left hand side argument is not supported in array-pairs"
556 unless defined($el) and length($el);
557 my $elref = ref($el);
559 push(@res, $self->_expand_expr({ $el, shift(@expr) }));
560 } elsif ($elref eq 'ARRAY') {
561 push(@res, $self->_expand_expr($el)) if @$el;
562 } elsif (my $l = is_literal_value($el)) {
563 push @res, { -literal => $l };
564 } elsif ($elref eq 'HASH') {
565 push @res, $self->_expand_expr($el);
570 return { -op => [ $logic, @res ] };
572 if (my $literal = is_literal_value($expr)) {
573 return +{ -literal => $literal };
575 if (!ref($expr) or Scalar::Util::blessed($expr)) {
576 if (my $d = $Default_Scalar_To) {
577 return +{ $d => $expr };
579 if (my $m = our $Cur_Col_Meta) {
580 return +{ -bind => [ $m, $expr ] };
582 return +{ -value => $expr };
587 sub _expand_expr_hashpair {
588 my ($self, $k, $v, $logic) = @_;
589 unless (defined($k) and length($k)) {
590 if (defined($k) and my $literal = is_literal_value($v)) {
591 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
592 return { -literal => $literal };
594 puke "Supplying an empty left hand side argument is not supported";
597 $self->_assert_pass_injection_guard($k =~ /^-(.*)$/s);
598 if ($k =~ s/ [_\s]? \d+ $//x ) {
599 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
600 . "You probably wanted ...-and => [ $k => COND1, $k => COND2 ... ]";
603 return $self->_expand_expr($v);
607 return $self->_expand_expr($v);
609 puke "-bool => undef not supported" unless defined($v);
610 return { -ident => $v };
613 return { -op => [ 'not', $self->_expand_expr($v) ] };
615 if (my ($rest) = $k =~/^-not[_ ](.*)$/) {
618 $self->_expand_expr_hashpair("-${rest}", $v, $logic)
621 if (my ($logic) = $k =~ /^-(and|or)$/i) {
622 if (ref($v) eq 'HASH') {
623 return $self->_expand_expr($v, $logic);
625 if (ref($v) eq 'ARRAY') {
626 return $self->_expand_expr($v, $logic);
631 $op =~ s/^-// if length($op) > 1;
633 # top level special ops are illegal in general
634 puke "Illegal use of top-level '-$op'"
635 if List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
637 if ($k eq '-value' and my $m = our $Cur_Col_Meta) {
638 return +{ -bind => [ $m, $v ] };
640 if ($k eq '-op' or $k eq '-ident' or $k eq '-value' or $k eq '-bind' or $k eq '-literal' or $k eq '-func') {
646 and (keys %$v)[0] =~ /^-/
648 my ($func) = $k =~ /^-(.*)$/;
649 return +{ -func => [ $func, $self->_expand_expr($v) ] };
651 if (!ref($v) or is_literal_value($v)) {
652 return +{ -op => [ $k =~ /^-(.*)$/, $self->_expand_expr($v) ] };
659 and exists $v->{-value}
660 and not defined $v->{-value}
663 return $self->_expand_expr_hashpair($k => { $self->{cmp} => undef });
665 if (!ref($v) or Scalar::Util::blessed($v)) {
670 { -bind => [ $k, $v ] }
674 if (ref($v) eq 'HASH') {
678 map $self->_expand_expr_hashpair($k => { $_ => $v->{$_} }),
685 $self->_assert_pass_injection_guard($vk);
686 if ($vk =~ s/ [_\s]? \d+ $//x ) {
687 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
688 . "You probably wanted ...-and => [ -$vk => COND1, -$vk => COND2 ... ]";
690 if ($vk =~ /^(?:not[ _])?between$/) {
691 local our $Cur_Col_Meta = $k;
692 my @rhs = map $self->_expand_expr($_),
693 ref($vv) eq 'ARRAY' ? @$vv : $vv;
695 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
697 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
699 puke "Operator '${\uc($vk)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
702 join(' ', split '_', $vk),
707 if ($vk =~ /^(?:not[ _])?in$/) {
708 if (my $literal = is_literal_value($vv)) {
709 my ($sql, @bind) = @$literal;
710 my $opened_sql = $self->_open_outer_paren($sql);
712 $vk, { -ident => $k },
713 [ { -literal => [ $opened_sql, @bind ] } ]
717 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
718 . "-${\uc($vk)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
719 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
720 . 'will emit the logically correct SQL instead of raising this exception)'
722 puke("Argument passed to the '${\uc($vk)}' operator can not be undefined")
724 my @rhs = map $self->_expand_expr($_),
725 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
726 map { defined($_) ? $_: puke($undef_err) }
727 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
728 return $self->${\($vk =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
731 join(' ', split '_', $vk),
736 if ($vk eq 'ident') {
737 if (! defined $vv or ref $vv) {
738 puke "-$vk requires a single plain scalar argument (a quotable identifier)";
746 if ($vk eq 'value') {
747 return $self->_expand_expr_hashpair($k, undef) unless defined($vv);
751 { -bind => [ $k, $vv ] }
754 if ($vk =~ /^is(?:[ _]not)?$/) {
755 puke "$vk can only take undef as argument"
759 and exists($vv->{-value})
760 and !defined($vv->{-value})
763 return +{ -op => [ $vk.' null', { -ident => $k } ] };
765 if ($vk =~ /^(and|or)$/) {
766 if (ref($vv) eq 'HASH') {
769 map $self->_expand_expr_hashpair($k, { $_ => $vv->{$_} }),
774 if (my $us = List::Util::first { $vk =~ $_->{regex} } @{$self->{user_special_ops}}) {
775 return { -op => [ $vk, { -ident => $k }, $vv ] };
777 if (ref($vv) eq 'ARRAY') {
778 my ($logic, @values) = (
779 (defined($vv->[0]) and $vv->[0] =~ /^-(and|or)$/i)
784 $vk =~ $self->{inequality_op}
785 or join(' ', split '_', $vk) =~ $self->{not_like_op}
787 if (lc($logic) eq '-or' and @values > 1) {
788 my $op = uc join ' ', split '_', $vk;
789 belch "A multi-element arrayref as an argument to the inequality op '$op' "
790 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
791 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
796 # try to DWIM on equality operators
797 my $op = join ' ', split '_', $vk;
799 $op =~ $self->{equality_op} ? $self->sqlfalse
800 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
801 : $op =~ $self->{inequality_op} ? $self->sqltrue
802 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
803 : puke "operator '$op' applied on an empty array (field '$k')";
807 map $self->_expand_expr_hashpair($k => { $vk => $_ }),
815 and exists $vv->{-value}
816 and not defined $vv->{-value}
819 my $op = join ' ', split '_', $vk;
821 $op =~ /^not$/i ? 'is not' # legacy
822 : $op =~ $self->{equality_op} ? 'is'
823 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
824 : $op =~ $self->{inequality_op} ? 'is not'
825 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
826 : puke "unexpected operator '$op' with undef operand";
827 return +{ -op => [ $is.' null', { -ident => $k } ] };
829 local our $Cur_Col_Meta = $k;
833 $self->_expand_expr($vv)
836 if (ref($v) eq 'ARRAY') {
837 return $self->sqlfalse unless @$v;
838 $self->_debug("ARRAY($k) means distribute over elements");
840 $v->[0] =~ /^-((?:and|or))$/i
841 ? ($v = [ @{$v}[1..$#$v] ], $1)
842 : ($self->{logic} || 'or')
846 map $self->_expand_expr({ $k => $_ }, $this_logic), @$v
849 if (my $literal = is_literal_value($v)) {
851 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
854 my ($sql, @bind) = @$literal;
855 if ($self->{bindtype} eq 'columns') {
857 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
858 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
862 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
868 my ($self, $expr) = @_;
869 my ($k, $v, @rest) = %$expr;
871 my %op = map +("-$_" => '_render_'.$_),
872 qw(op func value bind ident literal);
873 if (my $meth = $op{$k}) {
874 return $self->$meth($v);
876 die "notreached: $k";
880 my ($self, $where, $logic) = @_;
882 #print STDERR Data::Dumper::Concise::Dumper([ $where, $logic ]);
884 my $where_exp = $self->_expand_expr($where, $logic);
886 #print STDERR Data::Dumper::Concise::Dumper([ EXP => $where_exp ]);
888 # dispatch on appropriate method according to refkind of $where
889 # my $method = $self->_METHOD_FOR_refkind("_where", $where_exp);
891 # my ($sql, @bind) = $self->$method($where_exp, $logic);
893 my ($sql, @bind) = defined($where_exp) ? $self->_render_expr($where_exp) : (undef);
895 # DBIx::Class used to call _recurse_where in scalar context
896 # something else might too...
898 return ($sql, @bind);
901 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
907 my ($self, $ident) = @_;
909 return $self->_convert($self->_quote($ident));
913 my ($self, $value) = @_;
915 return ($self->_convert('?'), $self->_bindtype(undef, $value));
918 my %unop_postfix = map +($_ => 1),
919 'is null', 'is not null',
927 my ($self, $args) = @_;
928 my ($left, $low, $high) = @$args;
929 my ($rhsql, @rhbind) = do {
931 puke "Single arg to between must be a literal"
932 unless $low->{-literal};
935 my ($l, $h) = map [ $self->_render_expr($_) ], $low, $high;
936 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
937 @{$l}[1..$#$l], @{$h}[1..$#$h])
940 my ($lhsql, @lhbind) = $self->_render_expr($left);
942 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
946 }), 'between', 'not between'),
950 my ($self, $args) = @_;
951 my ($lhs, $rhs) = @$args;
954 my ($sql, @bind) = $self->_render_expr($_);
955 push @in_bind, @bind;
958 my ($lhsql, @lbind) = $self->_render_expr($lhs);
960 $lhsql.' '.$self->_sqlcase($op).' ( '
971 my ($op, @args) = @$v;
972 $op =~ s/^-// if length($op) > 1;
974 if (my $h = $special{$op}) {
975 return $self->$h(\@args);
977 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{user_special_ops}}) {
978 puke "Special op '${op}' requires first value to be identifier"
979 unless my ($k) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
980 return $self->${\($us->{handler})}($k, $op, $args[1]);
982 my $final_op = $op =~ /^(?:is|not)_/ ? join(' ', split '_', $op) : $op;
983 if (@args == 1 and $op !~ /^(and|or)$/) {
984 my ($expr_sql, @bind) = $self->_render_expr($args[0]);
985 my $op_sql = $self->_sqlcase($final_op);
987 $unop_postfix{lc($final_op)}
988 ? "${expr_sql} ${op_sql}"
989 : "${op_sql} ${expr_sql}"
991 return (($op eq 'not' ? '('.$final_sql.')' : $final_sql), @bind);
993 my @parts = map [ $self->_render_expr($_) ], @args;
994 my ($final_sql) = map +($op =~ /^(and|or)$/ ? "(${_})" : $_), join(
995 ' '.$self->_sqlcase($final_op).' ',
1000 map @{$_}[1..$#$_], @parts
1007 my ($self, $rest) = @_;
1008 my ($func, @args) = @$rest;
1012 push @arg_sql, shift @x;
1014 } map [ $self->_render_expr($_) ], @args;
1015 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1019 my ($self, $bind) = @_;
1020 return ($self->_convert('?'), $self->_bindtype(@$bind));
1023 sub _render_literal {
1024 my ($self, $literal) = @_;
1025 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1029 # Some databases (SQLite) treat col IN (1, 2) different from
1030 # col IN ( (1, 2) ). Use this to strip all outer parens while
1031 # adding them back in the corresponding method
1032 sub _open_outer_paren {
1033 my ($self, $sql) = @_;
1035 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1037 # there are closing parens inside, need the heavy duty machinery
1038 # to reevaluate the extraction starting from $sql (full reevaluation)
1039 if ($inner =~ /\)/) {
1040 require Text::Balanced;
1042 my (undef, $remainder) = do {
1043 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1045 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1048 # the entire expression needs to be a balanced bracketed thing
1049 # (after an extract no remainder sans trailing space)
1050 last if defined $remainder and $remainder =~ /\S/;
1060 #======================================================================
1062 #======================================================================
1065 my ($self, $arg) = @_;
1067 return '' unless defined($arg);
1069 my @chunks = $self->_order_by_chunks($arg);
1073 my ($s, @b) = $self->_render_expr($_);
1080 $self->_sqlcase(' order by'),
1086 return wantarray ? ($sql, @bind) : $sql;
1089 sub _order_by_chunks {
1090 my ($self, $arg) = @_;
1092 if (ref($arg) eq 'ARRAY') {
1093 return map $self->_order_by_chunks($_), @$arg;
1095 if (my $l = is_literal_value($arg)) {
1096 return +{ -literal => $l };
1099 return +{ -ident => $arg };
1101 if (ref($arg) eq 'HASH') {
1102 my ($key, $val, @rest) = %$arg;
1104 return () unless $key;
1106 if (@rest or not $key =~ /^-(desc|asc)/i) {
1107 puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
1112 map +{ -op => [ $dir, $_ ] }, $self->_order_by_chunks($val);
1117 #======================================================================
1118 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1119 #======================================================================
1124 $self->_SWITCH_refkind($from, {
1125 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
1126 SCALAR => sub {$self->_quote($from)},
1127 SCALARREF => sub {$$from},
1132 #======================================================================
1134 #======================================================================
1136 # highly optimized, as it's called way too often
1138 # my ($self, $label) = @_;
1140 return '' unless defined $_[1];
1141 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1143 $_[0]->{quote_char} or
1144 ($_[0]->_assert_pass_injection_guard($_[1]), return $_[1]);
1146 my $qref = ref $_[0]->{quote_char};
1148 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1149 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1150 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1152 my $esc = $_[0]->{escape_char} || $r;
1154 # parts containing * are naturally unquoted
1155 return join($_[0]->{name_sep}||'', map
1156 +( $_ eq '*' ? $_ : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r } ),
1157 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
1162 # Conversion, if applicable
1164 #my ($self, $arg) = @_;
1165 if ($_[0]->{convert}) {
1166 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
1173 #my ($self, $col, @vals) = @_;
1174 # called often - tighten code
1175 return $_[0]->{bindtype} eq 'columns'
1176 ? map {[$_[1], $_]} @_[2 .. $#_]
1181 # Dies if any element of @bind is not in [colname => value] format
1182 # if bindtype is 'columns'.
1183 sub _assert_bindval_matches_bindtype {
1184 # my ($self, @bind) = @_;
1186 if ($self->{bindtype} eq 'columns') {
1188 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1189 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1195 sub _join_sql_clauses {
1196 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1198 if (@$clauses_aref > 1) {
1199 my $join = " " . $self->_sqlcase($logic) . " ";
1200 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1201 return ($sql, @$bind_aref);
1203 elsif (@$clauses_aref) {
1204 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1207 return (); # if no SQL, ignore @$bind_aref
1212 # Fix SQL case, if so requested
1214 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1215 # don't touch the argument ... crooked logic, but let's not change it!
1216 return $_[0]->{case} ? $_[1] : uc($_[1]);
1220 #======================================================================
1221 # DISPATCHING FROM REFKIND
1222 #======================================================================
1225 my ($self, $data) = @_;
1227 return 'UNDEF' unless defined $data;
1229 # blessed objects are treated like scalars
1230 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1232 return 'SCALAR' unless $ref;
1235 while ($ref eq 'REF') {
1237 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1241 return ($ref||'SCALAR') . ('REF' x $n_steps);
1245 my ($self, $data) = @_;
1246 my @try = ($self->_refkind($data));
1247 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1248 push @try, 'FALLBACK';
1252 sub _METHOD_FOR_refkind {
1253 my ($self, $meth_prefix, $data) = @_;
1256 for (@{$self->_try_refkind($data)}) {
1257 $method = $self->can($meth_prefix."_".$_)
1261 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1265 sub _SWITCH_refkind {
1266 my ($self, $data, $dispatch_table) = @_;
1269 for (@{$self->_try_refkind($data)}) {
1270 $coderef = $dispatch_table->{$_}
1274 puke "no dispatch entry for ".$self->_refkind($data)
1283 #======================================================================
1284 # VALUES, GENERATE, AUTOLOAD
1285 #======================================================================
1287 # LDNOTE: original code from nwiger, didn't touch code in that section
1288 # I feel the AUTOLOAD stuff should not be the default, it should
1289 # only be activated on explicit demand by user.
1293 my $data = shift || return;
1294 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1295 unless ref $data eq 'HASH';
1298 foreach my $k (sort keys %$data) {
1299 my $v = $data->{$k};
1300 $self->_SWITCH_refkind($v, {
1302 if ($self->{array_datatypes}) { # array datatype
1303 push @all_bind, $self->_bindtype($k, $v);
1305 else { # literal SQL with bind
1306 my ($sql, @bind) = @$v;
1307 $self->_assert_bindval_matches_bindtype(@bind);
1308 push @all_bind, @bind;
1311 ARRAYREFREF => sub { # literal SQL with bind
1312 my ($sql, @bind) = @${$v};
1313 $self->_assert_bindval_matches_bindtype(@bind);
1314 push @all_bind, @bind;
1316 SCALARREF => sub { # literal SQL without bind
1318 SCALAR_or_UNDEF => sub {
1319 push @all_bind, $self->_bindtype($k, $v);
1330 my(@sql, @sqlq, @sqlv);
1334 if ($ref eq 'HASH') {
1335 for my $k (sort keys %$_) {
1338 my $label = $self->_quote($k);
1339 if ($r eq 'ARRAY') {
1340 # literal SQL with bind
1341 my ($sql, @bind) = @$v;
1342 $self->_assert_bindval_matches_bindtype(@bind);
1343 push @sqlq, "$label = $sql";
1345 } elsif ($r eq 'SCALAR') {
1346 # literal SQL without bind
1347 push @sqlq, "$label = $$v";
1349 push @sqlq, "$label = ?";
1350 push @sqlv, $self->_bindtype($k, $v);
1353 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1354 } elsif ($ref eq 'ARRAY') {
1355 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1358 if ($r eq 'ARRAY') { # literal SQL with bind
1359 my ($sql, @bind) = @$v;
1360 $self->_assert_bindval_matches_bindtype(@bind);
1363 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1364 # embedded literal SQL
1371 push @sql, '(' . join(', ', @sqlq) . ')';
1372 } elsif ($ref eq 'SCALAR') {
1376 # strings get case twiddled
1377 push @sql, $self->_sqlcase($_);
1381 my $sql = join ' ', @sql;
1383 # this is pretty tricky
1384 # if ask for an array, return ($stmt, @bind)
1385 # otherwise, s/?/shift @sqlv/ to put it inline
1387 return ($sql, @sqlv);
1389 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1390 ref $d ? $d->[1] : $d/e;
1399 # This allows us to check for a local, then _form, attr
1401 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1402 return $self->generate($name, @_);
1413 SQL::Abstract - Generate SQL from Perl data structures
1419 my $sql = SQL::Abstract->new;
1421 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1423 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1425 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1427 my($stmt, @bind) = $sql->delete($table, \%where);
1429 # Then, use these in your DBI statements
1430 my $sth = $dbh->prepare($stmt);
1431 $sth->execute(@bind);
1433 # Just generate the WHERE clause
1434 my($stmt, @bind) = $sql->where(\%where, $order);
1436 # Return values in the same order, for hashed queries
1437 # See PERFORMANCE section for more details
1438 my @bind = $sql->values(\%fieldvals);
1442 This module was inspired by the excellent L<DBIx::Abstract>.
1443 However, in using that module I found that what I really wanted
1444 to do was generate SQL, but still retain complete control over my
1445 statement handles and use the DBI interface. So, I set out to
1446 create an abstract SQL generation module.
1448 While based on the concepts used by L<DBIx::Abstract>, there are
1449 several important differences, especially when it comes to WHERE
1450 clauses. I have modified the concepts used to make the SQL easier
1451 to generate from Perl data structures and, IMO, more intuitive.
1452 The underlying idea is for this module to do what you mean, based
1453 on the data structures you provide it. The big advantage is that
1454 you don't have to modify your code every time your data changes,
1455 as this module figures it out.
1457 To begin with, an SQL INSERT is as easy as just specifying a hash
1458 of C<key=value> pairs:
1461 name => 'Jimbo Bobson',
1462 phone => '123-456-7890',
1463 address => '42 Sister Lane',
1464 city => 'St. Louis',
1465 state => 'Louisiana',
1468 The SQL can then be generated with this:
1470 my($stmt, @bind) = $sql->insert('people', \%data);
1472 Which would give you something like this:
1474 $stmt = "INSERT INTO people
1475 (address, city, name, phone, state)
1476 VALUES (?, ?, ?, ?, ?)";
1477 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1478 '123-456-7890', 'Louisiana');
1480 These are then used directly in your DBI code:
1482 my $sth = $dbh->prepare($stmt);
1483 $sth->execute(@bind);
1485 =head2 Inserting and Updating Arrays
1487 If your database has array types (like for example Postgres),
1488 activate the special option C<< array_datatypes => 1 >>
1489 when creating the C<SQL::Abstract> object.
1490 Then you may use an arrayref to insert and update database array types:
1492 my $sql = SQL::Abstract->new(array_datatypes => 1);
1494 planets => [qw/Mercury Venus Earth Mars/]
1497 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1501 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1503 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1506 =head2 Inserting and Updating SQL
1508 In order to apply SQL functions to elements of your C<%data> you may
1509 specify a reference to an arrayref for the given hash value. For example,
1510 if you need to execute the Oracle C<to_date> function on a value, you can
1511 say something like this:
1515 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1518 The first value in the array is the actual SQL. Any other values are
1519 optional and would be included in the bind values array. This gives
1522 my($stmt, @bind) = $sql->insert('people', \%data);
1524 $stmt = "INSERT INTO people (name, date_entered)
1525 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1526 @bind = ('Bill', '03/02/2003');
1528 An UPDATE is just as easy, all you change is the name of the function:
1530 my($stmt, @bind) = $sql->update('people', \%data);
1532 Notice that your C<%data> isn't touched; the module will generate
1533 the appropriately quirky SQL for you automatically. Usually you'll
1534 want to specify a WHERE clause for your UPDATE, though, which is
1535 where handling C<%where> hashes comes in handy...
1537 =head2 Complex where statements
1539 This module can generate pretty complicated WHERE statements
1540 easily. For example, simple C<key=value> pairs are taken to mean
1541 equality, and if you want to see if a field is within a set
1542 of values, you can use an arrayref. Let's say we wanted to
1543 SELECT some data based on this criteria:
1546 requestor => 'inna',
1547 worker => ['nwiger', 'rcwe', 'sfz'],
1548 status => { '!=', 'completed' }
1551 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1553 The above would give you something like this:
1555 $stmt = "SELECT * FROM tickets WHERE
1556 ( requestor = ? ) AND ( status != ? )
1557 AND ( worker = ? OR worker = ? OR worker = ? )";
1558 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1560 Which you could then use in DBI code like so:
1562 my $sth = $dbh->prepare($stmt);
1563 $sth->execute(@bind);
1569 The methods are simple. There's one for every major SQL operation,
1570 and a constructor you use first. The arguments are specified in a
1571 similar order for each method (table, then fields, then a where
1572 clause) to try and simplify things.
1574 =head2 new(option => 'value')
1576 The C<new()> function takes a list of options and values, and returns
1577 a new B<SQL::Abstract> object which can then be used to generate SQL
1578 through the methods below. The options accepted are:
1584 If set to 'lower', then SQL will be generated in all lowercase. By
1585 default SQL is generated in "textbook" case meaning something like:
1587 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1589 Any setting other than 'lower' is ignored.
1593 This determines what the default comparison operator is. By default
1594 it is C<=>, meaning that a hash like this:
1596 %where = (name => 'nwiger', email => 'nate@wiger.org');
1598 Will generate SQL like this:
1600 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1602 However, you may want loose comparisons by default, so if you set
1603 C<cmp> to C<like> you would get SQL such as:
1605 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1607 You can also override the comparison on an individual basis - see
1608 the huge section on L</"WHERE CLAUSES"> at the bottom.
1610 =item sqltrue, sqlfalse
1612 Expressions for inserting boolean values within SQL statements.
1613 By default these are C<1=1> and C<1=0>. They are used
1614 by the special operators C<-in> and C<-not_in> for generating
1615 correct SQL even when the argument is an empty array (see below).
1619 This determines the default logical operator for multiple WHERE
1620 statements in arrays or hashes. If absent, the default logic is "or"
1621 for arrays, and "and" for hashes. This means that a WHERE
1625 event_date => {'>=', '2/13/99'},
1626 event_date => {'<=', '4/24/03'},
1629 will generate SQL like this:
1631 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1633 This is probably not what you want given this query, though (look
1634 at the dates). To change the "OR" to an "AND", simply specify:
1636 my $sql = SQL::Abstract->new(logic => 'and');
1638 Which will change the above C<WHERE> to:
1640 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1642 The logic can also be changed locally by inserting
1643 a modifier in front of an arrayref:
1645 @where = (-and => [event_date => {'>=', '2/13/99'},
1646 event_date => {'<=', '4/24/03'} ]);
1648 See the L</"WHERE CLAUSES"> section for explanations.
1652 This will automatically convert comparisons using the specified SQL
1653 function for both column and value. This is mostly used with an argument
1654 of C<upper> or C<lower>, so that the SQL will have the effect of
1655 case-insensitive "searches". For example, this:
1657 $sql = SQL::Abstract->new(convert => 'upper');
1658 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1660 Will turn out the following SQL:
1662 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1664 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1665 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1666 not validate this option; it will just pass through what you specify verbatim).
1670 This is a kludge because many databases suck. For example, you can't
1671 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1672 Instead, you have to use C<bind_param()>:
1674 $sth->bind_param(1, 'reg data');
1675 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1677 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1678 which loses track of which field each slot refers to. Fear not.
1680 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1681 Currently, you can specify either C<normal> (default) or C<columns>. If you
1682 specify C<columns>, you will get an array that looks like this:
1684 my $sql = SQL::Abstract->new(bindtype => 'columns');
1685 my($stmt, @bind) = $sql->insert(...);
1688 [ 'column1', 'value1' ],
1689 [ 'column2', 'value2' ],
1690 [ 'column3', 'value3' ],
1693 You can then iterate through this manually, using DBI's C<bind_param()>.
1695 $sth->prepare($stmt);
1698 my($col, $data) = @$_;
1699 if ($col eq 'details' || $col eq 'comments') {
1700 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1701 } elsif ($col eq 'image') {
1702 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1704 $sth->bind_param($i, $data);
1708 $sth->execute; # execute without @bind now
1710 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1711 Basically, the advantage is still that you don't have to care which fields
1712 are or are not included. You could wrap that above C<for> loop in a simple
1713 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1714 get a layer of abstraction over manual SQL specification.
1716 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1717 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1718 will expect the bind values in this format.
1722 This is the character that a table or column name will be quoted
1723 with. By default this is an empty string, but you could set it to
1724 the character C<`>, to generate SQL like this:
1726 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1728 Alternatively, you can supply an array ref of two items, the first being the left
1729 hand quote character, and the second the right hand quote character. For
1730 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1731 that generates SQL like this:
1733 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1735 Quoting is useful if you have tables or columns names that are reserved
1736 words in your database's SQL dialect.
1740 This is the character that will be used to escape L</quote_char>s appearing
1741 in an identifier before it has been quoted.
1743 The parameter default in case of a single L</quote_char> character is the quote
1746 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
1747 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
1748 of the B<opening (left)> L</quote_char> within the identifier are currently left
1749 untouched. The default for opening-closing-style quotes may change in future
1750 versions, thus you are B<strongly encouraged> to specify the escape character
1755 This is the character that separates a table and column name. It is
1756 necessary to specify this when the C<quote_char> option is selected,
1757 so that tables and column names can be individually quoted like this:
1759 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1761 =item injection_guard
1763 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1764 column name specified in a query structure. This is a safety mechanism to avoid
1765 injection attacks when mishandling user input e.g.:
1767 my %condition_as_column_value_pairs = get_values_from_user();
1768 $sqla->select( ... , \%condition_as_column_value_pairs );
1770 If the expression matches an exception is thrown. Note that literal SQL
1771 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1773 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1775 =item array_datatypes
1777 When this option is true, arrayrefs in INSERT or UPDATE are
1778 interpreted as array datatypes and are passed directly
1780 When this option is false, arrayrefs are interpreted
1781 as literal SQL, just like refs to arrayrefs
1782 (but this behavior is for backwards compatibility; when writing
1783 new queries, use the "reference to arrayref" syntax
1789 Takes a reference to a list of "special operators"
1790 to extend the syntax understood by L<SQL::Abstract>.
1791 See section L</"SPECIAL OPERATORS"> for details.
1795 Takes a reference to a list of "unary operators"
1796 to extend the syntax understood by L<SQL::Abstract>.
1797 See section L</"UNARY OPERATORS"> for details.
1803 =head2 insert($table, \@values || \%fieldvals, \%options)
1805 This is the simplest function. You simply give it a table name
1806 and either an arrayref of values or hashref of field/value pairs.
1807 It returns an SQL INSERT statement and a list of bind values.
1808 See the sections on L</"Inserting and Updating Arrays"> and
1809 L</"Inserting and Updating SQL"> for information on how to insert
1810 with those data types.
1812 The optional C<\%options> hash reference may contain additional
1813 options to generate the insert SQL. Currently supported options
1820 Takes either a scalar of raw SQL fields, or an array reference of
1821 field names, and adds on an SQL C<RETURNING> statement at the end.
1822 This allows you to return data generated by the insert statement
1823 (such as row IDs) without performing another C<SELECT> statement.
1824 Note, however, this is not part of the SQL standard and may not
1825 be supported by all database engines.
1829 =head2 update($table, \%fieldvals, \%where, \%options)
1831 This takes a table, hashref of field/value pairs, and an optional
1832 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1834 See the sections on L</"Inserting and Updating Arrays"> and
1835 L</"Inserting and Updating SQL"> for information on how to insert
1836 with those data types.
1838 The optional C<\%options> hash reference may contain additional
1839 options to generate the update SQL. Currently supported options
1846 See the C<returning> option to
1847 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1851 =head2 select($source, $fields, $where, $order)
1853 This returns a SQL SELECT statement and associated list of bind values, as
1854 specified by the arguments:
1860 Specification of the 'FROM' part of the statement.
1861 The argument can be either a plain scalar (interpreted as a table
1862 name, will be quoted), or an arrayref (interpreted as a list
1863 of table names, joined by commas, quoted), or a scalarref
1864 (literal SQL, not quoted).
1868 Specification of the list of fields to retrieve from
1870 The argument can be either an arrayref (interpreted as a list
1871 of field names, will be joined by commas and quoted), or a
1872 plain scalar (literal SQL, not quoted).
1873 Please observe that this API is not as flexible as that of
1874 the first argument C<$source>, for backwards compatibility reasons.
1878 Optional argument to specify the WHERE part of the query.
1879 The argument is most often a hashref, but can also be
1880 an arrayref or plain scalar --
1881 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1885 Optional argument to specify the ORDER BY part of the query.
1886 The argument can be a scalar, a hashref or an arrayref
1887 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1893 =head2 delete($table, \%where, \%options)
1895 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1896 It returns an SQL DELETE statement and list of bind values.
1898 The optional C<\%options> hash reference may contain additional
1899 options to generate the delete SQL. Currently supported options
1906 See the C<returning> option to
1907 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1911 =head2 where(\%where, $order)
1913 This is used to generate just the WHERE clause. For example,
1914 if you have an arbitrary data structure and know what the
1915 rest of your SQL is going to look like, but want an easy way
1916 to produce a WHERE clause, use this. It returns an SQL WHERE
1917 clause and list of bind values.
1920 =head2 values(\%data)
1922 This just returns the values from the hash C<%data>, in the same
1923 order that would be returned from any of the other above queries.
1924 Using this allows you to markedly speed up your queries if you
1925 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1927 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1929 Warning: This is an experimental method and subject to change.
1931 This returns arbitrarily generated SQL. It's a really basic shortcut.
1932 It will return two different things, depending on return context:
1934 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1935 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1937 These would return the following:
1939 # First calling form
1940 $stmt = "CREATE TABLE test (?, ?)";
1941 @bind = (field1, field2);
1943 # Second calling form
1944 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1946 Depending on what you're trying to do, it's up to you to choose the correct
1947 format. In this example, the second form is what you would want.
1951 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1955 ALTER SESSION SET nls_date_format = 'MM/YY'
1957 You get the idea. Strings get their case twiddled, but everything
1958 else remains verbatim.
1960 =head1 EXPORTABLE FUNCTIONS
1962 =head2 is_plain_value
1964 Determines if the supplied argument is a plain value as understood by this
1969 =item * The value is C<undef>
1971 =item * The value is a non-reference
1973 =item * The value is an object with stringification overloading
1975 =item * The value is of the form C<< { -value => $anything } >>
1979 On failure returns C<undef>, on success returns a B<scalar> reference
1980 to the original supplied argument.
1986 The stringification overloading detection is rather advanced: it takes
1987 into consideration not only the presence of a C<""> overload, but if that
1988 fails also checks for enabled
1989 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
1990 on either C<0+> or C<bool>.
1992 Unfortunately testing in the field indicates that this
1993 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
1994 but only when very large numbers of stringifying objects are involved.
1995 At the time of writing ( Sep 2014 ) there is no clear explanation of
1996 the direct cause, nor is there a manageably small test case that reliably
1997 reproduces the problem.
1999 If you encounter any of the following exceptions in B<random places within
2000 your application stack> - this module may be to blame:
2002 Operation "ne": no method found,
2003 left argument in overloaded package <something>,
2004 right argument in overloaded package <something>
2008 Stub found while resolving method "???" overloading """" in package <something>
2010 If you fall victim to the above - please attempt to reduce the problem
2011 to something that could be sent to the L<SQL::Abstract developers
2012 |DBIx::Class/GETTING HELP/SUPPORT>
2013 (either publicly or privately). As a workaround in the meantime you can
2014 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2015 value, which will most likely eliminate your problem (at the expense of
2016 not being able to properly detect exotic forms of stringification).
2018 This notice and environment variable will be removed in a future version,
2019 as soon as the underlying problem is found and a reliable workaround is
2024 =head2 is_literal_value
2026 Determines if the supplied argument is a literal value as understood by this
2031 =item * C<\$sql_string>
2033 =item * C<\[ $sql_string, @bind_values ]>
2037 On failure returns C<undef>, on success returns an B<array> reference
2038 containing the unpacked version of the supplied literal SQL and bind values.
2040 =head1 WHERE CLAUSES
2044 This module uses a variation on the idea from L<DBIx::Abstract>. It
2045 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2046 module is that things in arrays are OR'ed, and things in hashes
2049 The easiest way to explain is to show lots of examples. After
2050 each C<%where> hash shown, it is assumed you used:
2052 my($stmt, @bind) = $sql->where(\%where);
2054 However, note that the C<%where> hash can be used directly in any
2055 of the other functions as well, as described above.
2057 =head2 Key-value pairs
2059 So, let's get started. To begin, a simple hash:
2063 status => 'completed'
2066 Is converted to SQL C<key = val> statements:
2068 $stmt = "WHERE user = ? AND status = ?";
2069 @bind = ('nwiger', 'completed');
2071 One common thing I end up doing is having a list of values that
2072 a field can be in. To do this, simply specify a list inside of
2077 status => ['assigned', 'in-progress', 'pending'];
2080 This simple code will create the following:
2082 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2083 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2085 A field associated to an empty arrayref will be considered a
2086 logical false and will generate 0=1.
2088 =head2 Tests for NULL values
2090 If the value part is C<undef> then this is converted to SQL <IS NULL>
2099 $stmt = "WHERE user = ? AND status IS NULL";
2102 To test if a column IS NOT NULL:
2106 status => { '!=', undef },
2109 =head2 Specific comparison operators
2111 If you want to specify a different type of operator for your comparison,
2112 you can use a hashref for a given column:
2116 status => { '!=', 'completed' }
2119 Which would generate:
2121 $stmt = "WHERE user = ? AND status != ?";
2122 @bind = ('nwiger', 'completed');
2124 To test against multiple values, just enclose the values in an arrayref:
2126 status => { '=', ['assigned', 'in-progress', 'pending'] };
2128 Which would give you:
2130 "WHERE status = ? OR status = ? OR status = ?"
2133 The hashref can also contain multiple pairs, in which case it is expanded
2134 into an C<AND> of its elements:
2138 status => { '!=', 'completed', -not_like => 'pending%' }
2141 # Or more dynamically, like from a form
2142 $where{user} = 'nwiger';
2143 $where{status}{'!='} = 'completed';
2144 $where{status}{'-not_like'} = 'pending%';
2146 # Both generate this
2147 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2148 @bind = ('nwiger', 'completed', 'pending%');
2151 To get an OR instead, you can combine it with the arrayref idea:
2155 priority => [ { '=', 2 }, { '>', 5 } ]
2158 Which would generate:
2160 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2161 @bind = ('2', '5', 'nwiger');
2163 If you want to include literal SQL (with or without bind values), just use a
2164 scalar reference or reference to an arrayref as the value:
2167 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2168 date_expires => { '<' => \"now()" }
2171 Which would generate:
2173 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2174 @bind = ('11/26/2008');
2177 =head2 Logic and nesting operators
2179 In the example above,
2180 there is a subtle trap if you want to say something like
2181 this (notice the C<AND>):
2183 WHERE priority != ? AND priority != ?
2185 Because, in Perl you I<can't> do this:
2187 priority => { '!=' => 2, '!=' => 1 }
2189 As the second C<!=> key will obliterate the first. The solution
2190 is to use the special C<-modifier> form inside an arrayref:
2192 priority => [ -and => {'!=', 2},
2196 Normally, these would be joined by C<OR>, but the modifier tells it
2197 to use C<AND> instead. (Hint: You can use this in conjunction with the
2198 C<logic> option to C<new()> in order to change the way your queries
2199 work by default.) B<Important:> Note that the C<-modifier> goes
2200 B<INSIDE> the arrayref, as an extra first element. This will
2201 B<NOT> do what you think it might:
2203 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2205 Here is a quick list of equivalencies, since there is some overlap:
2208 status => {'!=', 'completed', 'not like', 'pending%' }
2209 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2212 status => {'=', ['assigned', 'in-progress']}
2213 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2214 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2218 =head2 Special operators: IN, BETWEEN, etc.
2220 You can also use the hashref format to compare a list of fields using the
2221 C<IN> comparison operator, by specifying the list as an arrayref:
2224 status => 'completed',
2225 reportid => { -in => [567, 2335, 2] }
2228 Which would generate:
2230 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2231 @bind = ('completed', '567', '2335', '2');
2233 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2236 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2237 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2238 'sqltrue' (by default: C<1=1>).
2240 In addition to the array you can supply a chunk of literal sql or
2241 literal sql with bind:
2244 customer => { -in => \[
2245 'SELECT cust_id FROM cust WHERE balance > ?',
2248 status => { -in => \'SELECT status_codes FROM states' },
2254 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2255 AND status IN ( SELECT status_codes FROM states )
2259 Finally, if the argument to C<-in> is not a reference, it will be
2260 treated as a single-element array.
2262 Another pair of operators is C<-between> and C<-not_between>,
2263 used with an arrayref of two values:
2267 completion_date => {
2268 -not_between => ['2002-10-01', '2003-02-06']
2274 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2276 Just like with C<-in> all plausible combinations of literal SQL
2280 start0 => { -between => [ 1, 2 ] },
2281 start1 => { -between => \["? AND ?", 1, 2] },
2282 start2 => { -between => \"lower(x) AND upper(y)" },
2283 start3 => { -between => [
2285 \["upper(?)", 'stuff' ],
2292 ( start0 BETWEEN ? AND ? )
2293 AND ( start1 BETWEEN ? AND ? )
2294 AND ( start2 BETWEEN lower(x) AND upper(y) )
2295 AND ( start3 BETWEEN lower(x) AND upper(?) )
2297 @bind = (1, 2, 1, 2, 'stuff');
2300 These are the two builtin "special operators"; but the
2301 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2303 =head2 Unary operators: bool
2305 If you wish to test against boolean columns or functions within your
2306 database you can use the C<-bool> and C<-not_bool> operators. For
2307 example to test the column C<is_user> being true and the column
2308 C<is_enabled> being false you would use:-
2312 -not_bool => 'is_enabled',
2317 WHERE is_user AND NOT is_enabled
2319 If a more complex combination is required, testing more conditions,
2320 then you should use the and/or operators:-
2325 -not_bool => { two=> { -rlike => 'bar' } },
2326 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2337 (NOT ( three = ? OR three > ? ))
2340 =head2 Nested conditions, -and/-or prefixes
2342 So far, we've seen how multiple conditions are joined with a top-level
2343 C<AND>. We can change this by putting the different conditions we want in
2344 hashes and then putting those hashes in an array. For example:
2349 status => { -like => ['pending%', 'dispatched'] },
2353 status => 'unassigned',
2357 This data structure would create the following:
2359 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2360 OR ( user = ? AND status = ? ) )";
2361 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2364 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2365 to change the logic inside:
2371 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2372 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2379 $stmt = "WHERE ( user = ?
2380 AND ( ( workhrs > ? AND geo = ? )
2381 OR ( workhrs < ? OR geo = ? ) ) )";
2382 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2384 =head3 Algebraic inconsistency, for historical reasons
2386 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2387 operator goes C<outside> of the nested structure; whereas when connecting
2388 several constraints on one column, the C<-and> operator goes
2389 C<inside> the arrayref. Here is an example combining both features:
2392 -and => [a => 1, b => 2],
2393 -or => [c => 3, d => 4],
2394 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2399 WHERE ( ( ( a = ? AND b = ? )
2400 OR ( c = ? OR d = ? )
2401 OR ( e LIKE ? AND e LIKE ? ) ) )
2403 This difference in syntax is unfortunate but must be preserved for
2404 historical reasons. So be careful: the two examples below would
2405 seem algebraically equivalent, but they are not
2408 { -like => 'foo%' },
2409 { -like => '%bar' },
2411 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2414 { col => { -like => 'foo%' } },
2415 { col => { -like => '%bar' } },
2417 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2420 =head2 Literal SQL and value type operators
2422 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2423 side" is a column name and the "right side" is a value (normally rendered as
2424 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2425 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2426 alter this behavior. There are several ways of doing so.
2430 This is a virtual operator that signals the string to its right side is an
2431 identifier (a column name) and not a value. For example to compare two
2432 columns you would write:
2435 priority => { '<', 2 },
2436 requestor => { -ident => 'submitter' },
2441 $stmt = "WHERE priority < ? AND requestor = submitter";
2444 If you are maintaining legacy code you may see a different construct as
2445 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2450 This is a virtual operator that signals that the construct to its right side
2451 is a value to be passed to DBI. This is for example necessary when you want
2452 to write a where clause against an array (for RDBMS that support such
2453 datatypes). For example:
2456 array => { -value => [1, 2, 3] }
2461 $stmt = 'WHERE array = ?';
2462 @bind = ([1, 2, 3]);
2464 Note that if you were to simply say:
2470 the result would probably not be what you wanted:
2472 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2477 Finally, sometimes only literal SQL will do. To include a random snippet
2478 of SQL verbatim, you specify it as a scalar reference. Consider this only
2479 as a last resort. Usually there is a better way. For example:
2482 priority => { '<', 2 },
2483 requestor => { -in => \'(SELECT name FROM hitmen)' },
2488 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2491 Note that in this example, you only get one bind parameter back, since
2492 the verbatim SQL is passed as part of the statement.
2496 Never use untrusted input as a literal SQL argument - this is a massive
2497 security risk (there is no way to check literal snippets for SQL
2498 injections and other nastyness). If you need to deal with untrusted input
2499 use literal SQL with placeholders as described next.
2501 =head3 Literal SQL with placeholders and bind values (subqueries)
2503 If the literal SQL to be inserted has placeholders and bind values,
2504 use a reference to an arrayref (yes this is a double reference --
2505 not so common, but perfectly legal Perl). For example, to find a date
2506 in Postgres you can use something like this:
2509 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2514 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2517 Note that you must pass the bind values in the same format as they are returned
2518 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2519 to C<columns>, you must provide the bind values in the
2520 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2521 scalar value; most commonly the column name, but you can use any scalar value
2522 (including references and blessed references), L<SQL::Abstract> will simply
2523 pass it through intact. So if C<bindtype> is set to C<columns> the above
2524 example will look like:
2527 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2530 Literal SQL is especially useful for nesting parenthesized clauses in the
2531 main SQL query. Here is a first example:
2533 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2537 bar => \["IN ($sub_stmt)" => @sub_bind],
2542 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2543 WHERE c2 < ? AND c3 LIKE ?))";
2544 @bind = (1234, 100, "foo%");
2546 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2547 are expressed in the same way. Of course the C<$sub_stmt> and
2548 its associated bind values can be generated through a former call
2551 my ($sub_stmt, @sub_bind)
2552 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2553 c3 => {-like => "foo%"}});
2556 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2559 In the examples above, the subquery was used as an operator on a column;
2560 but the same principle also applies for a clause within the main C<%where>
2561 hash, like an EXISTS subquery:
2563 my ($sub_stmt, @sub_bind)
2564 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2565 my %where = ( -and => [
2567 \["EXISTS ($sub_stmt)" => @sub_bind],
2572 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2573 WHERE c1 = ? AND c2 > t0.c0))";
2577 Observe that the condition on C<c2> in the subquery refers to
2578 column C<t0.c0> of the main query: this is I<not> a bind
2579 value, so we have to express it through a scalar ref.
2580 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2581 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2582 what we wanted here.
2584 Finally, here is an example where a subquery is used
2585 for expressing unary negation:
2587 my ($sub_stmt, @sub_bind)
2588 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2589 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2591 lname => {like => '%son%'},
2592 \["NOT ($sub_stmt)" => @sub_bind],
2597 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2598 @bind = ('%son%', 10, 20)
2600 =head3 Deprecated usage of Literal SQL
2602 Below are some examples of archaic use of literal SQL. It is shown only as
2603 reference for those who deal with legacy code. Each example has a much
2604 better, cleaner and safer alternative that users should opt for in new code.
2610 my %where = ( requestor => \'IS NOT NULL' )
2612 $stmt = "WHERE requestor IS NOT NULL"
2614 This used to be the way of generating NULL comparisons, before the handling
2615 of C<undef> got formalized. For new code please use the superior syntax as
2616 described in L</Tests for NULL values>.
2620 my %where = ( requestor => \'= submitter' )
2622 $stmt = "WHERE requestor = submitter"
2624 This used to be the only way to compare columns. Use the superior L</-ident>
2625 method for all new code. For example an identifier declared in such a way
2626 will be properly quoted if L</quote_char> is properly set, while the legacy
2627 form will remain as supplied.
2631 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2633 $stmt = "WHERE completed > ? AND is_ready"
2634 @bind = ('2012-12-21')
2636 Using an empty string literal used to be the only way to express a boolean.
2637 For all new code please use the much more readable
2638 L<-bool|/Unary operators: bool> operator.
2644 These pages could go on for a while, since the nesting of the data
2645 structures this module can handle are pretty much unlimited (the
2646 module implements the C<WHERE> expansion as a recursive function
2647 internally). Your best bet is to "play around" with the module a
2648 little to see how the data structures behave, and choose the best
2649 format for your data based on that.
2651 And of course, all the values above will probably be replaced with
2652 variables gotten from forms or the command line. After all, if you
2653 knew everything ahead of time, you wouldn't have to worry about
2654 dynamically-generating SQL and could just hardwire it into your
2657 =head1 ORDER BY CLAUSES
2659 Some functions take an order by clause. This can either be a scalar (just a
2660 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2661 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2664 Given | Will Generate
2665 ---------------------------------------------------------------
2667 'colA' | ORDER BY colA
2669 [qw/colA colB/] | ORDER BY colA, colB
2671 {-asc => 'colA'} | ORDER BY colA ASC
2673 {-desc => 'colB'} | ORDER BY colB DESC
2675 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2677 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2679 \'colA DESC' | ORDER BY colA DESC
2681 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2682 | /* ...with $x bound to ? */
2685 { -asc => 'colA' }, | colA ASC,
2686 { -desc => [qw/colB/] }, | colB DESC,
2687 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2688 \'colE DESC', | colE DESC,
2689 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2690 ] | /* ...with $x bound to ? */
2691 ===============================================================
2695 =head1 SPECIAL OPERATORS
2697 my $sqlmaker = SQL::Abstract->new(special_ops => [
2701 my ($self, $field, $op, $arg) = @_;
2707 handler => 'method_name',
2711 A "special operator" is a SQL syntactic clause that can be
2712 applied to a field, instead of a usual binary operator.
2715 WHERE field IN (?, ?, ?)
2716 WHERE field BETWEEN ? AND ?
2717 WHERE MATCH(field) AGAINST (?, ?)
2719 Special operators IN and BETWEEN are fairly standard and therefore
2720 are builtin within C<SQL::Abstract> (as the overridable methods
2721 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2722 like the MATCH .. AGAINST example above which is specific to MySQL,
2723 you can write your own operator handlers - supply a C<special_ops>
2724 argument to the C<new> method. That argument takes an arrayref of
2725 operator definitions; each operator definition is a hashref with two
2732 the regular expression to match the operator
2736 Either a coderef or a plain scalar method name. In both cases
2737 the expected return is C<< ($sql, @bind) >>.
2739 When supplied with a method name, it is simply called on the
2740 L<SQL::Abstract> object as:
2742 $self->$method_name($field, $op, $arg)
2746 $field is the LHS of the operator
2747 $op is the part that matched the handler regex
2750 When supplied with a coderef, it is called as:
2752 $coderef->($self, $field, $op, $arg)
2757 For example, here is an implementation
2758 of the MATCH .. AGAINST syntax for MySQL
2760 my $sqlmaker = SQL::Abstract->new(special_ops => [
2762 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2763 {regex => qr/^match$/i,
2765 my ($self, $field, $op, $arg) = @_;
2766 $arg = [$arg] if not ref $arg;
2767 my $label = $self->_quote($field);
2768 my ($placeholder) = $self->_convert('?');
2769 my $placeholders = join ", ", (($placeholder) x @$arg);
2770 my $sql = $self->_sqlcase('match') . " ($label) "
2771 . $self->_sqlcase('against') . " ($placeholders) ";
2772 my @bind = $self->_bindtype($field, @$arg);
2773 return ($sql, @bind);
2780 =head1 UNARY OPERATORS
2782 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2786 my ($self, $op, $arg) = @_;
2792 handler => 'method_name',
2796 A "unary operator" is a SQL syntactic clause that can be
2797 applied to a field - the operator goes before the field
2799 You can write your own operator handlers - supply a C<unary_ops>
2800 argument to the C<new> method. That argument takes an arrayref of
2801 operator definitions; each operator definition is a hashref with two
2808 the regular expression to match the operator
2812 Either a coderef or a plain scalar method name. In both cases
2813 the expected return is C<< $sql >>.
2815 When supplied with a method name, it is simply called on the
2816 L<SQL::Abstract> object as:
2818 $self->$method_name($op, $arg)
2822 $op is the part that matched the handler regex
2823 $arg is the RHS or argument of the operator
2825 When supplied with a coderef, it is called as:
2827 $coderef->($self, $op, $arg)
2835 Thanks to some benchmarking by Mark Stosberg, it turns out that
2836 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2837 I must admit this wasn't an intentional design issue, but it's a
2838 byproduct of the fact that you get to control your C<DBI> handles
2841 To maximize performance, use a code snippet like the following:
2843 # prepare a statement handle using the first row
2844 # and then reuse it for the rest of the rows
2846 for my $href (@array_of_hashrefs) {
2847 $stmt ||= $sql->insert('table', $href);
2848 $sth ||= $dbh->prepare($stmt);
2849 $sth->execute($sql->values($href));
2852 The reason this works is because the keys in your C<$href> are sorted
2853 internally by B<SQL::Abstract>. Thus, as long as your data retains
2854 the same structure, you only have to generate the SQL the first time
2855 around. On subsequent queries, simply use the C<values> function provided
2856 by this module to return your values in the correct order.
2858 However this depends on the values having the same type - if, for
2859 example, the values of a where clause may either have values
2860 (resulting in sql of the form C<column = ?> with a single bind
2861 value), or alternatively the values might be C<undef> (resulting in
2862 sql of the form C<column IS NULL> with no bind value) then the
2863 caching technique suggested will not work.
2867 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2868 really like this part (I do, at least). Building up a complex query
2869 can be as simple as the following:
2876 use CGI::FormBuilder;
2879 my $form = CGI::FormBuilder->new(...);
2880 my $sql = SQL::Abstract->new;
2882 if ($form->submitted) {
2883 my $field = $form->field;
2884 my $id = delete $field->{id};
2885 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2888 Of course, you would still have to connect using C<DBI> to run the
2889 query, but the point is that if you make your form look like your
2890 table, the actual query script can be extremely simplistic.
2892 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2893 a fast interface to returning and formatting data. I frequently
2894 use these three modules together to write complex database query
2895 apps in under 50 lines.
2897 =head1 HOW TO CONTRIBUTE
2899 Contributions are always welcome, in all usable forms (we especially
2900 welcome documentation improvements). The delivery methods include git-
2901 or unified-diff formatted patches, GitHub pull requests, or plain bug
2902 reports either via RT or the Mailing list. Contributors are generally
2903 granted full access to the official repository after their first several
2904 patches pass successful review.
2906 This project is maintained in a git repository. The code and related tools are
2907 accessible at the following locations:
2911 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
2913 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
2915 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
2917 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
2923 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2924 Great care has been taken to preserve the I<published> behavior
2925 documented in previous versions in the 1.* family; however,
2926 some features that were previously undocumented, or behaved
2927 differently from the documentation, had to be changed in order
2928 to clarify the semantics. Hence, client code that was relying
2929 on some dark areas of C<SQL::Abstract> v1.*
2930 B<might behave differently> in v1.50.
2932 The main changes are:
2938 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
2942 support for the { operator => \"..." } construct (to embed literal SQL)
2946 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2950 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2954 defensive programming: check arguments
2958 fixed bug with global logic, which was previously implemented
2959 through global variables yielding side-effects. Prior versions would
2960 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2961 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2962 Now this is interpreted
2963 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2968 fixed semantics of _bindtype on array args
2972 dropped the C<_anoncopy> of the %where tree. No longer necessary,
2973 we just avoid shifting arrays within that tree.
2977 dropped the C<_modlogic> function
2981 =head1 ACKNOWLEDGEMENTS
2983 There are a number of individuals that have really helped out with
2984 this module. Unfortunately, most of them submitted bugs via CPAN
2985 so I have no idea who they are! But the people I do know are:
2987 Ash Berlin (order_by hash term support)
2988 Matt Trout (DBIx::Class support)
2989 Mark Stosberg (benchmarking)
2990 Chas Owens (initial "IN" operator support)
2991 Philip Collins (per-field SQL functions)
2992 Eric Kolve (hashref "AND" support)
2993 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2994 Dan Kubb (support for "quote_char" and "name_sep")
2995 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
2996 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
2997 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
2998 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
2999 Oliver Charles (support for "RETURNING" after "INSERT")
3005 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
3009 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3011 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3013 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3014 While not an official support venue, C<DBIx::Class> makes heavy use of
3015 C<SQL::Abstract>, and as such list members there are very familiar with
3016 how to create queries.
3020 This module is free software; you may copy this under the same
3021 terms as perl itself (either the GNU General Public License or
3022 the Artistic License)