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{special_ops} ||= [];
160 # regexes are applied in order, thus push after user-defines
161 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
164 $opt{unary_ops} ||= [];
166 # rudimentary sanity-check for user supplied bits treated as functions/operators
167 # If a purported function matches this regular expression, an exception is thrown.
168 # Literal SQL is *NOT* subject to this check, only functions (and column names
169 # when quoting is not in effect)
172 # need to guard against ()'s in column names too, but this will break tons of
173 # hacks... ideas anyone?
174 $opt{injection_guard} ||= qr/
180 $opt{node_types} = +{
181 map +("-$_" => '_render_'.$_),
182 qw(op func value bind ident literal)
185 $opt{expand_unary} = {};
187 return bless \%opt, $class;
190 sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
191 sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
193 sub _assert_pass_injection_guard {
194 if ($_[1] =~ $_[0]->{injection_guard}) {
195 my $class = ref $_[0];
196 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
197 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
198 . "{injection_guard} attribute to ${class}->new()"
203 #======================================================================
205 #======================================================================
209 my $table = $self->_table(shift);
210 my $data = shift || return;
213 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
214 my ($sql, @bind) = $self->$method($data);
215 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
217 if ($options->{returning}) {
218 my ($s, @b) = $self->_insert_returning($options);
223 return wantarray ? ($sql, @bind) : $sql;
226 # So that subclasses can override INSERT ... RETURNING separately from
227 # UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
228 sub _insert_returning { shift->_returning(@_) }
231 my ($self, $options) = @_;
233 my $f = $options->{returning};
235 my ($sql, @bind) = $self->_render_expr(
236 $self->_expand_maybe_list_expr($f, undef, -ident)
239 ? $self->_sqlcase(' returning ') . $sql
240 : ($self->_sqlcase(' returning ').$sql, @bind);
243 sub _insert_HASHREF { # explicit list of fields and then values
244 my ($self, $data) = @_;
246 my @fields = sort keys %$data;
248 my ($sql, @bind) = $self->_insert_values($data);
251 $_ = $self->_quote($_) foreach @fields;
252 $sql = "( ".join(", ", @fields).") ".$sql;
254 return ($sql, @bind);
257 sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
258 my ($self, $data) = @_;
260 # no names (arrayref) so can't generate bindtype
261 $self->{bindtype} ne 'columns'
262 or belch "can't do 'columns' bindtype when called with arrayref";
264 my (@values, @all_bind);
265 foreach my $value (@$data) {
266 my ($values, @bind) = $self->_insert_value(undef, $value);
267 push @values, $values;
268 push @all_bind, @bind;
270 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
271 return ($sql, @all_bind);
274 sub _insert_ARRAYREFREF { # literal SQL with bind
275 my ($self, $data) = @_;
277 my ($sql, @bind) = @${$data};
278 $self->_assert_bindval_matches_bindtype(@bind);
280 return ($sql, @bind);
284 sub _insert_SCALARREF { # literal SQL without bind
285 my ($self, $data) = @_;
291 my ($self, $data) = @_;
293 my (@values, @all_bind);
294 foreach my $column (sort keys %$data) {
295 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
296 push @values, $values;
297 push @all_bind, @bind;
299 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
300 return ($sql, @all_bind);
304 my ($self, $column, $v) = @_;
306 return $self->_render_expr(
307 $self->_expand_insert_value($column, $v)
311 sub _expand_insert_value {
312 my ($self, $column, $v) = @_;
314 if (ref($v) eq 'ARRAY') {
315 if ($self->{array_datatypes}) {
316 return +{ -bind => [ $column, $v ] };
318 my ($sql, @bind) = @$v;
319 $self->_assert_bindval_matches_bindtype(@bind);
320 return +{ -literal => $v };
322 if (ref($v) eq 'HASH') {
323 if (grep !/^-/, keys %$v) {
324 belch "HASH ref as bind value in insert is not supported";
325 return +{ -bind => [ $column, $v ] };
329 return +{ -bind => [ $column, undef ] };
331 local our $Cur_Col_Meta = $column;
332 return $self->_expand_expr($v);
337 #======================================================================
339 #======================================================================
344 my $table = $self->_table(shift);
345 my $data = shift || return;
349 # first build the 'SET' part of the sql statement
350 puke "Unsupported data type specified to \$sql->update"
351 unless ref $data eq 'HASH';
353 my ($sql, @all_bind) = $self->_update_set_values($data);
354 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
358 my($where_sql, @where_bind) = $self->where($where);
360 push @all_bind, @where_bind;
363 if ($options->{returning}) {
364 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
365 $sql .= $returning_sql;
366 push @all_bind, @returning_bind;
369 return wantarray ? ($sql, @all_bind) : $sql;
372 sub _update_set_values {
373 my ($self, $data) = @_;
375 return $self->_render_expr(
376 $self->_expand_update_set_values($data),
380 sub _expand_update_set_values {
381 my ($self, $data) = @_;
382 $self->_expand_maybe_list_expr( [
385 $set = { -bind => $_ } unless defined $set;
386 +{ -op => [ '=', { -ident => $k }, $set ] };
392 ? ($self->{array_datatypes}
393 ? [ $k, +{ -bind => [ $k, $v ] } ]
394 : [ $k, +{ -literal => $v } ])
396 local our $Cur_Col_Meta = $k;
397 [ $k, $self->_expand_expr($v) ]
404 # So that subclasses can override UPDATE ... RETURNING separately from
406 sub _update_returning { shift->_returning(@_) }
410 #======================================================================
412 #======================================================================
417 my $table = $self->_table(shift);
418 my $fields = shift || '*';
422 my ($fields_sql, @bind) = $self->_select_fields($fields);
424 my ($where_sql, @where_bind) = $self->where($where, $order);
425 push @bind, @where_bind;
427 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
428 $self->_sqlcase('from'), $table)
431 return wantarray ? ($sql, @bind) : $sql;
435 my ($self, $fields) = @_;
436 return $fields unless ref($fields);
437 return $self->_render_expr(
438 $self->_expand_maybe_list_expr($fields, undef, '-ident')
442 #======================================================================
444 #======================================================================
449 my $table = $self->_table(shift);
453 my($where_sql, @bind) = $self->where($where);
454 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
456 if ($options->{returning}) {
457 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
458 $sql .= $returning_sql;
459 push @bind, @returning_bind;
462 return wantarray ? ($sql, @bind) : $sql;
465 # So that subclasses can override DELETE ... RETURNING separately from
467 sub _delete_returning { shift->_returning(@_) }
471 #======================================================================
473 #======================================================================
477 # Finally, a separate routine just to handle WHERE clauses
479 my ($self, $where, $order) = @_;
481 local $self->{convert_where} = $self->{convert};
484 my ($sql, @bind) = defined($where)
485 ? $self->_recurse_where($where)
487 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
491 my ($order_sql, @order_bind) = $self->_order_by($order);
493 push @bind, @order_bind;
496 return wantarray ? ($sql, @bind) : $sql;
500 my ($self, $expr, $logic, $default_scalar_to) = @_;
501 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
502 return undef unless defined($expr);
503 if (ref($expr) eq 'HASH') {
504 if (keys %$expr > 1) {
508 map $self->_expand_expr_hashpair($_ => $expr->{$_}, $logic),
512 return unless %$expr;
513 return $self->_expand_expr_hashpair(%$expr, $logic);
515 if (ref($expr) eq 'ARRAY') {
516 my $logic = lc($logic || $self->{logic});
517 $logic eq 'and' or $logic eq 'or' or puke "unknown logic: $logic";
523 while (my ($el) = splice @expr, 0, 1) {
524 puke "Supplying an empty left hand side argument is not supported in array-pairs"
525 unless defined($el) and length($el);
526 my $elref = ref($el);
528 push(@res, $self->_expand_expr({ $el, shift(@expr) }));
529 } elsif ($elref eq 'ARRAY') {
530 push(@res, $self->_expand_expr($el)) if @$el;
531 } elsif (my $l = is_literal_value($el)) {
532 push @res, { -literal => $l };
533 } elsif ($elref eq 'HASH') {
534 push @res, $self->_expand_expr($el);
539 return { -op => [ $logic, @res ] };
541 if (my $literal = is_literal_value($expr)) {
542 return +{ -literal => $literal };
544 if (!ref($expr) or Scalar::Util::blessed($expr)) {
545 if (my $d = $Default_Scalar_To) {
546 return +{ $d => $expr };
548 if (my $m = our $Cur_Col_Meta) {
549 return +{ -bind => [ $m, $expr ] };
551 return +{ -value => $expr };
558 sub _expand_expr_hashpair {
559 my ($self, $k, $v, $logic) = @_;
560 unless (defined($k) and length($k)) {
561 if (defined($k) and my $literal = is_literal_value($v)) {
562 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
563 return { -literal => $literal };
565 puke "Supplying an empty left hand side argument is not supported";
568 $self->_assert_pass_injection_guard($k =~ /^-(.*)$/s);
569 if ($k =~ s/ [_\s]? \d+ $//x ) {
570 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
571 . "You probably wanted ...-and => [ $k => COND1, $k => COND2 ... ]";
574 # DBIx::Class requires a nest warning to be emitted once but the private
575 # method it overrode to do so no longer exists
576 if (ref($self) =~ /^DBIx::Class::SQLMaker/) {
577 unless ($Nest_Warned) {
579 "-nest in search conditions is deprecated, you most probably wanted:\n"
580 .q|{..., -and => [ \%cond0, \@cond1, \'cond2', \[ 'cond3', [ col => bind ] ], etc. ], ... }|
585 return $self->_expand_expr($v);
589 return $self->_expand_expr($v);
591 puke "-bool => undef not supported" unless defined($v);
592 return { -ident => $v };
595 return { -op => [ 'not', $self->_expand_expr($v) ] };
597 if (my ($rest) = $k =~/^-not[_ ](.*)$/) {
600 $self->_expand_expr_hashpair("-${rest}", $v, $logic)
603 if (my ($logic) = $k =~ /^-(and|or)$/i) {
604 if (ref($v) eq 'HASH') {
605 return $self->_expand_expr($v, $logic);
607 if (ref($v) eq 'ARRAY') {
608 return $self->_expand_expr($v, $logic);
613 $op =~ s/^-// if length($op) > 1;
615 # top level special ops are illegal in general
616 puke "Illegal use of top-level '-$op'"
617 if List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
618 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
619 return { -op => [ $op, $v ] };
622 if ($k eq '-value' and my $m = our $Cur_Col_Meta) {
623 return +{ -bind => [ $m, $v ] };
625 if (my $custom = $self->{expand_unary}{$k}) {
626 return $self->$custom($v);
628 if ($self->{node_types}{$k}) {
634 and (keys %$v)[0] =~ /^-/
636 my ($func) = $k =~ /^-(.*)$/;
637 return +{ -func => [ $func, $self->_expand_expr($v) ] };
639 if (!ref($v) or is_literal_value($v)) {
640 return +{ -op => [ $k =~ /^-(.*)$/, $self->_expand_expr($v) ] };
647 and exists $v->{-value}
648 and not defined $v->{-value}
651 return $self->_expand_expr_hashpair($k => { $self->{cmp} => undef });
653 if (!ref($v) or Scalar::Util::blessed($v)) {
654 my $d = our $Default_Scalar_To;
659 ($d ? { $d => $v } : { -bind => [ $k, $v ] })
663 if (ref($v) eq 'HASH') {
667 map $self->_expand_expr_hashpair($k => { $_ => $v->{$_} }),
674 $self->_assert_pass_injection_guard($vk);
675 if ($vk =~ s/ [_\s]? \d+ $//x ) {
676 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
677 . "You probably wanted ...-and => [ -$vk => COND1, -$vk => COND2 ... ]";
679 if ($vk =~ /^(?:not[ _])?between$/) {
680 local our $Cur_Col_Meta = $k;
681 my @rhs = map $self->_expand_expr($_),
682 ref($vv) eq 'ARRAY' ? @$vv : $vv;
684 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
686 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
688 puke "Operator '${\uc($vk)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
691 join(' ', split '_', $vk),
696 if ($vk =~ /^(?:not[ _])?in$/) {
697 if (my $literal = is_literal_value($vv)) {
698 my ($sql, @bind) = @$literal;
699 my $opened_sql = $self->_open_outer_paren($sql);
701 $vk, { -ident => $k },
702 [ { -literal => [ $opened_sql, @bind ] } ]
706 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
707 . "-${\uc($vk)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
708 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
709 . 'will emit the logically correct SQL instead of raising this exception)'
711 puke("Argument passed to the '${\uc($vk)}' operator can not be undefined")
713 my @rhs = map $self->_expand_expr($_),
714 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
715 map { defined($_) ? $_: puke($undef_err) }
716 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
717 return $self->${\($vk =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
720 join(' ', split '_', $vk),
725 if ($vk eq 'ident') {
726 if (! defined $vv or (ref($vv) and ref($vv) eq 'ARRAY')) {
727 puke "-$vk requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
735 if ($vk eq 'value') {
736 return $self->_expand_expr_hashpair($k, undef) unless defined($vv);
740 { -bind => [ $k, $vv ] }
743 if ($vk =~ /^is(?:[ _]not)?$/) {
744 puke "$vk can only take undef as argument"
748 and exists($vv->{-value})
749 and !defined($vv->{-value})
752 return +{ -op => [ $vk.' null', { -ident => $k } ] };
754 if ($vk =~ /^(and|or)$/) {
755 if (ref($vv) eq 'HASH') {
758 map $self->_expand_expr_hashpair($k, { $_ => $vv->{$_} }),
763 if (my $us = List::Util::first { $vk =~ $_->{regex} } @{$self->{special_ops}}) {
764 return { -op => [ $vk, { -ident => $k }, $vv ] };
766 if (my $us = List::Util::first { $vk =~ $_->{regex} } @{$self->{unary_ops}}) {
770 { -op => [ $vk, $vv ] }
773 if (ref($vv) eq 'ARRAY') {
774 my ($logic, @values) = (
775 (defined($vv->[0]) and $vv->[0] =~ /^-(and|or)$/i)
780 $vk =~ $self->{inequality_op}
781 or join(' ', split '_', $vk) =~ $self->{not_like_op}
783 if (lc($logic) eq '-or' and @values > 1) {
784 my $op = uc join ' ', split '_', $vk;
785 belch "A multi-element arrayref as an argument to the inequality op '$op' "
786 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
787 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
792 # try to DWIM on equality operators
793 my $op = join ' ', split '_', $vk;
795 $op =~ $self->{equality_op} ? $self->sqlfalse
796 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
797 : $op =~ $self->{inequality_op} ? $self->sqltrue
798 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
799 : puke "operator '$op' applied on an empty array (field '$k')";
803 map $self->_expand_expr_hashpair($k => { $vk => $_ }),
811 and exists $vv->{-value}
812 and not defined $vv->{-value}
815 my $op = join ' ', split '_', $vk;
817 $op =~ /^not$/i ? 'is not' # legacy
818 : $op =~ $self->{equality_op} ? 'is'
819 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
820 : $op =~ $self->{inequality_op} ? 'is not'
821 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
822 : puke "unexpected operator '$op' with undef operand";
823 return +{ -op => [ $is.' null', { -ident => $k } ] };
825 local our $Cur_Col_Meta = $k;
829 $self->_expand_expr($vv)
832 if (ref($v) eq 'ARRAY') {
833 return $self->sqlfalse unless @$v;
834 $self->_debug("ARRAY($k) means distribute over elements");
836 $v->[0] =~ /^-((?:and|or))$/i
837 ? ($v = [ @{$v}[1..$#$v] ], $1)
838 : ($self->{logic} || 'or')
842 map $self->_expand_expr({ $k => $_ }, $this_logic), @$v
845 if (my $literal = is_literal_value($v)) {
847 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
850 my ($sql, @bind) = @$literal;
851 if ($self->{bindtype} eq 'columns') {
853 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
854 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
858 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
864 my ($self, $expr) = @_;
865 my ($k, $v, @rest) = %$expr;
867 if (my $meth = $self->{node_types}{$k}) {
868 return $self->$meth($v);
870 die "notreached: $k";
874 my ($self, $where, $logic) = @_;
876 #print STDERR Data::Dumper::Concise::Dumper([ $where, $logic ]);
878 # Special case: top level simple string treated as literal
880 my $where_exp = (ref($where)
881 ? $self->_expand_expr($where, $logic)
882 : { -literal => [ $where ] });
884 #print STDERR Data::Dumper::Concise::Dumper([ EXP => $where_exp ]);
886 # dispatch on appropriate method according to refkind of $where
887 # my $method = $self->_METHOD_FOR_refkind("_where", $where_exp);
889 # my ($sql, @bind) = $self->$method($where_exp, $logic);
891 my ($sql, @bind) = defined($where_exp) ? $self->_render_expr($where_exp) : (undef);
893 # DBIx::Class used to call _recurse_where in scalar context
894 # something else might too...
896 return ($sql, @bind);
899 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
905 my ($self, $ident) = @_;
907 return $self->_convert($self->_quote($ident));
911 my ($self, $value) = @_;
913 return ($self->_convert('?'), $self->_bindtype(undef, $value));
916 my %unop_postfix = map +($_ => 1),
917 'is null', 'is not null',
925 my ($self, $args) = @_;
926 my ($left, $low, $high) = @$args;
927 my ($rhsql, @rhbind) = do {
929 puke "Single arg to between must be a literal"
930 unless $low->{-literal};
933 my ($l, $h) = map [ $self->_render_expr($_) ], $low, $high;
934 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
935 @{$l}[1..$#$l], @{$h}[1..$#$h])
938 my ($lhsql, @lhbind) = $self->_render_expr($left);
940 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
944 }), 'between', 'not between'),
948 my ($self, $args) = @_;
949 my ($lhs, $rhs) = @$args;
952 my ($sql, @bind) = $self->_render_expr($_);
953 push @in_bind, @bind;
956 my ($lhsql, @lbind) = $self->_render_expr($lhs);
958 $lhsql.' '.$self->_sqlcase($op).' ( '
969 my ($op, @args) = @$v;
970 $op =~ s/^-// if length($op) > 1;
972 if (my $h = $special{$op}) {
973 return $self->$h(\@args);
975 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
976 puke "Special op '${op}' requires first value to be identifier"
977 unless my ($k) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
978 return $self->${\($us->{handler})}($k, $op, $args[1]);
980 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
981 return $self->${\($us->{handler})}($op, $args[0]);
983 my $final_op = $op =~ /^(?:is|not)_/ ? join(' ', split '_', $op) : $op;
984 if (@args == 1 and $op !~ /^(and|or)$/) {
985 my ($expr_sql, @bind) = $self->_render_expr($args[0]);
986 my $op_sql = $self->_sqlcase($final_op);
988 $unop_postfix{lc($final_op)}
989 ? "${expr_sql} ${op_sql}"
990 : "${op_sql} ${expr_sql}"
992 return (($op eq 'not' ? '('.$final_sql.')' : $final_sql), @bind);
994 my @parts = map [ $self->_render_expr($_) ], @args;
995 my ($final_sql) = map +($op =~ /^(and|or)$/ ? "( ${_} )" : $_), join(
996 ($final_op eq ',' ? '' : ' ').$self->_sqlcase($final_op).' ',
1001 map @{$_}[1..$#$_], @parts
1008 my ($self, $rest) = @_;
1009 my ($func, @args) = @$rest;
1013 push @arg_sql, shift @x;
1015 } map [ $self->_render_expr($_) ], @args;
1016 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1020 my ($self, $bind) = @_;
1021 return ($self->_convert('?'), $self->_bindtype(@$bind));
1024 sub _render_literal {
1025 my ($self, $literal) = @_;
1026 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
1030 # Some databases (SQLite) treat col IN (1, 2) different from
1031 # col IN ( (1, 2) ). Use this to strip all outer parens while
1032 # adding them back in the corresponding method
1033 sub _open_outer_paren {
1034 my ($self, $sql) = @_;
1036 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
1038 # there are closing parens inside, need the heavy duty machinery
1039 # to reevaluate the extraction starting from $sql (full reevaluation)
1040 if ($inner =~ /\)/) {
1041 require Text::Balanced;
1043 my (undef, $remainder) = do {
1044 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1046 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
1049 # the entire expression needs to be a balanced bracketed thing
1050 # (after an extract no remainder sans trailing space)
1051 last if defined $remainder and $remainder =~ /\S/;
1061 #======================================================================
1063 #======================================================================
1065 sub _expand_order_by {
1066 my ($self, $arg) = @_;
1068 return unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
1070 my $expander = sub {
1071 my ($self, $dir, $expr) = @_;
1072 my @to_expand = ref($expr) eq 'ARRAY' ? @$expr : $expr;
1073 foreach my $arg (@to_expand) {
1077 and grep /^-(asc|desc)$/, keys %$arg
1079 puke "ordering direction hash passed to order by must have exactly one key (-asc or -desc)";
1082 my @exp = map +(defined($dir) ? { -op => [ $dir => $_ ] } : $_),
1083 map $self->_expand_expr($_, undef, -ident),
1084 map ref($_) eq 'ARRAY' ? @$_ : $_, @to_expand;
1085 return (@exp > 1 ? { -op => [ ',', @exp ] } : $exp[0]);
1088 local @{$self->{expand_unary}}{qw(-asc -desc)} = (
1089 sub { shift->$expander(asc => @_) },
1090 sub { shift->$expander(desc => @_) },
1093 return $self->$expander(undef, $arg);
1097 my ($self, $arg) = @_;
1099 return '' unless defined(my $expanded = $self->_expand_order_by($arg));
1101 my ($sql, @bind) = $self->_render_expr($expanded);
1103 my $final_sql = $self->_sqlcase(' order by ').$sql;
1105 return wantarray ? ($final_sql, @bind) : $final_sql;
1108 # _order_by no longer needs to call this so doesn't but DBIC uses it.
1110 sub _order_by_chunks {
1111 my ($self, $arg) = @_;
1113 return () unless defined(my $expanded = $self->_expand_order_by($arg));
1115 return $self->_chunkify_order_by($expanded);
1118 sub _chunkify_order_by {
1119 my ($self, $expanded) = @_;
1121 if (ref() eq 'HASH' and my $op = $_->{-op}) {
1122 if ($op->[0] eq ',') {
1123 return map $self->_chunkify_order_by($_), @{$op}[1..$#$op];
1126 return [ $self->_render_expr($_) ];
1130 #======================================================================
1131 # DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1132 #======================================================================
1137 ($self->_render_expr(
1138 $self->_expand_maybe_list_expr($from, undef, -ident)
1143 #======================================================================
1145 #======================================================================
1147 sub _expand_maybe_list_expr {
1148 my ($self, $expr, $logic, $default) = @_;
1150 if (ref($expr) eq 'ARRAY') {
1152 ',', map $self->_expand_expr($_, $logic, $default), @$expr
1159 return $self->_expand_expr($e, $logic, $default);
1162 # highly optimized, as it's called way too often
1164 # my ($self, $label) = @_;
1166 return '' unless defined $_[1];
1167 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
1168 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
1170 unless ($_[0]->{quote_char}) {
1171 if (ref($_[1]) eq 'ARRAY') {
1172 return join($_[0]->{name_sep}||'.', @{$_[1]});
1174 $_[0]->_assert_pass_injection_guard($_[1]);
1179 my $qref = ref $_[0]->{quote_char};
1181 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1182 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1183 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1185 my $esc = $_[0]->{escape_char} || $r;
1187 # parts containing * are naturally unquoted
1189 $_[0]->{name_sep}||'',
1193 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1195 (ref($_[1]) eq 'ARRAY'
1199 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1207 # Conversion, if applicable
1209 #my ($self, $arg) = @_;
1210 if ($_[0]->{convert_where}) {
1211 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
1218 #my ($self, $col, @vals) = @_;
1219 # called often - tighten code
1220 return $_[0]->{bindtype} eq 'columns'
1221 ? map {[$_[1], $_]} @_[2 .. $#_]
1226 # Dies if any element of @bind is not in [colname => value] format
1227 # if bindtype is 'columns'.
1228 sub _assert_bindval_matches_bindtype {
1229 # my ($self, @bind) = @_;
1231 if ($self->{bindtype} eq 'columns') {
1233 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
1234 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
1240 sub _join_sql_clauses {
1241 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1243 if (@$clauses_aref > 1) {
1244 my $join = " " . $self->_sqlcase($logic) . " ";
1245 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1246 return ($sql, @$bind_aref);
1248 elsif (@$clauses_aref) {
1249 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1252 return (); # if no SQL, ignore @$bind_aref
1257 # Fix SQL case, if so requested
1259 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1260 # don't touch the argument ... crooked logic, but let's not change it!
1261 return $_[0]->{case} ? $_[1] : uc($_[1]);
1265 #======================================================================
1266 # DISPATCHING FROM REFKIND
1267 #======================================================================
1270 my ($self, $data) = @_;
1272 return 'UNDEF' unless defined $data;
1274 # blessed objects are treated like scalars
1275 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1277 return 'SCALAR' unless $ref;
1280 while ($ref eq 'REF') {
1282 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1286 return ($ref||'SCALAR') . ('REF' x $n_steps);
1290 my ($self, $data) = @_;
1291 my @try = ($self->_refkind($data));
1292 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1293 push @try, 'FALLBACK';
1297 sub _METHOD_FOR_refkind {
1298 my ($self, $meth_prefix, $data) = @_;
1301 for (@{$self->_try_refkind($data)}) {
1302 $method = $self->can($meth_prefix."_".$_)
1306 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
1310 sub _SWITCH_refkind {
1311 my ($self, $data, $dispatch_table) = @_;
1314 for (@{$self->_try_refkind($data)}) {
1315 $coderef = $dispatch_table->{$_}
1319 puke "no dispatch entry for ".$self->_refkind($data)
1328 #======================================================================
1329 # VALUES, GENERATE, AUTOLOAD
1330 #======================================================================
1332 # LDNOTE: original code from nwiger, didn't touch code in that section
1333 # I feel the AUTOLOAD stuff should not be the default, it should
1334 # only be activated on explicit demand by user.
1338 my $data = shift || return;
1339 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1340 unless ref $data eq 'HASH';
1343 foreach my $k (sort keys %$data) {
1344 my $v = $data->{$k};
1345 $self->_SWITCH_refkind($v, {
1347 if ($self->{array_datatypes}) { # array datatype
1348 push @all_bind, $self->_bindtype($k, $v);
1350 else { # literal SQL with bind
1351 my ($sql, @bind) = @$v;
1352 $self->_assert_bindval_matches_bindtype(@bind);
1353 push @all_bind, @bind;
1356 ARRAYREFREF => sub { # literal SQL with bind
1357 my ($sql, @bind) = @${$v};
1358 $self->_assert_bindval_matches_bindtype(@bind);
1359 push @all_bind, @bind;
1361 SCALARREF => sub { # literal SQL without bind
1363 SCALAR_or_UNDEF => sub {
1364 push @all_bind, $self->_bindtype($k, $v);
1375 my(@sql, @sqlq, @sqlv);
1379 if ($ref eq 'HASH') {
1380 for my $k (sort keys %$_) {
1383 my $label = $self->_quote($k);
1384 if ($r eq 'ARRAY') {
1385 # literal SQL with bind
1386 my ($sql, @bind) = @$v;
1387 $self->_assert_bindval_matches_bindtype(@bind);
1388 push @sqlq, "$label = $sql";
1390 } elsif ($r eq 'SCALAR') {
1391 # literal SQL without bind
1392 push @sqlq, "$label = $$v";
1394 push @sqlq, "$label = ?";
1395 push @sqlv, $self->_bindtype($k, $v);
1398 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1399 } elsif ($ref eq 'ARRAY') {
1400 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1403 if ($r eq 'ARRAY') { # literal SQL with bind
1404 my ($sql, @bind) = @$v;
1405 $self->_assert_bindval_matches_bindtype(@bind);
1408 } elsif ($r eq 'SCALAR') { # literal SQL without bind
1409 # embedded literal SQL
1416 push @sql, '(' . join(', ', @sqlq) . ')';
1417 } elsif ($ref eq 'SCALAR') {
1421 # strings get case twiddled
1422 push @sql, $self->_sqlcase($_);
1426 my $sql = join ' ', @sql;
1428 # this is pretty tricky
1429 # if ask for an array, return ($stmt, @bind)
1430 # otherwise, s/?/shift @sqlv/ to put it inline
1432 return ($sql, @sqlv);
1434 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1435 ref $d ? $d->[1] : $d/e;
1444 # This allows us to check for a local, then _form, attr
1446 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1447 return $self->generate($name, @_);
1458 SQL::Abstract - Generate SQL from Perl data structures
1464 my $sql = SQL::Abstract->new;
1466 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
1468 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1470 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1472 my($stmt, @bind) = $sql->delete($table, \%where);
1474 # Then, use these in your DBI statements
1475 my $sth = $dbh->prepare($stmt);
1476 $sth->execute(@bind);
1478 # Just generate the WHERE clause
1479 my($stmt, @bind) = $sql->where(\%where, $order);
1481 # Return values in the same order, for hashed queries
1482 # See PERFORMANCE section for more details
1483 my @bind = $sql->values(\%fieldvals);
1487 This module was inspired by the excellent L<DBIx::Abstract>.
1488 However, in using that module I found that what I really wanted
1489 to do was generate SQL, but still retain complete control over my
1490 statement handles and use the DBI interface. So, I set out to
1491 create an abstract SQL generation module.
1493 While based on the concepts used by L<DBIx::Abstract>, there are
1494 several important differences, especially when it comes to WHERE
1495 clauses. I have modified the concepts used to make the SQL easier
1496 to generate from Perl data structures and, IMO, more intuitive.
1497 The underlying idea is for this module to do what you mean, based
1498 on the data structures you provide it. The big advantage is that
1499 you don't have to modify your code every time your data changes,
1500 as this module figures it out.
1502 To begin with, an SQL INSERT is as easy as just specifying a hash
1503 of C<key=value> pairs:
1506 name => 'Jimbo Bobson',
1507 phone => '123-456-7890',
1508 address => '42 Sister Lane',
1509 city => 'St. Louis',
1510 state => 'Louisiana',
1513 The SQL can then be generated with this:
1515 my($stmt, @bind) = $sql->insert('people', \%data);
1517 Which would give you something like this:
1519 $stmt = "INSERT INTO people
1520 (address, city, name, phone, state)
1521 VALUES (?, ?, ?, ?, ?)";
1522 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1523 '123-456-7890', 'Louisiana');
1525 These are then used directly in your DBI code:
1527 my $sth = $dbh->prepare($stmt);
1528 $sth->execute(@bind);
1530 =head2 Inserting and Updating Arrays
1532 If your database has array types (like for example Postgres),
1533 activate the special option C<< array_datatypes => 1 >>
1534 when creating the C<SQL::Abstract> object.
1535 Then you may use an arrayref to insert and update database array types:
1537 my $sql = SQL::Abstract->new(array_datatypes => 1);
1539 planets => [qw/Mercury Venus Earth Mars/]
1542 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1546 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1548 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1551 =head2 Inserting and Updating SQL
1553 In order to apply SQL functions to elements of your C<%data> you may
1554 specify a reference to an arrayref for the given hash value. For example,
1555 if you need to execute the Oracle C<to_date> function on a value, you can
1556 say something like this:
1560 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
1563 The first value in the array is the actual SQL. Any other values are
1564 optional and would be included in the bind values array. This gives
1567 my($stmt, @bind) = $sql->insert('people', \%data);
1569 $stmt = "INSERT INTO people (name, date_entered)
1570 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1571 @bind = ('Bill', '03/02/2003');
1573 An UPDATE is just as easy, all you change is the name of the function:
1575 my($stmt, @bind) = $sql->update('people', \%data);
1577 Notice that your C<%data> isn't touched; the module will generate
1578 the appropriately quirky SQL for you automatically. Usually you'll
1579 want to specify a WHERE clause for your UPDATE, though, which is
1580 where handling C<%where> hashes comes in handy...
1582 =head2 Complex where statements
1584 This module can generate pretty complicated WHERE statements
1585 easily. For example, simple C<key=value> pairs are taken to mean
1586 equality, and if you want to see if a field is within a set
1587 of values, you can use an arrayref. Let's say we wanted to
1588 SELECT some data based on this criteria:
1591 requestor => 'inna',
1592 worker => ['nwiger', 'rcwe', 'sfz'],
1593 status => { '!=', 'completed' }
1596 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1598 The above would give you something like this:
1600 $stmt = "SELECT * FROM tickets WHERE
1601 ( requestor = ? ) AND ( status != ? )
1602 AND ( worker = ? OR worker = ? OR worker = ? )";
1603 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1605 Which you could then use in DBI code like so:
1607 my $sth = $dbh->prepare($stmt);
1608 $sth->execute(@bind);
1614 The methods are simple. There's one for every major SQL operation,
1615 and a constructor you use first. The arguments are specified in a
1616 similar order for each method (table, then fields, then a where
1617 clause) to try and simplify things.
1619 =head2 new(option => 'value')
1621 The C<new()> function takes a list of options and values, and returns
1622 a new B<SQL::Abstract> object which can then be used to generate SQL
1623 through the methods below. The options accepted are:
1629 If set to 'lower', then SQL will be generated in all lowercase. By
1630 default SQL is generated in "textbook" case meaning something like:
1632 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1634 Any setting other than 'lower' is ignored.
1638 This determines what the default comparison operator is. By default
1639 it is C<=>, meaning that a hash like this:
1641 %where = (name => 'nwiger', email => 'nate@wiger.org');
1643 Will generate SQL like this:
1645 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1647 However, you may want loose comparisons by default, so if you set
1648 C<cmp> to C<like> you would get SQL such as:
1650 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1652 You can also override the comparison on an individual basis - see
1653 the huge section on L</"WHERE CLAUSES"> at the bottom.
1655 =item sqltrue, sqlfalse
1657 Expressions for inserting boolean values within SQL statements.
1658 By default these are C<1=1> and C<1=0>. They are used
1659 by the special operators C<-in> and C<-not_in> for generating
1660 correct SQL even when the argument is an empty array (see below).
1664 This determines the default logical operator for multiple WHERE
1665 statements in arrays or hashes. If absent, the default logic is "or"
1666 for arrays, and "and" for hashes. This means that a WHERE
1670 event_date => {'>=', '2/13/99'},
1671 event_date => {'<=', '4/24/03'},
1674 will generate SQL like this:
1676 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1678 This is probably not what you want given this query, though (look
1679 at the dates). To change the "OR" to an "AND", simply specify:
1681 my $sql = SQL::Abstract->new(logic => 'and');
1683 Which will change the above C<WHERE> to:
1685 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1687 The logic can also be changed locally by inserting
1688 a modifier in front of an arrayref:
1690 @where = (-and => [event_date => {'>=', '2/13/99'},
1691 event_date => {'<=', '4/24/03'} ]);
1693 See the L</"WHERE CLAUSES"> section for explanations.
1697 This will automatically convert comparisons using the specified SQL
1698 function for both column and value. This is mostly used with an argument
1699 of C<upper> or C<lower>, so that the SQL will have the effect of
1700 case-insensitive "searches". For example, this:
1702 $sql = SQL::Abstract->new(convert => 'upper');
1703 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1705 Will turn out the following SQL:
1707 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1709 The conversion can be C<upper()>, C<lower()>, or any other SQL function
1710 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1711 not validate this option; it will just pass through what you specify verbatim).
1715 This is a kludge because many databases suck. For example, you can't
1716 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1717 Instead, you have to use C<bind_param()>:
1719 $sth->bind_param(1, 'reg data');
1720 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1722 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1723 which loses track of which field each slot refers to. Fear not.
1725 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1726 Currently, you can specify either C<normal> (default) or C<columns>. If you
1727 specify C<columns>, you will get an array that looks like this:
1729 my $sql = SQL::Abstract->new(bindtype => 'columns');
1730 my($stmt, @bind) = $sql->insert(...);
1733 [ 'column1', 'value1' ],
1734 [ 'column2', 'value2' ],
1735 [ 'column3', 'value3' ],
1738 You can then iterate through this manually, using DBI's C<bind_param()>.
1740 $sth->prepare($stmt);
1743 my($col, $data) = @$_;
1744 if ($col eq 'details' || $col eq 'comments') {
1745 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1746 } elsif ($col eq 'image') {
1747 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1749 $sth->bind_param($i, $data);
1753 $sth->execute; # execute without @bind now
1755 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1756 Basically, the advantage is still that you don't have to care which fields
1757 are or are not included. You could wrap that above C<for> loop in a simple
1758 sub called C<bind_fields()> or something and reuse it repeatedly. You still
1759 get a layer of abstraction over manual SQL specification.
1761 Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
1762 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1763 will expect the bind values in this format.
1767 This is the character that a table or column name will be quoted
1768 with. By default this is an empty string, but you could set it to
1769 the character C<`>, to generate SQL like this:
1771 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1773 Alternatively, you can supply an array ref of two items, the first being the left
1774 hand quote character, and the second the right hand quote character. For
1775 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1776 that generates SQL like this:
1778 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1780 Quoting is useful if you have tables or columns names that are reserved
1781 words in your database's SQL dialect.
1785 This is the character that will be used to escape L</quote_char>s appearing
1786 in an identifier before it has been quoted.
1788 The parameter default in case of a single L</quote_char> character is the quote
1791 When opening-closing-style quoting is used (L</quote_char> is an arrayref)
1792 this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
1793 of the B<opening (left)> L</quote_char> within the identifier are currently left
1794 untouched. The default for opening-closing-style quotes may change in future
1795 versions, thus you are B<strongly encouraged> to specify the escape character
1800 This is the character that separates a table and column name. It is
1801 necessary to specify this when the C<quote_char> option is selected,
1802 so that tables and column names can be individually quoted like this:
1804 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1806 =item injection_guard
1808 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1809 column name specified in a query structure. This is a safety mechanism to avoid
1810 injection attacks when mishandling user input e.g.:
1812 my %condition_as_column_value_pairs = get_values_from_user();
1813 $sqla->select( ... , \%condition_as_column_value_pairs );
1815 If the expression matches an exception is thrown. Note that literal SQL
1816 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1818 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1820 =item array_datatypes
1822 When this option is true, arrayrefs in INSERT or UPDATE are
1823 interpreted as array datatypes and are passed directly
1825 When this option is false, arrayrefs are interpreted
1826 as literal SQL, just like refs to arrayrefs
1827 (but this behavior is for backwards compatibility; when writing
1828 new queries, use the "reference to arrayref" syntax
1834 Takes a reference to a list of "special operators"
1835 to extend the syntax understood by L<SQL::Abstract>.
1836 See section L</"SPECIAL OPERATORS"> for details.
1840 Takes a reference to a list of "unary operators"
1841 to extend the syntax understood by L<SQL::Abstract>.
1842 See section L</"UNARY OPERATORS"> for details.
1848 =head2 insert($table, \@values || \%fieldvals, \%options)
1850 This is the simplest function. You simply give it a table name
1851 and either an arrayref of values or hashref of field/value pairs.
1852 It returns an SQL INSERT statement and a list of bind values.
1853 See the sections on L</"Inserting and Updating Arrays"> and
1854 L</"Inserting and Updating SQL"> for information on how to insert
1855 with those data types.
1857 The optional C<\%options> hash reference may contain additional
1858 options to generate the insert SQL. Currently supported options
1865 Takes either a scalar of raw SQL fields, or an array reference of
1866 field names, and adds on an SQL C<RETURNING> statement at the end.
1867 This allows you to return data generated by the insert statement
1868 (such as row IDs) without performing another C<SELECT> statement.
1869 Note, however, this is not part of the SQL standard and may not
1870 be supported by all database engines.
1874 =head2 update($table, \%fieldvals, \%where, \%options)
1876 This takes a table, hashref of field/value pairs, and an optional
1877 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
1879 See the sections on L</"Inserting and Updating Arrays"> and
1880 L</"Inserting and Updating SQL"> for information on how to insert
1881 with those data types.
1883 The optional C<\%options> hash reference may contain additional
1884 options to generate the update SQL. Currently supported options
1891 See the C<returning> option to
1892 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1896 =head2 select($source, $fields, $where, $order)
1898 This returns a SQL SELECT statement and associated list of bind values, as
1899 specified by the arguments:
1905 Specification of the 'FROM' part of the statement.
1906 The argument can be either a plain scalar (interpreted as a table
1907 name, will be quoted), or an arrayref (interpreted as a list
1908 of table names, joined by commas, quoted), or a scalarref
1909 (literal SQL, not quoted).
1913 Specification of the list of fields to retrieve from
1915 The argument can be either an arrayref (interpreted as a list
1916 of field names, will be joined by commas and quoted), or a
1917 plain scalar (literal SQL, not quoted).
1918 Please observe that this API is not as flexible as that of
1919 the first argument C<$source>, for backwards compatibility reasons.
1923 Optional argument to specify the WHERE part of the query.
1924 The argument is most often a hashref, but can also be
1925 an arrayref or plain scalar --
1926 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
1930 Optional argument to specify the ORDER BY part of the query.
1931 The argument can be a scalar, a hashref or an arrayref
1932 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1938 =head2 delete($table, \%where, \%options)
1940 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
1941 It returns an SQL DELETE statement and list of bind values.
1943 The optional C<\%options> hash reference may contain additional
1944 options to generate the delete SQL. Currently supported options
1951 See the C<returning> option to
1952 L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1956 =head2 where(\%where, $order)
1958 This is used to generate just the WHERE clause. For example,
1959 if you have an arbitrary data structure and know what the
1960 rest of your SQL is going to look like, but want an easy way
1961 to produce a WHERE clause, use this. It returns an SQL WHERE
1962 clause and list of bind values.
1965 =head2 values(\%data)
1967 This just returns the values from the hash C<%data>, in the same
1968 order that would be returned from any of the other above queries.
1969 Using this allows you to markedly speed up your queries if you
1970 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1972 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
1974 Warning: This is an experimental method and subject to change.
1976 This returns arbitrarily generated SQL. It's a really basic shortcut.
1977 It will return two different things, depending on return context:
1979 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1980 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1982 These would return the following:
1984 # First calling form
1985 $stmt = "CREATE TABLE test (?, ?)";
1986 @bind = (field1, field2);
1988 # Second calling form
1989 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1991 Depending on what you're trying to do, it's up to you to choose the correct
1992 format. In this example, the second form is what you would want.
1996 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2000 ALTER SESSION SET nls_date_format = 'MM/YY'
2002 You get the idea. Strings get their case twiddled, but everything
2003 else remains verbatim.
2005 =head1 EXPORTABLE FUNCTIONS
2007 =head2 is_plain_value
2009 Determines if the supplied argument is a plain value as understood by this
2014 =item * The value is C<undef>
2016 =item * The value is a non-reference
2018 =item * The value is an object with stringification overloading
2020 =item * The value is of the form C<< { -value => $anything } >>
2024 On failure returns C<undef>, on success returns a B<scalar> reference
2025 to the original supplied argument.
2031 The stringification overloading detection is rather advanced: it takes
2032 into consideration not only the presence of a C<""> overload, but if that
2033 fails also checks for enabled
2034 L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2035 on either C<0+> or C<bool>.
2037 Unfortunately testing in the field indicates that this
2038 detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2039 but only when very large numbers of stringifying objects are involved.
2040 At the time of writing ( Sep 2014 ) there is no clear explanation of
2041 the direct cause, nor is there a manageably small test case that reliably
2042 reproduces the problem.
2044 If you encounter any of the following exceptions in B<random places within
2045 your application stack> - this module may be to blame:
2047 Operation "ne": no method found,
2048 left argument in overloaded package <something>,
2049 right argument in overloaded package <something>
2053 Stub found while resolving method "???" overloading """" in package <something>
2055 If you fall victim to the above - please attempt to reduce the problem
2056 to something that could be sent to the L<SQL::Abstract developers
2057 |DBIx::Class/GETTING HELP/SUPPORT>
2058 (either publicly or privately). As a workaround in the meantime you can
2059 set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2060 value, which will most likely eliminate your problem (at the expense of
2061 not being able to properly detect exotic forms of stringification).
2063 This notice and environment variable will be removed in a future version,
2064 as soon as the underlying problem is found and a reliable workaround is
2069 =head2 is_literal_value
2071 Determines if the supplied argument is a literal value as understood by this
2076 =item * C<\$sql_string>
2078 =item * C<\[ $sql_string, @bind_values ]>
2082 On failure returns C<undef>, on success returns an B<array> reference
2083 containing the unpacked version of the supplied literal SQL and bind values.
2085 =head1 WHERE CLAUSES
2089 This module uses a variation on the idea from L<DBIx::Abstract>. It
2090 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2091 module is that things in arrays are OR'ed, and things in hashes
2094 The easiest way to explain is to show lots of examples. After
2095 each C<%where> hash shown, it is assumed you used:
2097 my($stmt, @bind) = $sql->where(\%where);
2099 However, note that the C<%where> hash can be used directly in any
2100 of the other functions as well, as described above.
2102 =head2 Key-value pairs
2104 So, let's get started. To begin, a simple hash:
2108 status => 'completed'
2111 Is converted to SQL C<key = val> statements:
2113 $stmt = "WHERE user = ? AND status = ?";
2114 @bind = ('nwiger', 'completed');
2116 One common thing I end up doing is having a list of values that
2117 a field can be in. To do this, simply specify a list inside of
2122 status => ['assigned', 'in-progress', 'pending'];
2125 This simple code will create the following:
2127 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2128 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2130 A field associated to an empty arrayref will be considered a
2131 logical false and will generate 0=1.
2133 =head2 Tests for NULL values
2135 If the value part is C<undef> then this is converted to SQL <IS NULL>
2144 $stmt = "WHERE user = ? AND status IS NULL";
2147 To test if a column IS NOT NULL:
2151 status => { '!=', undef },
2154 =head2 Specific comparison operators
2156 If you want to specify a different type of operator for your comparison,
2157 you can use a hashref for a given column:
2161 status => { '!=', 'completed' }
2164 Which would generate:
2166 $stmt = "WHERE user = ? AND status != ?";
2167 @bind = ('nwiger', 'completed');
2169 To test against multiple values, just enclose the values in an arrayref:
2171 status => { '=', ['assigned', 'in-progress', 'pending'] };
2173 Which would give you:
2175 "WHERE status = ? OR status = ? OR status = ?"
2178 The hashref can also contain multiple pairs, in which case it is expanded
2179 into an C<AND> of its elements:
2183 status => { '!=', 'completed', -not_like => 'pending%' }
2186 # Or more dynamically, like from a form
2187 $where{user} = 'nwiger';
2188 $where{status}{'!='} = 'completed';
2189 $where{status}{'-not_like'} = 'pending%';
2191 # Both generate this
2192 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2193 @bind = ('nwiger', 'completed', 'pending%');
2196 To get an OR instead, you can combine it with the arrayref idea:
2200 priority => [ { '=', 2 }, { '>', 5 } ]
2203 Which would generate:
2205 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2206 @bind = ('2', '5', 'nwiger');
2208 If you want to include literal SQL (with or without bind values), just use a
2209 scalar reference or reference to an arrayref as the value:
2212 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2213 date_expires => { '<' => \"now()" }
2216 Which would generate:
2218 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2219 @bind = ('11/26/2008');
2222 =head2 Logic and nesting operators
2224 In the example above,
2225 there is a subtle trap if you want to say something like
2226 this (notice the C<AND>):
2228 WHERE priority != ? AND priority != ?
2230 Because, in Perl you I<can't> do this:
2232 priority => { '!=' => 2, '!=' => 1 }
2234 As the second C<!=> key will obliterate the first. The solution
2235 is to use the special C<-modifier> form inside an arrayref:
2237 priority => [ -and => {'!=', 2},
2241 Normally, these would be joined by C<OR>, but the modifier tells it
2242 to use C<AND> instead. (Hint: You can use this in conjunction with the
2243 C<logic> option to C<new()> in order to change the way your queries
2244 work by default.) B<Important:> Note that the C<-modifier> goes
2245 B<INSIDE> the arrayref, as an extra first element. This will
2246 B<NOT> do what you think it might:
2248 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2250 Here is a quick list of equivalencies, since there is some overlap:
2253 status => {'!=', 'completed', 'not like', 'pending%' }
2254 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2257 status => {'=', ['assigned', 'in-progress']}
2258 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2259 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2263 =head2 Special operators: IN, BETWEEN, etc.
2265 You can also use the hashref format to compare a list of fields using the
2266 C<IN> comparison operator, by specifying the list as an arrayref:
2269 status => 'completed',
2270 reportid => { -in => [567, 2335, 2] }
2273 Which would generate:
2275 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2276 @bind = ('completed', '567', '2335', '2');
2278 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
2281 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2282 (by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2283 'sqltrue' (by default: C<1=1>).
2285 In addition to the array you can supply a chunk of literal sql or
2286 literal sql with bind:
2289 customer => { -in => \[
2290 'SELECT cust_id FROM cust WHERE balance > ?',
2293 status => { -in => \'SELECT status_codes FROM states' },
2299 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2300 AND status IN ( SELECT status_codes FROM states )
2304 Finally, if the argument to C<-in> is not a reference, it will be
2305 treated as a single-element array.
2307 Another pair of operators is C<-between> and C<-not_between>,
2308 used with an arrayref of two values:
2312 completion_date => {
2313 -not_between => ['2002-10-01', '2003-02-06']
2319 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2321 Just like with C<-in> all plausible combinations of literal SQL
2325 start0 => { -between => [ 1, 2 ] },
2326 start1 => { -between => \["? AND ?", 1, 2] },
2327 start2 => { -between => \"lower(x) AND upper(y)" },
2328 start3 => { -between => [
2330 \["upper(?)", 'stuff' ],
2337 ( start0 BETWEEN ? AND ? )
2338 AND ( start1 BETWEEN ? AND ? )
2339 AND ( start2 BETWEEN lower(x) AND upper(y) )
2340 AND ( start3 BETWEEN lower(x) AND upper(?) )
2342 @bind = (1, 2, 1, 2, 'stuff');
2345 These are the two builtin "special operators"; but the
2346 list can be expanded: see section L</"SPECIAL OPERATORS"> below.
2348 =head2 Unary operators: bool
2350 If you wish to test against boolean columns or functions within your
2351 database you can use the C<-bool> and C<-not_bool> operators. For
2352 example to test the column C<is_user> being true and the column
2353 C<is_enabled> being false you would use:-
2357 -not_bool => 'is_enabled',
2362 WHERE is_user AND NOT is_enabled
2364 If a more complex combination is required, testing more conditions,
2365 then you should use the and/or operators:-
2370 -not_bool => { two=> { -rlike => 'bar' } },
2371 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
2382 (NOT ( three = ? OR three > ? ))
2385 =head2 Nested conditions, -and/-or prefixes
2387 So far, we've seen how multiple conditions are joined with a top-level
2388 C<AND>. We can change this by putting the different conditions we want in
2389 hashes and then putting those hashes in an array. For example:
2394 status => { -like => ['pending%', 'dispatched'] },
2398 status => 'unassigned',
2402 This data structure would create the following:
2404 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2405 OR ( user = ? AND status = ? ) )";
2406 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2409 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2410 to change the logic inside:
2416 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2417 -or => { workhrs => {'<', 50}, geo => 'EURO' },
2424 $stmt = "WHERE ( user = ?
2425 AND ( ( workhrs > ? AND geo = ? )
2426 OR ( workhrs < ? OR geo = ? ) ) )";
2427 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
2429 =head3 Algebraic inconsistency, for historical reasons
2431 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2432 operator goes C<outside> of the nested structure; whereas when connecting
2433 several constraints on one column, the C<-and> operator goes
2434 C<inside> the arrayref. Here is an example combining both features:
2437 -and => [a => 1, b => 2],
2438 -or => [c => 3, d => 4],
2439 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2444 WHERE ( ( ( a = ? AND b = ? )
2445 OR ( c = ? OR d = ? )
2446 OR ( e LIKE ? AND e LIKE ? ) ) )
2448 This difference in syntax is unfortunate but must be preserved for
2449 historical reasons. So be careful: the two examples below would
2450 seem algebraically equivalent, but they are not
2453 { -like => 'foo%' },
2454 { -like => '%bar' },
2456 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
2459 { col => { -like => 'foo%' } },
2460 { col => { -like => '%bar' } },
2462 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
2465 =head2 Literal SQL and value type operators
2467 The basic premise of SQL::Abstract is that in WHERE specifications the "left
2468 side" is a column name and the "right side" is a value (normally rendered as
2469 a placeholder). This holds true for both hashrefs and arrayref pairs as you
2470 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2471 alter this behavior. There are several ways of doing so.
2475 This is a virtual operator that signals the string to its right side is an
2476 identifier (a column name) and not a value. For example to compare two
2477 columns you would write:
2480 priority => { '<', 2 },
2481 requestor => { -ident => 'submitter' },
2486 $stmt = "WHERE priority < ? AND requestor = submitter";
2489 If you are maintaining legacy code you may see a different construct as
2490 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2495 This is a virtual operator that signals that the construct to its right side
2496 is a value to be passed to DBI. This is for example necessary when you want
2497 to write a where clause against an array (for RDBMS that support such
2498 datatypes). For example:
2501 array => { -value => [1, 2, 3] }
2506 $stmt = 'WHERE array = ?';
2507 @bind = ([1, 2, 3]);
2509 Note that if you were to simply say:
2515 the result would probably not be what you wanted:
2517 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2522 Finally, sometimes only literal SQL will do. To include a random snippet
2523 of SQL verbatim, you specify it as a scalar reference. Consider this only
2524 as a last resort. Usually there is a better way. For example:
2527 priority => { '<', 2 },
2528 requestor => { -in => \'(SELECT name FROM hitmen)' },
2533 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2536 Note that in this example, you only get one bind parameter back, since
2537 the verbatim SQL is passed as part of the statement.
2541 Never use untrusted input as a literal SQL argument - this is a massive
2542 security risk (there is no way to check literal snippets for SQL
2543 injections and other nastyness). If you need to deal with untrusted input
2544 use literal SQL with placeholders as described next.
2546 =head3 Literal SQL with placeholders and bind values (subqueries)
2548 If the literal SQL to be inserted has placeholders and bind values,
2549 use a reference to an arrayref (yes this is a double reference --
2550 not so common, but perfectly legal Perl). For example, to find a date
2551 in Postgres you can use something like this:
2554 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
2559 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
2562 Note that you must pass the bind values in the same format as they are returned
2563 by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
2564 to C<columns>, you must provide the bind values in the
2565 C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2566 scalar value; most commonly the column name, but you can use any scalar value
2567 (including references and blessed references), L<SQL::Abstract> will simply
2568 pass it through intact. So if C<bindtype> is set to C<columns> the above
2569 example will look like:
2572 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
2575 Literal SQL is especially useful for nesting parenthesized clauses in the
2576 main SQL query. Here is a first example:
2578 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2582 bar => \["IN ($sub_stmt)" => @sub_bind],
2587 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
2588 WHERE c2 < ? AND c3 LIKE ?))";
2589 @bind = (1234, 100, "foo%");
2591 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
2592 are expressed in the same way. Of course the C<$sub_stmt> and
2593 its associated bind values can be generated through a former call
2596 my ($sub_stmt, @sub_bind)
2597 = $sql->select("t1", "c1", {c2 => {"<" => 100},
2598 c3 => {-like => "foo%"}});
2601 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2604 In the examples above, the subquery was used as an operator on a column;
2605 but the same principle also applies for a clause within the main C<%where>
2606 hash, like an EXISTS subquery:
2608 my ($sub_stmt, @sub_bind)
2609 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
2610 my %where = ( -and => [
2612 \["EXISTS ($sub_stmt)" => @sub_bind],
2617 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
2618 WHERE c1 = ? AND c2 > t0.c0))";
2622 Observe that the condition on C<c2> in the subquery refers to
2623 column C<t0.c0> of the main query: this is I<not> a bind
2624 value, so we have to express it through a scalar ref.
2625 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2626 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2627 what we wanted here.
2629 Finally, here is an example where a subquery is used
2630 for expressing unary negation:
2632 my ($sub_stmt, @sub_bind)
2633 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2634 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2636 lname => {like => '%son%'},
2637 \["NOT ($sub_stmt)" => @sub_bind],
2642 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2643 @bind = ('%son%', 10, 20)
2645 =head3 Deprecated usage of Literal SQL
2647 Below are some examples of archaic use of literal SQL. It is shown only as
2648 reference for those who deal with legacy code. Each example has a much
2649 better, cleaner and safer alternative that users should opt for in new code.
2655 my %where = ( requestor => \'IS NOT NULL' )
2657 $stmt = "WHERE requestor IS NOT NULL"
2659 This used to be the way of generating NULL comparisons, before the handling
2660 of C<undef> got formalized. For new code please use the superior syntax as
2661 described in L</Tests for NULL values>.
2665 my %where = ( requestor => \'= submitter' )
2667 $stmt = "WHERE requestor = submitter"
2669 This used to be the only way to compare columns. Use the superior L</-ident>
2670 method for all new code. For example an identifier declared in such a way
2671 will be properly quoted if L</quote_char> is properly set, while the legacy
2672 form will remain as supplied.
2676 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2678 $stmt = "WHERE completed > ? AND is_ready"
2679 @bind = ('2012-12-21')
2681 Using an empty string literal used to be the only way to express a boolean.
2682 For all new code please use the much more readable
2683 L<-bool|/Unary operators: bool> operator.
2689 These pages could go on for a while, since the nesting of the data
2690 structures this module can handle are pretty much unlimited (the
2691 module implements the C<WHERE> expansion as a recursive function
2692 internally). Your best bet is to "play around" with the module a
2693 little to see how the data structures behave, and choose the best
2694 format for your data based on that.
2696 And of course, all the values above will probably be replaced with
2697 variables gotten from forms or the command line. After all, if you
2698 knew everything ahead of time, you wouldn't have to worry about
2699 dynamically-generating SQL and could just hardwire it into your
2702 =head1 ORDER BY CLAUSES
2704 Some functions take an order by clause. This can either be a scalar (just a
2705 column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2706 >>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2709 Given | Will Generate
2710 ---------------------------------------------------------------
2712 'colA' | ORDER BY colA
2714 [qw/colA colB/] | ORDER BY colA, colB
2716 {-asc => 'colA'} | ORDER BY colA ASC
2718 {-desc => 'colB'} | ORDER BY colB DESC
2720 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2722 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2724 \'colA DESC' | ORDER BY colA DESC
2726 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2727 | /* ...with $x bound to ? */
2730 { -asc => 'colA' }, | colA ASC,
2731 { -desc => [qw/colB/] }, | colB DESC,
2732 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2733 \'colE DESC', | colE DESC,
2734 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2735 ] | /* ...with $x bound to ? */
2736 ===============================================================
2740 =head1 SPECIAL OPERATORS
2742 my $sqlmaker = SQL::Abstract->new(special_ops => [
2746 my ($self, $field, $op, $arg) = @_;
2752 handler => 'method_name',
2756 A "special operator" is a SQL syntactic clause that can be
2757 applied to a field, instead of a usual binary operator.
2760 WHERE field IN (?, ?, ?)
2761 WHERE field BETWEEN ? AND ?
2762 WHERE MATCH(field) AGAINST (?, ?)
2764 Special operators IN and BETWEEN are fairly standard and therefore
2765 are builtin within C<SQL::Abstract> (as the overridable methods
2766 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2767 like the MATCH .. AGAINST example above which is specific to MySQL,
2768 you can write your own operator handlers - supply a C<special_ops>
2769 argument to the C<new> method. That argument takes an arrayref of
2770 operator definitions; each operator definition is a hashref with two
2777 the regular expression to match the operator
2781 Either a coderef or a plain scalar method name. In both cases
2782 the expected return is C<< ($sql, @bind) >>.
2784 When supplied with a method name, it is simply called on the
2785 L<SQL::Abstract> object as:
2787 $self->$method_name($field, $op, $arg)
2791 $field is the LHS of the operator
2792 $op is the part that matched the handler regex
2795 When supplied with a coderef, it is called as:
2797 $coderef->($self, $field, $op, $arg)
2802 For example, here is an implementation
2803 of the MATCH .. AGAINST syntax for MySQL
2805 my $sqlmaker = SQL::Abstract->new(special_ops => [
2807 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2808 {regex => qr/^match$/i,
2810 my ($self, $field, $op, $arg) = @_;
2811 $arg = [$arg] if not ref $arg;
2812 my $label = $self->_quote($field);
2813 my ($placeholder) = $self->_convert('?');
2814 my $placeholders = join ", ", (($placeholder) x @$arg);
2815 my $sql = $self->_sqlcase('match') . " ($label) "
2816 . $self->_sqlcase('against') . " ($placeholders) ";
2817 my @bind = $self->_bindtype($field, @$arg);
2818 return ($sql, @bind);
2825 =head1 UNARY OPERATORS
2827 my $sqlmaker = SQL::Abstract->new(unary_ops => [
2831 my ($self, $op, $arg) = @_;
2837 handler => 'method_name',
2841 A "unary operator" is a SQL syntactic clause that can be
2842 applied to a field - the operator goes before the field
2844 You can write your own operator handlers - supply a C<unary_ops>
2845 argument to the C<new> method. That argument takes an arrayref of
2846 operator definitions; each operator definition is a hashref with two
2853 the regular expression to match the operator
2857 Either a coderef or a plain scalar method name. In both cases
2858 the expected return is C<< $sql >>.
2860 When supplied with a method name, it is simply called on the
2861 L<SQL::Abstract> object as:
2863 $self->$method_name($op, $arg)
2867 $op is the part that matched the handler regex
2868 $arg is the RHS or argument of the operator
2870 When supplied with a coderef, it is called as:
2872 $coderef->($self, $op, $arg)
2880 Thanks to some benchmarking by Mark Stosberg, it turns out that
2881 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2882 I must admit this wasn't an intentional design issue, but it's a
2883 byproduct of the fact that you get to control your C<DBI> handles
2886 To maximize performance, use a code snippet like the following:
2888 # prepare a statement handle using the first row
2889 # and then reuse it for the rest of the rows
2891 for my $href (@array_of_hashrefs) {
2892 $stmt ||= $sql->insert('table', $href);
2893 $sth ||= $dbh->prepare($stmt);
2894 $sth->execute($sql->values($href));
2897 The reason this works is because the keys in your C<$href> are sorted
2898 internally by B<SQL::Abstract>. Thus, as long as your data retains
2899 the same structure, you only have to generate the SQL the first time
2900 around. On subsequent queries, simply use the C<values> function provided
2901 by this module to return your values in the correct order.
2903 However this depends on the values having the same type - if, for
2904 example, the values of a where clause may either have values
2905 (resulting in sql of the form C<column = ?> with a single bind
2906 value), or alternatively the values might be C<undef> (resulting in
2907 sql of the form C<column IS NULL> with no bind value) then the
2908 caching technique suggested will not work.
2912 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2913 really like this part (I do, at least). Building up a complex query
2914 can be as simple as the following:
2921 use CGI::FormBuilder;
2924 my $form = CGI::FormBuilder->new(...);
2925 my $sql = SQL::Abstract->new;
2927 if ($form->submitted) {
2928 my $field = $form->field;
2929 my $id = delete $field->{id};
2930 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2933 Of course, you would still have to connect using C<DBI> to run the
2934 query, but the point is that if you make your form look like your
2935 table, the actual query script can be extremely simplistic.
2937 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2938 a fast interface to returning and formatting data. I frequently
2939 use these three modules together to write complex database query
2940 apps in under 50 lines.
2942 =head1 HOW TO CONTRIBUTE
2944 Contributions are always welcome, in all usable forms (we especially
2945 welcome documentation improvements). The delivery methods include git-
2946 or unified-diff formatted patches, GitHub pull requests, or plain bug
2947 reports either via RT or the Mailing list. Contributors are generally
2948 granted full access to the official repository after their first several
2949 patches pass successful review.
2951 This project is maintained in a git repository. The code and related tools are
2952 accessible at the following locations:
2956 =item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
2958 =item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
2960 =item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
2962 =item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
2968 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2969 Great care has been taken to preserve the I<published> behavior
2970 documented in previous versions in the 1.* family; however,
2971 some features that were previously undocumented, or behaved
2972 differently from the documentation, had to be changed in order
2973 to clarify the semantics. Hence, client code that was relying
2974 on some dark areas of C<SQL::Abstract> v1.*
2975 B<might behave differently> in v1.50.
2977 The main changes are:
2983 support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
2987 support for the { operator => \"..." } construct (to embed literal SQL)
2991 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2995 optional support for L<array datatypes|/"Inserting and Updating Arrays">
2999 defensive programming: check arguments
3003 fixed bug with global logic, which was previously implemented
3004 through global variables yielding side-effects. Prior versions would
3005 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3006 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3007 Now this is interpreted
3008 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3013 fixed semantics of _bindtype on array args
3017 dropped the C<_anoncopy> of the %where tree. No longer necessary,
3018 we just avoid shifting arrays within that tree.
3022 dropped the C<_modlogic> function
3026 =head1 ACKNOWLEDGEMENTS
3028 There are a number of individuals that have really helped out with
3029 this module. Unfortunately, most of them submitted bugs via CPAN
3030 so I have no idea who they are! But the people I do know are:
3032 Ash Berlin (order_by hash term support)
3033 Matt Trout (DBIx::Class support)
3034 Mark Stosberg (benchmarking)
3035 Chas Owens (initial "IN" operator support)
3036 Philip Collins (per-field SQL functions)
3037 Eric Kolve (hashref "AND" support)
3038 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3039 Dan Kubb (support for "quote_char" and "name_sep")
3040 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
3041 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
3042 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
3043 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
3044 Oliver Charles (support for "RETURNING" after "INSERT")
3050 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
3054 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3056 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
3058 For support, your best bet is to try the C<DBIx::Class> users mailing list.
3059 While not an official support venue, C<DBIx::Class> makes heavy use of
3060 C<SQL::Abstract>, and as such list members there are very familiar with
3061 how to create queries.
3065 This module is free software; you may copy this under the same
3066 terms as perl itself (either the GNU General Public License or
3067 the Artistic License)