arrayref hashpair case
[scpubgit/Q-Branch.git] / lib / SQL / Abstract.pm
CommitLineData
96449e8e 1package SQL::Abstract; # see doc at end of file
2
96449e8e 3use strict;
4use warnings;
9d9d5bd6 5use Carp ();
312d830b 6use List::Util ();
7use Scalar::Util ();
96449e8e 8
0da0fe34 9use Exporter 'import';
10our @EXPORT_OK = qw(is_plain_value is_literal_value);
11
12BEGIN {
13 if ($] < 5.009_005) {
14 require MRO::Compat;
15 }
16 else {
17 require mro;
18 }
843a94b5 19
20 *SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION = $ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}
21 ? sub () { 0 }
22 : sub () { 1 }
23 ;
0da0fe34 24}
25
96449e8e 26#======================================================================
27# GLOBALS
28#======================================================================
29
dc6afcf8 30our $VERSION = '1.86';
7479e27e 31
22f1a437 32# This would confuse some packagers
c520207b 33$VERSION = eval $VERSION if $VERSION =~ /_/; # numify for warning-free dev releases
96449e8e 34
35our $AUTOLOAD;
36
37# special operators (-in, -between). May be extended/overridden by user.
38# See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
39my @BUILTIN_SPECIAL_OPS = (
b8db59b8 40 {regex => qr/^ (?: not \s )? between $/ix, handler => '_where_field_BETWEEN'},
41 {regex => qr/^ (?: not \s )? in $/ix, handler => '_where_field_IN'},
cc422895 42 {regex => qr/^ ident $/ix, handler => '_where_op_IDENT'},
43 {regex => qr/^ value $/ix, handler => '_where_op_VALUE'},
b9b5a0b1 44 {regex => qr/^ is (?: \s+ not )? $/ix, handler => '_where_field_IS'},
96449e8e 45);
46
97a920ef 47# unaryish operators - key maps to handler
59f23b3d 48my @BUILTIN_UNARY_OPS = (
a47b433a 49 # the digits are backcompat stuff
b8db59b8 50 { regex => qr/^ and (?: [_\s]? \d+ )? $/xi, handler => '_where_op_ANDOR' },
51 { regex => qr/^ or (?: [_\s]? \d+ )? $/xi, handler => '_where_op_ANDOR' },
52 { regex => qr/^ nest (?: [_\s]? \d+ )? $/xi, handler => '_where_op_NEST' },
53 { regex => qr/^ (?: not \s )? bool $/xi, handler => '_where_op_BOOL' },
cc422895 54 { regex => qr/^ ident $/xi, handler => '_where_op_IDENT' },
b9b5a0b1 55 { regex => qr/^ value $/xi, handler => '_where_op_VALUE' },
59f23b3d 56);
97a920ef 57
96449e8e 58#======================================================================
59# DEBUGGING AND ERROR REPORTING
60#======================================================================
61
62sub _debug {
63 return unless $_[0]->{debug}; shift; # a little faster
64 my $func = (caller(1))[3];
65 warn "[$func] ", @_, "\n";
66}
67
68sub belch (@) {
69 my($func) = (caller(1))[3];
9d9d5bd6 70 Carp::carp "[$func] Warning: ", @_;
96449e8e 71}
72
73sub puke (@) {
74 my($func) = (caller(1))[3];
9d9d5bd6 75 Carp::croak "[$func] Fatal: ", @_;
96449e8e 76}
77
0da0fe34 78sub is_literal_value ($) {
79 ref $_[0] eq 'SCALAR' ? [ ${$_[0]} ]
80 : ( ref $_[0] eq 'REF' and ref ${$_[0]} eq 'ARRAY' ) ? [ @${ $_[0] } ]
0da0fe34 81 : undef;
82}
83
84# FIXME XSify - this can be done so much more efficiently
85sub is_plain_value ($) {
86 no strict 'refs';
966200cc 87 ! length ref $_[0] ? \($_[0])
0da0fe34 88 : (
89 ref $_[0] eq 'HASH' and keys %{$_[0]} == 1
90 and
91 exists $_[0]->{-value}
966200cc 92 ) ? \($_[0]->{-value})
0da0fe34 93 : (
a1c9e0ff 94 # reuse @_ for even moar speedz
95 defined ( $_[1] = Scalar::Util::blessed $_[0] )
0da0fe34 96 and
97 # deliberately not using Devel::OverloadInfo - the checks we are
98 # intersted in are much more limited than the fullblown thing, and
99 # this is a very hot piece of code
100 (
e8d729d4 101 # simply using ->can('(""') can leave behind stub methods that
102 # break actually using the overload later (see L<perldiag/Stub
103 # found while resolving method "%s" overloading "%s" in package
104 # "%s"> and the source of overload::mycan())
44e54b41 105 #
0da0fe34 106 # either has stringification which DBI SHOULD prefer out of the box
a1c9e0ff 107 grep { *{ (qq[${_}::(""]) }{CODE} } @{ $_[2] = mro::get_linear_isa( $_[1] ) }
0da0fe34 108 or
20e178a8 109 # has nummification or boolification, AND fallback is *not* disabled
0da0fe34 110 (
843a94b5 111 SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION
112 and
20e178a8 113 (
114 grep { *{"${_}::(0+"}{CODE} } @{$_[2]}
115 or
116 grep { *{"${_}::(bool"}{CODE} } @{$_[2]}
117 )
0da0fe34 118 and
119 (
120 # no fallback specified at all
a1c9e0ff 121 ! ( ($_[3]) = grep { *{"${_}::()"}{CODE} } @{$_[2]} )
0da0fe34 122 or
123 # fallback explicitly undef
a1c9e0ff 124 ! defined ${"$_[3]::()"}
0da0fe34 125 or
126 # explicitly true
a1c9e0ff 127 !! ${"$_[3]::()"}
0da0fe34 128 )
129 )
130 )
966200cc 131 ) ? \($_[0])
0da0fe34 132 : undef;
133}
134
135
96449e8e 136
137#======================================================================
138# NEW
139#======================================================================
140
141sub new {
142 my $self = shift;
143 my $class = ref($self) || $self;
144 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
145
146 # choose our case by keeping an option around
147 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
148
149 # default logic for interpreting arrayrefs
ef559da3 150 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
96449e8e 151
152 # how to return bind vars
96449e8e 153 $opt{bindtype} ||= 'normal';
154
155 # default comparison is "=", but can be overridden
156 $opt{cmp} ||= '=';
157
3af02ccb 158 # try to recognize which are the 'equality' and 'inequality' ops
3cdadcbe 159 # (temporary quickfix (in 2007), should go through a more seasoned API)
160 $opt{equality_op} = qr/^( \Q$opt{cmp}\E | \= )$/ix;
161 $opt{inequality_op} = qr/^( != | <> )$/ix;
162
163 $opt{like_op} = qr/^ (is\s+)? r?like $/xi;
164 $opt{not_like_op} = qr/^ (is\s+)? not \s+ r?like $/xi;
96449e8e 165
166 # SQL booleans
167 $opt{sqltrue} ||= '1=1';
168 $opt{sqlfalse} ||= '0=1';
169
9d48860e 170 # special operators
96449e8e 171 $opt{special_ops} ||= [];
b6251592 172 # regexes are applied in order, thus push after user-defines
96449e8e 173 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
174
9d48860e 175 # unary operators
59f23b3d 176 $opt{unary_ops} ||= [];
177 push @{$opt{unary_ops}}, @BUILTIN_UNARY_OPS;
178
3af02ccb 179 # rudimentary sanity-check for user supplied bits treated as functions/operators
b6251592 180 # If a purported function matches this regular expression, an exception is thrown.
181 # Literal SQL is *NOT* subject to this check, only functions (and column names
182 # when quoting is not in effect)
96449e8e 183
b6251592 184 # FIXME
185 # need to guard against ()'s in column names too, but this will break tons of
186 # hacks... ideas anyone?
187 $opt{injection_guard} ||= qr/
188 \;
189 |
190 ^ \s* go \s
191 /xmi;
96449e8e 192
b6251592 193 return bless \%opt, $class;
194}
96449e8e 195
170e6c33 196
197sub _assert_pass_injection_guard {
198 if ($_[1] =~ $_[0]->{injection_guard}) {
199 my $class = ref $_[0];
200 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
201 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
202 . "{injection_guard} attribute to ${class}->new()"
203 }
204}
205
206
96449e8e 207#======================================================================
208# INSERT methods
209#======================================================================
210
211sub insert {
02288357 212 my $self = shift;
213 my $table = $self->_table(shift);
214 my $data = shift || return;
215 my $options = shift;
96449e8e 216
217 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
02288357 218 my ($sql, @bind) = $self->$method($data);
96449e8e 219 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
02288357 220
e82e648a 221 if ($options->{returning}) {
ca4f826a 222 my ($s, @b) = $self->_insert_returning($options);
e82e648a 223 $sql .= $s;
224 push @bind, @b;
02288357 225 }
226
96449e8e 227 return wantarray ? ($sql, @bind) : $sql;
228}
229
60f3fd3f 230# So that subclasses can override INSERT ... RETURNING separately from
231# UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
b17a3ece 232sub _insert_returning { shift->_returning(@_) }
233
95904db5 234sub _returning {
e82e648a 235 my ($self, $options) = @_;
6b1fe79d 236
e82e648a 237 my $f = $options->{returning};
238
239 my $fieldlist = $self->_SWITCH_refkind($f, {
240 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$f;},
241 SCALAR => sub {$self->_quote($f)},
242 SCALARREF => sub {$$f},
6b1fe79d 243 });
e82e648a 244 return $self->_sqlcase(' returning ') . $fieldlist;
6b1fe79d 245}
246
96449e8e 247sub _insert_HASHREF { # explicit list of fields and then values
248 my ($self, $data) = @_;
249
250 my @fields = sort keys %$data;
251
fe3ae272 252 my ($sql, @bind) = $self->_insert_values($data);
96449e8e 253
254 # assemble SQL
255 $_ = $self->_quote($_) foreach @fields;
256 $sql = "( ".join(", ", @fields).") ".$sql;
257
258 return ($sql, @bind);
259}
260
261sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
262 my ($self, $data) = @_;
263
264 # no names (arrayref) so can't generate bindtype
265 $self->{bindtype} ne 'columns'
266 or belch "can't do 'columns' bindtype when called with arrayref";
267
19b6ccce 268 my (@values, @all_bind);
269 foreach my $value (@$data) {
270 my ($values, @bind) = $self->_insert_value(undef, $value);
271 push @values, $values;
272 push @all_bind, @bind;
273 }
274 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
275 return ($sql, @all_bind);
fe3ae272 276}
277
278sub _insert_ARRAYREFREF { # literal SQL with bind
279 my ($self, $data) = @_;
280
281 my ($sql, @bind) = @${$data};
282 $self->_assert_bindval_matches_bindtype(@bind);
283
284 return ($sql, @bind);
285}
286
287
288sub _insert_SCALARREF { # literal SQL without bind
289 my ($self, $data) = @_;
290
291 return ($$data);
292}
293
294sub _insert_values {
295 my ($self, $data) = @_;
296
96449e8e 297 my (@values, @all_bind);
fe3ae272 298 foreach my $column (sort keys %$data) {
19b6ccce 299 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
300 push @values, $values;
301 push @all_bind, @bind;
302 }
303 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
304 return ($sql, @all_bind);
305}
96449e8e 306
19b6ccce 307sub _insert_value {
308 my ($self, $column, $v) = @_;
96449e8e 309
19b6ccce 310 my (@values, @all_bind);
311 $self->_SWITCH_refkind($v, {
96449e8e 312
19b6ccce 313 ARRAYREF => sub {
314 if ($self->{array_datatypes}) { # if array datatype are activated
96449e8e 315 push @values, '?';
fe3ae272 316 push @all_bind, $self->_bindtype($column, $v);
19b6ccce 317 }
318 else { # else literal SQL with bind
319 my ($sql, @bind) = @$v;
320 $self->_assert_bindval_matches_bindtype(@bind);
321 push @values, $sql;
322 push @all_bind, @bind;
323 }
324 },
325
326 ARRAYREFREF => sub { # literal SQL with bind
327 my ($sql, @bind) = @${$v};
328 $self->_assert_bindval_matches_bindtype(@bind);
329 push @values, $sql;
330 push @all_bind, @bind;
331 },
332
be21dde3 333 # THINK: anything useful to do with a HASHREF ?
19b6ccce 334 HASHREF => sub { # (nothing, but old SQLA passed it through)
335 #TODO in SQLA >= 2.0 it will die instead
336 belch "HASH ref as bind value in insert is not supported";
337 push @values, '?';
338 push @all_bind, $self->_bindtype($column, $v);
339 },
340
341 SCALARREF => sub { # literal SQL without bind
342 push @values, $$v;
343 },
344
345 SCALAR_or_UNDEF => sub {
346 push @values, '?';
347 push @all_bind, $self->_bindtype($column, $v);
348 },
96449e8e 349
19b6ccce 350 });
96449e8e 351
19b6ccce 352 my $sql = join(", ", @values);
96449e8e 353 return ($sql, @all_bind);
354}
355
356
96449e8e 357
358#======================================================================
359# UPDATE methods
360#======================================================================
361
362
363sub update {
95904db5 364 my $self = shift;
365 my $table = $self->_table(shift);
366 my $data = shift || return;
367 my $where = shift;
368 my $options = shift;
96449e8e 369
370 # first build the 'SET' part of the sql statement
96449e8e 371 puke "Unsupported data type specified to \$sql->update"
372 unless ref $data eq 'HASH';
373
9ade906e 374 my ($sql, @all_bind) = $self->_update_set_values($data);
a9e94508 375 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
9ade906e 376 . $sql;
377
378 if ($where) {
379 my($where_sql, @where_bind) = $self->where($where);
380 $sql .= $where_sql;
381 push @all_bind, @where_bind;
382 }
383
384 if ($options->{returning}) {
385 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
386 $sql .= $returning_sql;
387 push @all_bind, @returning_bind;
388 }
389
390 return wantarray ? ($sql, @all_bind) : $sql;
391}
392
393sub _update_set_values {
394 my ($self, $data) = @_;
395
396 my (@set, @all_bind);
96449e8e 397 for my $k (sort keys %$data) {
398 my $v = $data->{$k};
399 my $r = ref $v;
400 my $label = $self->_quote($k);
401
402 $self->_SWITCH_refkind($v, {
9d48860e 403 ARRAYREF => sub {
96449e8e 404 if ($self->{array_datatypes}) { # array datatype
405 push @set, "$label = ?";
406 push @all_bind, $self->_bindtype($k, $v);
407 }
408 else { # literal SQL with bind
409 my ($sql, @bind) = @$v;
fe3ae272 410 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 411 push @set, "$label = $sql";
fe3ae272 412 push @all_bind, @bind;
96449e8e 413 }
414 },
415 ARRAYREFREF => sub { # literal SQL with bind
416 my ($sql, @bind) = @${$v};
fe3ae272 417 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 418 push @set, "$label = $sql";
fe3ae272 419 push @all_bind, @bind;
96449e8e 420 },
421 SCALARREF => sub { # literal SQL without bind
422 push @set, "$label = $$v";
0ec3aec7 423 },
424 HASHREF => sub {
425 my ($op, $arg, @rest) = %$v;
426
427 puke 'Operator calls in update must be in the form { -op => $arg }'
428 if (@rest or not $op =~ /^\-(.+)/);
429
430 local $self->{_nested_func_lhs} = $k;
ca4f826a 431 my ($sql, @bind) = $self->_where_unary_op($1, $arg);
0ec3aec7 432
433 push @set, "$label = $sql";
434 push @all_bind, @bind;
435 },
96449e8e 436 SCALAR_or_UNDEF => sub {
437 push @set, "$label = ?";
438 push @all_bind, $self->_bindtype($k, $v);
439 },
440 });
441 }
442
443 # generate sql
9ade906e 444 my $sql = join ', ', @set;
96449e8e 445
9ade906e 446 return ($sql, @all_bind);
96449e8e 447}
448
60f3fd3f 449# So that subclasses can override UPDATE ... RETURNING separately from
450# INSERT and DELETE
20bb2ad5 451sub _update_returning { shift->_returning(@_) }
96449e8e 452
453
454
455#======================================================================
456# SELECT
457#======================================================================
458
459
460sub select {
461 my $self = shift;
462 my $table = $self->_table(shift);
463 my $fields = shift || '*';
464 my $where = shift;
465 my $order = shift;
466
daa4ccdd 467 my ($fields_sql, @bind) = $self->_select_fields($fields);
96449e8e 468
daa4ccdd 469 my ($where_sql, @where_bind) = $self->where($where, $order);
470 push @bind, @where_bind;
471
472 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
96449e8e 473 $self->_sqlcase('from'), $table)
474 . $where_sql;
475
9d48860e 476 return wantarray ? ($sql, @bind) : $sql;
96449e8e 477}
478
daa4ccdd 479sub _select_fields {
480 my ($self, $fields) = @_;
481 return ref $fields eq 'ARRAY' ? join ', ', map { $self->_quote($_) } @$fields
482 : $fields;
483}
484
96449e8e 485#======================================================================
486# DELETE
487#======================================================================
488
489
490sub delete {
85327cd5 491 my $self = shift;
492 my $table = $self->_table(shift);
493 my $where = shift;
494 my $options = shift;
96449e8e 495
496 my($where_sql, @bind) = $self->where($where);
a9e94508 497 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
96449e8e 498
85327cd5 499 if ($options->{returning}) {
ca4f826a 500 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
85327cd5 501 $sql .= $returning_sql;
502 push @bind, @returning_bind;
503 }
504
9d48860e 505 return wantarray ? ($sql, @bind) : $sql;
96449e8e 506}
507
60f3fd3f 508# So that subclasses can override DELETE ... RETURNING separately from
509# INSERT and UPDATE
85327cd5 510sub _delete_returning { shift->_returning(@_) }
511
512
96449e8e 513
514#======================================================================
515# WHERE: entry point
516#======================================================================
517
518
519
520# Finally, a separate routine just to handle WHERE clauses
521sub where {
522 my ($self, $where, $order) = @_;
523
524 # where ?
525 my ($sql, @bind) = $self->_recurse_where($where);
417dd15e 526 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
96449e8e 527
528 # order by?
529 if ($order) {
26fe4d30 530 my ($order_sql, @order_bind) = $self->_order_by($order);
531 $sql .= $order_sql;
532 push @bind, @order_bind;
96449e8e 533 }
534
9d48860e 535 return wantarray ? ($sql, @bind) : $sql;
96449e8e 536}
537
a2cd381d 538sub _expand_expr {
539 my ($self, $expr, $logic) = @_;
59588695 540 if (ref($expr) eq 'HASH') {
541 if (keys %$expr > 1) {
542 $logic ||= 'and';
543 return +{ "-${logic}" => [
544 map $self->_expand_expr_hashpair($_ => $expr->{$_}, $logic),
545 sort keys %$expr
546 ] };
547 }
548 return $self->_expand_expr_hashpair(%$expr, $logic);
a2cd381d 549 }
550 return $expr;
551}
96449e8e 552
59588695 553sub _expand_expr_hashpair {
554 my ($self, $k, $v, $logic) = @_;
ef071fad 555 if ($k =~ /^-/) {
556 if ($k eq '-nest') {
557 return $self->_expand_expr($v);
558 }
559 } else {
560 if (!ref($v)) {
59588695 561 return +{ $k => { $self->{cmp} => $v } };
562 }
7dbe1183 563 if (ref($v) eq 'ARRAY') {
564 return $self->{sqlfalse} unless @$v;
565 $self->_debug("ARRAY($k) means distribute over elements");
566 my $this_logic = (
567 $v->[0] =~ /^-((?:and|or))$/i
568 ? ($v = [ @{$v}[1..$#$v] ], $1)
569 : ($self->{logic} || 'or')
570 );
571 return +{ "-${this_logic}" => [ map $self->_expand_expr({ $k => $_ }, $this_logic), @$v ] };
572 }
ef071fad 573 if (my $literal = is_literal_value($v)) {
574 unless (length $k) {
575 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
576 return \$literal;
577 }
578 my ($sql, @bind) = @$literal;
579 return \[ $self->_quote($k).' '.$sql, @bind ];
331e2209 580 }
331e2209 581 }
59588695 582 return { $k => $v };
583}
584
96449e8e 585sub _recurse_where {
586 my ($self, $where, $logic) = @_;
587
a2cd381d 588 my $where_exp = $self->_expand_expr($where, $logic);
589
96449e8e 590 # dispatch on appropriate method according to refkind of $where
a2cd381d 591 my $method = $self->_METHOD_FOR_refkind("_where", $where_exp);
311b2151 592
a2cd381d 593 my ($sql, @bind) = $self->$method($where_exp, $logic);
311b2151 594
abe1a491 595 # DBIx::Class used to call _recurse_where in scalar context
596 # something else might too...
597 if (wantarray) {
598 return ($sql, @bind);
599 }
600 else {
601 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
602 return $sql;
603 }
96449e8e 604}
605
606
607
608#======================================================================
609# WHERE: top-level ARRAYREF
610#======================================================================
611
612
613sub _where_ARRAYREF {
5e1d09d5 614 my ($self, $where, $logic) = @_;
96449e8e 615
5e1d09d5 616 $logic = uc($logic || $self->{logic});
96449e8e 617 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
618
619 my @clauses = @$where;
620
96449e8e 621 my (@sql_clauses, @all_bind);
96449e8e 622 # need to use while() so can shift() for pairs
b5a576d2 623 while (@clauses) {
624 my $el = shift @clauses;
625
626 $el = undef if (defined $el and ! length $el);
96449e8e 627
628 # switch according to kind of $el and get corresponding ($sql, @bind)
629 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
630
631 # skip empty elements, otherwise get invalid trailing AND stuff
632 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
633
c94a6c93 634 ARRAYREFREF => sub {
635 my ($s, @b) = @$$el;
636 $self->_assert_bindval_matches_bindtype(@b);
637 ($s, @b);
638 },
474e3335 639
96449e8e 640 HASHREF => sub {$self->_recurse_where($el, 'and') if %$el},
96449e8e 641
642 SCALARREF => sub { ($$el); },
643
b5a576d2 644 SCALAR => sub {
645 # top-level arrayref with scalars, recurse in pairs
646 $self->_recurse_where({$el => shift(@clauses)})
647 },
96449e8e 648
b5a576d2 649 UNDEF => sub {puke "Supplying an empty left hand side argument is not supported in array-pairs" },
96449e8e 650 });
651
4b7b6026 652 if ($sql) {
653 push @sql_clauses, $sql;
654 push @all_bind, @bind;
655 }
96449e8e 656 }
657
658 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
659}
660
474e3335 661#======================================================================
662# WHERE: top-level ARRAYREFREF
663#======================================================================
96449e8e 664
474e3335 665sub _where_ARRAYREFREF {
666 my ($self, $where) = @_;
c94a6c93 667 my ($sql, @bind) = @$$where;
668 $self->_assert_bindval_matches_bindtype(@bind);
474e3335 669 return ($sql, @bind);
670}
96449e8e 671
672#======================================================================
673# WHERE: top-level HASHREF
674#======================================================================
675
676sub _where_HASHREF {
677 my ($self, $where) = @_;
678 my (@sql_clauses, @all_bind);
679
2281c758 680 for my $k (sort keys %$where) {
96449e8e 681 my $v = $where->{$k};
682
2281c758 683 # ($k => $v) is either a special unary op or a regular hashpair
684 my ($sql, @bind) = do {
685 if ($k =~ /^-./) {
686 # put the operator in canonical form
687 my $op = $k;
b8db59b8 688 $op = substr $op, 1; # remove initial dash
2281c758 689 $op =~ s/^\s+|\s+$//g;# remove leading/trailing space
b8db59b8 690 $op =~ s/\s+/ /g; # compress whitespace
691
692 # so that -not_foo works correctly
693 $op =~ s/^not_/NOT /i;
2281c758 694
695 $self->_debug("Unary OP(-$op) within hashref, recursing...");
ca4f826a 696 my ($s, @b) = $self->_where_unary_op($op, $v);
0ec3aec7 697
698 # top level vs nested
699 # we assume that handled unary ops will take care of their ()s
700 $s = "($s)" unless (
701 List::Util::first {$op =~ $_->{regex}} @{$self->{unary_ops}}
702 or
923ce642 703 ( defined $self->{_nested_func_lhs} and $self->{_nested_func_lhs} eq $k )
0ec3aec7 704 );
705 ($s, @b);
2281c758 706 }
707 else {
b5a576d2 708 if (! length $k) {
709 if (is_literal_value ($v) ) {
710 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
711 }
712 else {
713 puke "Supplying an empty left hand side argument is not supported in hash-pairs";
714 }
715 }
716
2281c758 717 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
718 $self->$method($k, $v);
719 }
720 };
96449e8e 721
722 push @sql_clauses, $sql;
723 push @all_bind, @bind;
724 }
725
726 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
727}
728
0ec3aec7 729sub _where_unary_op {
2281c758 730 my ($self, $op, $rhs) = @_;
96449e8e 731
ddd6fbb6 732 # top level special ops are illegal in general
733 # this includes the -ident/-value ops (dual purpose unary and special)
734 puke "Illegal use of top-level '-$op'"
ca4f826a 735 if ! defined $self->{_nested_func_lhs} and List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
ddd6fbb6 736
ca4f826a 737 if (my $op_entry = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
0ec3aec7 738 my $handler = $op_entry->{handler};
739
740 if (not ref $handler) {
741 if ($op =~ s/ [_\s]? \d+ $//x ) {
742 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
743 . "You probably wanted ...-and => [ -$op => COND1, -$op => COND2 ... ]";
744 }
ca4f826a 745 return $self->$handler($op, $rhs);
0ec3aec7 746 }
747 elsif (ref $handler eq 'CODE') {
748 return $handler->($self, $op, $rhs);
749 }
750 else {
751 puke "Illegal handler for operator $op - expecting a method name or a coderef";
752 }
753 }
754
3d86e3b1 755 $self->_debug("Generic unary OP: $op - recursing as function");
0ec3aec7 756
170e6c33 757 $self->_assert_pass_injection_guard($op);
b6251592 758
ca4f826a 759 my ($sql, @bind) = $self->_SWITCH_refkind($rhs, {
2281c758 760 SCALAR => sub {
ddd6fbb6 761 puke "Illegal use of top-level '-$op'"
923ce642 762 unless defined $self->{_nested_func_lhs};
a7661cfc 763
764 return (
765 $self->_convert('?'),
766 $self->_bindtype($self->{_nested_func_lhs}, $rhs)
767 );
2281c758 768 },
769 FALLBACK => sub {
ca4f826a 770 $self->_recurse_where($rhs)
2281c758 771 },
772 });
96449e8e 773
ca4f826a 774 $sql = sprintf('%s %s',
2281c758 775 $self->_sqlcase($op),
953d164e 776 $sql,
2281c758 777 );
96449e8e 778
2281c758 779 return ($sql, @bind);
97a920ef 780}
781
782sub _where_op_ANDOR {
2281c758 783 my ($self, $op, $v) = @_;
97a920ef 784
785 $self->_SWITCH_refkind($v, {
786 ARRAYREF => sub {
787 return $self->_where_ARRAYREF($v, $op);
788 },
789
790 HASHREF => sub {
ca4f826a 791 return ($op =~ /^or/i)
792 ? $self->_where_ARRAYREF([ map { $_ => $v->{$_} } (sort keys %$v) ], $op)
97a920ef 793 : $self->_where_HASHREF($v);
794 },
795
9d48860e 796 SCALARREF => sub {
48d9f5f8 797 puke "-$op => \\\$scalar makes little sense, use " .
a0d6d323 798 ($op =~ /^or/i
48d9f5f8 799 ? '[ \$scalar, \%rest_of_conditions ] instead'
800 : '-and => [ \$scalar, \%rest_of_conditions ] instead'
801 );
97a920ef 802 },
803
804 ARRAYREFREF => sub {
48d9f5f8 805 puke "-$op => \\[...] makes little sense, use " .
a0d6d323 806 ($op =~ /^or/i
48d9f5f8 807 ? '[ \[...], \%rest_of_conditions ] instead'
808 : '-and => [ \[...], \%rest_of_conditions ] instead'
809 );
97a920ef 810 },
811
812 SCALAR => sub { # permissively interpreted as SQL
48d9f5f8 813 puke "-$op => \$value makes little sense, use -bool => \$value instead";
97a920ef 814 },
815
816 UNDEF => sub {
817 puke "-$op => undef not supported";
818 },
819 });
820}
821
822sub _where_op_NEST {
9d48860e 823 my ($self, $op, $v) = @_;
97a920ef 824
96449e8e 825 $self->_SWITCH_refkind($v, {
826
96449e8e 827 SCALAR => sub { # permissively interpreted as SQL
01a01e57 828 belch "literal SQL should be -nest => \\'scalar' "
829 . "instead of -nest => 'scalar' ";
9d48860e 830 return ($v);
96449e8e 831 },
832
833 UNDEF => sub {
834 puke "-$op => undef not supported";
835 },
e9501094 836
837 FALLBACK => sub {
ca4f826a 838 $self->_recurse_where($v);
e9501094 839 },
840
96449e8e 841 });
842}
843
844
97a920ef 845sub _where_op_BOOL {
9d48860e 846 my ($self, $op, $v) = @_;
97a920ef 847
b8db59b8 848 my ($s, @b) = $self->_SWITCH_refkind($v, {
849 SCALAR => sub { # interpreted as SQL column
850 $self->_convert($self->_quote($v));
851 },
ef03f1bc 852
b8db59b8 853 UNDEF => sub {
854 puke "-$op => undef not supported";
855 },
97a920ef 856
b8db59b8 857 FALLBACK => sub {
ca4f826a 858 $self->_recurse_where($v);
b8db59b8 859 },
860 });
ef03f1bc 861
b8db59b8 862 $s = "(NOT $s)" if $op =~ /^not/i;
863 ($s, @b);
97a920ef 864}
865
866
cc422895 867sub _where_op_IDENT {
868 my $self = shift;
869 my ($op, $rhs) = splice @_, -2;
8aa76984 870 if (! defined $rhs or length ref $rhs) {
871 puke "-$op requires a single plain scalar argument (a quotable identifier)";
cc422895 872 }
873
874 # in case we are called as a top level special op (no '=')
875 my $lhs = shift;
876
877 $_ = $self->_convert($self->_quote($_)) for ($lhs, $rhs);
878
879 return $lhs
880 ? "$lhs = $rhs"
881 : $rhs
882 ;
883}
884
885sub _where_op_VALUE {
886 my $self = shift;
887 my ($op, $rhs) = splice @_, -2;
888
889 # in case we are called as a top level special op (no '=')
890 my $lhs = shift;
891
422ed2de 892 # special-case NULL
893 if (! defined $rhs) {
923ce642 894 return defined $lhs
b4fd1bf5 895 ? $self->_where_hashpair_HASHREF($lhs, { -is => undef })
422ed2de 896 : undef
897 ;
898 }
899
cc422895 900 my @bind =
ca4f826a 901 $self->_bindtype(
902 (defined $lhs ? $lhs : $self->{_nested_func_lhs}),
cc422895 903 $rhs,
904 )
905 ;
906
907 return $lhs
908 ? (
909 $self->_convert($self->_quote($lhs)) . ' = ' . $self->_convert('?'),
910 @bind
911 )
912 : (
913 $self->_convert('?'),
914 @bind,
915 )
916 ;
917}
918
96449e8e 919sub _where_hashpair_ARRAYREF {
920 my ($self, $k, $v) = @_;
921
ca4f826a 922 if (@$v) {
96449e8e 923 my @v = @$v; # need copy because of shift below
924 $self->_debug("ARRAY($k) means distribute over elements");
925
926 # put apart first element if it is an operator (-and, -or)
e3cecb45 927 my $op = (
928 (defined $v[0] && $v[0] =~ /^ - (?: AND|OR ) $/ix)
929 ? shift @v
930 : ''
04d940de 931 );
96449e8e 932 my @distributed = map { {$k => $_} } @v;
04d940de 933
934 if ($op) {
935 $self->_debug("OP($op) reinjected into the distributed array");
936 unshift @distributed, $op;
937 }
938
f67591bf 939 my $logic = $op ? substr($op, 1) : '';
96449e8e 940
f67591bf 941 return $self->_recurse_where(\@distributed, $logic);
9d48860e 942 }
96449e8e 943 else {
96449e8e 944 $self->_debug("empty ARRAY($k) means 0=1");
945 return ($self->{sqlfalse});
946 }
947}
948
949sub _where_hashpair_HASHREF {
eb49170d 950 my ($self, $k, $v, $logic) = @_;
951 $logic ||= 'and';
96449e8e 952
923ce642 953 local $self->{_nested_func_lhs} = defined $self->{_nested_func_lhs}
954 ? $self->{_nested_func_lhs}
955 : $k
956 ;
a7661cfc 957
eb49170d 958 my ($all_sql, @all_bind);
96449e8e 959
a47b433a 960 for my $orig_op (sort keys %$v) {
961 my $val = $v->{$orig_op};
96449e8e 962
963 # put the operator in canonical form
a47b433a 964 my $op = $orig_op;
b8db59b8 965
966 # FIXME - we need to phase out dash-less ops
967 $op =~ s/^-//; # remove possible initial dash
a47b433a 968 $op =~ s/^\s+|\s+$//g;# remove leading/trailing space
b8db59b8 969 $op =~ s/\s+/ /g; # compress whitespace
970
170e6c33 971 $self->_assert_pass_injection_guard($op);
b6251592 972
b9b5a0b1 973 # fixup is_not
974 $op =~ s/^is_not/IS NOT/i;
975
b8db59b8 976 # so that -not_foo works correctly
977 $op =~ s/^not_/NOT /i;
96449e8e 978
422ed2de 979 # another retarded special case: foo => { $op => { -value => undef } }
980 if (ref $val eq 'HASH' and keys %$val == 1 and exists $val->{-value} and ! defined $val->{-value} ) {
981 $val = undef;
982 }
983
96449e8e 984 my ($sql, @bind);
985
2281c758 986 # CASE: col-value logic modifiers
ca4f826a 987 if ($orig_op =~ /^ \- (and|or) $/xi) {
2281c758 988 ($sql, @bind) = $self->_where_hashpair_HASHREF($k, $val, $1);
989 }
96449e8e 990 # CASE: special operators like -in or -between
ca4f826a 991 elsif (my $special_op = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
3a2e1a5e 992 my $handler = $special_op->{handler};
993 if (! $handler) {
a47b433a 994 puke "No handler supplied for special operator $orig_op";
3a2e1a5e 995 }
996 elsif (not ref $handler) {
ca4f826a 997 ($sql, @bind) = $self->$handler($k, $op, $val);
3a2e1a5e 998 }
999 elsif (ref $handler eq 'CODE') {
1000 ($sql, @bind) = $handler->($self, $k, $op, $val);
1001 }
1002 else {
a47b433a 1003 puke "Illegal handler for special operator $orig_op - expecting a method name or a coderef";
3a2e1a5e 1004 }
96449e8e 1005 }
96449e8e 1006 else {
cf838930 1007 $self->_SWITCH_refkind($val, {
1008
1009 ARRAYREF => sub { # CASE: col => {op => \@vals}
1010 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
1011 },
1012
fe3ae272 1013 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]} (literal SQL with bind)
b3be7bd0 1014 my ($sub_sql, @sub_bind) = @$$val;
fe3ae272 1015 $self->_assert_bindval_matches_bindtype(@sub_bind);
b3be7bd0 1016 $sql = join ' ', $self->_convert($self->_quote($k)),
1017 $self->_sqlcase($op),
1018 $sub_sql;
fe3ae272 1019 @bind = @sub_bind;
b3be7bd0 1020 },
1021
cf838930 1022 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
3cdadcbe 1023 my $is =
40f2f231 1024 $op =~ /^not$/i ? 'is not' # legacy
1025 : $op =~ $self->{equality_op} ? 'is'
3cdadcbe 1026 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
1027 : $op =~ $self->{inequality_op} ? 'is not'
1028 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
1029 : puke "unexpected operator '$orig_op' with undef operand";
1030
cf838930 1031 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
1032 },
a47b433a 1033
2281c758 1034 FALLBACK => sub { # CASE: col => {op/func => $stuff}
ca4f826a 1035 ($sql, @bind) = $self->_where_unary_op($op, $val);
953d164e 1036
ca4f826a 1037 $sql = join(' ',
953d164e 1038 $self->_convert($self->_quote($k)),
1039 $self->{_nested_func_lhs} eq $k ? $sql : "($sql)", # top level vs nested
1040 );
cf838930 1041 },
1042 });
96449e8e 1043 }
1044
eb49170d 1045 ($all_sql) = (defined $all_sql and $all_sql) ? $self->_join_sql_clauses($logic, [$all_sql, $sql], []) : $sql;
96449e8e 1046 push @all_bind, @bind;
1047 }
eb49170d 1048 return ($all_sql, @all_bind);
96449e8e 1049}
1050
b9b5a0b1 1051sub _where_field_IS {
1052 my ($self, $k, $op, $v) = @_;
1053
1054 my ($s) = $self->_SWITCH_refkind($v, {
1055 UNDEF => sub {
1056 join ' ',
1057 $self->_convert($self->_quote($k)),
1058 map { $self->_sqlcase($_)} ($op, 'null')
1059 },
1060 FALLBACK => sub {
1061 puke "$op can only take undef as argument";
1062 },
1063 });
96449e8e 1064
b9b5a0b1 1065 $s;
1066}
96449e8e 1067
1068sub _where_field_op_ARRAYREF {
1069 my ($self, $k, $op, $vals) = @_;
1070
ce261791 1071 my @vals = @$vals; #always work on a copy
1072
ca4f826a 1073 if (@vals) {
bd6a65ca 1074 $self->_debug(sprintf '%s means multiple elements: [ %s ]',
1075 $vals,
ca4f826a 1076 join(', ', map { defined $_ ? "'$_'" : 'NULL' } @vals ),
bd6a65ca 1077 );
96449e8e 1078
4030915f 1079 # see if the first element is an -and/-or op
1080 my $logic;
ca4f826a 1081 if (defined $vals[0] && $vals[0] =~ /^ - (AND|OR) $/ix) {
4030915f 1082 $logic = uc $1;
ce261791 1083 shift @vals;
4030915f 1084 }
1085
3cdadcbe 1086 # a long standing API wart - an attempt to change this behavior during
1087 # the 1.50 series failed *spectacularly*. Warn instead and leave the
1088 # behavior as is
1089 if (
1090 @vals > 1
1091 and
1092 (!$logic or $logic eq 'OR')
1093 and
ca4f826a 1094 ($op =~ $self->{inequality_op} or $op =~ $self->{not_like_op})
3cdadcbe 1095 ) {
1096 my $o = uc($op);
1097 belch "A multi-element arrayref as an argument to the inequality op '$o' "
1098 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
1099 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
1100 ;
1101 }
1102
ce261791 1103 # distribute $op over each remaining member of @vals, append logic if exists
1104 return $self->_recurse_where([map { {$k => {$op, $_}} } @vals], $logic);
4030915f 1105
9d48860e 1106 }
96449e8e 1107 else {
9d48860e 1108 # try to DWIM on equality operators
3cdadcbe 1109 return
1110 $op =~ $self->{equality_op} ? $self->{sqlfalse}
1111 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->{sqlfalse}
1112 : $op =~ $self->{inequality_op} ? $self->{sqltrue}
1113 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->{sqltrue}
1114 : puke "operator '$op' applied on an empty array (field '$k')";
96449e8e 1115 }
1116}
1117
1118
1119sub _where_hashpair_SCALARREF {
1120 my ($self, $k, $v) = @_;
1121 $self->_debug("SCALAR($k) means literal SQL: $$v");
1122 my $sql = $self->_quote($k) . " " . $$v;
1123 return ($sql);
1124}
1125
fe3ae272 1126# literal SQL with bind
96449e8e 1127sub _where_hashpair_ARRAYREFREF {
1128 my ($self, $k, $v) = @_;
1129 $self->_debug("REF($k) means literal SQL: @${$v}");
c94a6c93 1130 my ($sql, @bind) = @$$v;
fe3ae272 1131 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 1132 $sql = $self->_quote($k) . " " . $sql;
96449e8e 1133 return ($sql, @bind );
1134}
1135
fe3ae272 1136# literal SQL without bind
96449e8e 1137sub _where_hashpair_SCALAR {
1138 my ($self, $k, $v) = @_;
1139 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
e4c43404 1140 return ($self->_where_hashpair_HASHREF($k, { $self->{cmp} => $v }));
96449e8e 1141}
1142
1143
1144sub _where_hashpair_UNDEF {
1145 my ($self, $k, $v) = @_;
1146 $self->_debug("UNDEF($k) means IS NULL");
5a859976 1147 return $self->_where_hashpair_HASHREF($k, { -is => undef });
96449e8e 1148}
1149
1150#======================================================================
1151# WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
1152#======================================================================
1153
1154
1155sub _where_SCALARREF {
1156 my ($self, $where) = @_;
1157
1158 # literal sql
1159 $self->_debug("SCALAR(*top) means literal SQL: $$where");
1160 return ($$where);
1161}
1162
1163
1164sub _where_SCALAR {
1165 my ($self, $where) = @_;
1166
1167 # literal sql
1168 $self->_debug("NOREF(*top) means literal SQL: $where");
1169 return ($where);
1170}
1171
1172
1173sub _where_UNDEF {
1174 my ($self) = @_;
1175 return ();
1176}
1177
1178
1179#======================================================================
1180# WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
1181#======================================================================
1182
1183
1184sub _where_field_BETWEEN {
1185 my ($self, $k, $op, $vals) = @_;
1186
4d8b3dc4 1187 my ($label, $and, $placeholder);
cf02fc47 1188 $label = $self->_convert($self->_quote($k));
1189 $and = ' ' . $self->_sqlcase('and') . ' ';
1190 $placeholder = $self->_convert('?');
96449e8e 1191 $op = $self->_sqlcase($op);
1192
7f54040f 1193 my $invalid_args = "Operator '$op' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
1194
4d8b3dc4 1195 my ($clause, @bind) = $self->_SWITCH_refkind($vals, {
1196 ARRAYREFREF => sub {
c94a6c93 1197 my ($s, @b) = @$$vals;
1198 $self->_assert_bindval_matches_bindtype(@b);
1199 ($s, @b);
4d8b3dc4 1200 },
1201 SCALARREF => sub {
1202 return $$vals;
1203 },
1204 ARRAYREF => sub {
7f54040f 1205 puke $invalid_args if @$vals != 2;
4d8b3dc4 1206
1207 my (@all_sql, @all_bind);
1208 foreach my $val (@$vals) {
1209 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
1210 SCALAR => sub {
5e5cbf51 1211 return ($placeholder, $self->_bindtype($k, $val) );
4d8b3dc4 1212 },
1213 SCALARREF => sub {
0336eddb 1214 return $$val;
4d8b3dc4 1215 },
1216 ARRAYREFREF => sub {
1217 my ($sql, @bind) = @$$val;
c94a6c93 1218 $self->_assert_bindval_matches_bindtype(@bind);
0336eddb 1219 return ($sql, @bind);
4d8b3dc4 1220 },
0336eddb 1221 HASHREF => sub {
1222 my ($func, $arg, @rest) = %$val;
0e49a487 1223 puke "Only simple { -func => arg } functions accepted as sub-arguments to BETWEEN"
0336eddb 1224 if (@rest or $func !~ /^ \- (.+)/x);
ca4f826a 1225 $self->_where_unary_op($1 => $arg);
7f54040f 1226 },
1227 FALLBACK => sub {
1228 puke $invalid_args,
1229 },
4d8b3dc4 1230 });
1231 push @all_sql, $sql;
1232 push @all_bind, @bind;
1233 }
1234
1235 return (
1236 (join $and, @all_sql),
5e5cbf51 1237 @all_bind
4d8b3dc4 1238 );
1239 },
1240 FALLBACK => sub {
7f54040f 1241 puke $invalid_args,
4d8b3dc4 1242 },
1243 });
cf02fc47 1244
cf02fc47 1245 my $sql = "( $label $op $clause )";
96449e8e 1246 return ($sql, @bind)
1247}
1248
1249
1250sub _where_field_IN {
1251 my ($self, $k, $op, $vals) = @_;
1252
be21dde3 1253 # backwards compatibility: if scalar, force into an arrayref
96449e8e 1254 $vals = [$vals] if defined $vals && ! ref $vals;
1255
96449e8e 1256 my ($label) = $self->_convert($self->_quote($k));
1257 my ($placeholder) = $self->_convert('?');
96449e8e 1258 $op = $self->_sqlcase($op);
1259
8a0d798a 1260 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
1261 ARRAYREF => sub { # list of choices
1262 if (@$vals) { # nonempty list
0336eddb 1263 my (@all_sql, @all_bind);
1264
1265 for my $val (@$vals) {
1266 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
1267 SCALAR => sub {
1268 return ($placeholder, $val);
1269 },
1270 SCALARREF => sub {
1271 return $$val;
1272 },
1273 ARRAYREFREF => sub {
1274 my ($sql, @bind) = @$$val;
1275 $self->_assert_bindval_matches_bindtype(@bind);
1276 return ($sql, @bind);
1277 },
1278 HASHREF => sub {
1279 my ($func, $arg, @rest) = %$val;
0e49a487 1280 puke "Only simple { -func => arg } functions accepted as sub-arguments to IN"
0336eddb 1281 if (@rest or $func !~ /^ \- (.+)/x);
ca4f826a 1282 $self->_where_unary_op($1 => $arg);
279eb282 1283 },
1284 UNDEF => sub {
032dfe20 1285 puke(
1286 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
1287 . "-$op operator was given an undef-containing list: !!!AUDIT YOUR CODE "
1288 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
1289 . 'will emit the logically correct SQL instead of raising this exception)'
1290 );
279eb282 1291 },
0336eddb 1292 });
1293 push @all_sql, $sql;
1294 push @all_bind, @bind;
1295 }
96449e8e 1296
88a89939 1297 return (
ca4f826a 1298 sprintf('%s %s ( %s )',
88a89939 1299 $label,
1300 $op,
ca4f826a 1301 join(', ', @all_sql)
88a89939 1302 ),
1303 $self->_bindtype($k, @all_bind),
0336eddb 1304 );
8a0d798a 1305 }
be21dde3 1306 else { # empty list: some databases won't understand "IN ()", so DWIM
8a0d798a 1307 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
1308 return ($sql);
1309 }
1310 },
1311
4a1f01a3 1312 SCALARREF => sub { # literal SQL
ca4f826a 1313 my $sql = $self->_open_outer_paren($$vals);
4a1f01a3 1314 return ("$label $op ( $sql )");
1315 },
8a0d798a 1316 ARRAYREFREF => sub { # literal SQL with bind
1317 my ($sql, @bind) = @$$vals;
fe3ae272 1318 $self->_assert_bindval_matches_bindtype(@bind);
ca4f826a 1319 $sql = $self->_open_outer_paren($sql);
8a0d798a 1320 return ("$label $op ( $sql )", @bind);
1321 },
1322
ff8ca6b4 1323 UNDEF => sub {
1324 puke "Argument passed to the '$op' operator can not be undefined";
1325 },
1326
8a0d798a 1327 FALLBACK => sub {
ff8ca6b4 1328 puke "special op $op requires an arrayref (or scalarref/arrayref-ref)";
8a0d798a 1329 },
1330 });
1331
1332 return ($sql, @bind);
96449e8e 1333}
1334
4a1f01a3 1335# Some databases (SQLite) treat col IN (1, 2) different from
1336# col IN ( (1, 2) ). Use this to strip all outer parens while
1337# adding them back in the corresponding method
1338sub _open_outer_paren {
1339 my ($self, $sql) = @_;
a5f91feb 1340
ca4f826a 1341 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
a5f91feb 1342
1343 # there are closing parens inside, need the heavy duty machinery
1344 # to reevaluate the extraction starting from $sql (full reevaluation)
ca4f826a 1345 if ($inner =~ /\)/) {
a5f91feb 1346 require Text::Balanced;
1347
1348 my (undef, $remainder) = do {
1349 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1350 local $@;
ca4f826a 1351 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
a5f91feb 1352 };
1353
1354 # the entire expression needs to be a balanced bracketed thing
1355 # (after an extract no remainder sans trailing space)
1356 last if defined $remainder and $remainder =~ /\S/;
1357 }
1358
1359 $sql = $inner;
1360 }
1361
1362 $sql;
4a1f01a3 1363}
1364
96449e8e 1365
96449e8e 1366#======================================================================
1367# ORDER BY
1368#======================================================================
1369
1370sub _order_by {
1371 my ($self, $arg) = @_;
1372
f267b646 1373 my (@sql, @bind);
ca4f826a 1374 for my $c ($self->_order_by_chunks($arg) ) {
1375 $self->_SWITCH_refkind($c, {
f267b646 1376 SCALAR => sub { push @sql, $c },
1377 ARRAYREF => sub { push @sql, shift @$c; push @bind, @$c },
1378 });
1379 }
1380
1381 my $sql = @sql
ca4f826a 1382 ? sprintf('%s %s',
f267b646 1383 $self->_sqlcase(' order by'),
ca4f826a 1384 join(', ', @sql)
f267b646 1385 )
1386 : ''
1387 ;
1388
1389 return wantarray ? ($sql, @bind) : $sql;
1390}
1391
1392sub _order_by_chunks {
1393 my ($self, $arg) = @_;
1394
1395 return $self->_SWITCH_refkind($arg, {
96449e8e 1396
1397 ARRAYREF => sub {
ca4f826a 1398 map { $self->_order_by_chunks($_ ) } @$arg;
96449e8e 1399 },
1400
c94a6c93 1401 ARRAYREFREF => sub {
1402 my ($s, @b) = @$$arg;
1403 $self->_assert_bindval_matches_bindtype(@b);
1404 [ $s, @b ];
1405 },
f267b646 1406
96449e8e 1407 SCALAR => sub {$self->_quote($arg)},
f267b646 1408
1409 UNDEF => sub {return () },
1410
96449e8e 1411 SCALARREF => sub {$$arg}, # literal SQL, no quoting
96449e8e 1412
f267b646 1413 HASHREF => sub {
5e436130 1414 # get first pair in hash
1415 my ($key, $val, @rest) = %$arg;
1416
1417 return () unless $key;
1418
ca4f826a 1419 if (@rest or not $key =~ /^-(desc|asc)/i) {
5e436130 1420 puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
f267b646 1421 }
5e436130 1422
1423 my $direction = $1;
96449e8e 1424
e9bd3547 1425 my @ret;
ca4f826a 1426 for my $c ($self->_order_by_chunks($val)) {
e9bd3547 1427 my ($sql, @bind);
96449e8e 1428
ca4f826a 1429 $self->_SWITCH_refkind($c, {
f267b646 1430 SCALAR => sub {
e9bd3547 1431 $sql = $c;
f267b646 1432 },
1433 ARRAYREF => sub {
e9bd3547 1434 ($sql, @bind) = @$c;
f267b646 1435 },
1436 });
96449e8e 1437
5e436130 1438 $sql = $sql . ' ' . $self->_sqlcase($direction);
96449e8e 1439
e9bd3547 1440 push @ret, [ $sql, @bind];
1441 }
96449e8e 1442
e9bd3547 1443 return @ret;
f267b646 1444 },
1445 });
96449e8e 1446}
1447
1448
96449e8e 1449#======================================================================
1450# DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1451#======================================================================
1452
1453sub _table {
1454 my $self = shift;
1455 my $from = shift;
1456 $self->_SWITCH_refkind($from, {
1457 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
1458 SCALAR => sub {$self->_quote($from)},
1459 SCALARREF => sub {$$from},
96449e8e 1460 });
1461}
1462
1463
1464#======================================================================
1465# UTILITY FUNCTIONS
1466#======================================================================
1467
955e77ca 1468# highly optimized, as it's called way too often
96449e8e 1469sub _quote {
955e77ca 1470 # my ($self, $label) = @_;
96449e8e 1471
955e77ca 1472 return '' unless defined $_[1];
955e77ca 1473 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
96449e8e 1474
439834d3 1475 $_[0]->{quote_char} or
1476 ($_[0]->_assert_pass_injection_guard($_[1]), return $_[1]);
96449e8e 1477
07d7c35c 1478 my $qref = ref $_[0]->{quote_char};
439834d3 1479 my ($l, $r) =
1480 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1481 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1482 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1483
46be4313 1484 my $esc = $_[0]->{escape_char} || $r;
96449e8e 1485
07d7c35c 1486 # parts containing * are naturally unquoted
ca4f826a 1487 return join($_[0]->{name_sep}||'', map
439834d3 1488 +( $_ eq '*' ? $_ : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r } ),
955e77ca 1489 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
1490 );
96449e8e 1491}
1492
1493
1494# Conversion, if applicable
d7c862e0 1495sub _convert {
07d7c35c 1496 #my ($self, $arg) = @_;
07d7c35c 1497 if ($_[0]->{convert}) {
1498 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
96449e8e 1499 }
07d7c35c 1500 return $_[1];
96449e8e 1501}
1502
1503# And bindtype
d7c862e0 1504sub _bindtype {
07d7c35c 1505 #my ($self, $col, @vals) = @_;
07d7c35c 1506 # called often - tighten code
1507 return $_[0]->{bindtype} eq 'columns'
1508 ? map {[$_[1], $_]} @_[2 .. $#_]
1509 : @_[2 .. $#_]
1510 ;
96449e8e 1511}
1512
fe3ae272 1513# Dies if any element of @bind is not in [colname => value] format
1514# if bindtype is 'columns'.
1515sub _assert_bindval_matches_bindtype {
c94a6c93 1516# my ($self, @bind) = @_;
1517 my $self = shift;
fe3ae272 1518 if ($self->{bindtype} eq 'columns') {
c94a6c93 1519 for (@_) {
1520 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
3a06278c 1521 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
fe3ae272 1522 }
1523 }
1524 }
1525}
1526
96449e8e 1527sub _join_sql_clauses {
1528 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1529
1530 if (@$clauses_aref > 1) {
1531 my $join = " " . $self->_sqlcase($logic) . " ";
1532 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1533 return ($sql, @$bind_aref);
1534 }
1535 elsif (@$clauses_aref) {
1536 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1537 }
1538 else {
1539 return (); # if no SQL, ignore @$bind_aref
1540 }
1541}
1542
1543
1544# Fix SQL case, if so requested
1545sub _sqlcase {
96449e8e 1546 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1547 # don't touch the argument ... crooked logic, but let's not change it!
07d7c35c 1548 return $_[0]->{case} ? $_[1] : uc($_[1]);
96449e8e 1549}
1550
1551
1552#======================================================================
1553# DISPATCHING FROM REFKIND
1554#======================================================================
1555
1556sub _refkind {
1557 my ($self, $data) = @_;
96449e8e 1558
955e77ca 1559 return 'UNDEF' unless defined $data;
1560
1561 # blessed objects are treated like scalars
1562 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1563
1564 return 'SCALAR' unless $ref;
1565
1566 my $n_steps = 1;
1567 while ($ref eq 'REF') {
96449e8e 1568 $data = $$data;
955e77ca 1569 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1570 $n_steps++ if $ref;
96449e8e 1571 }
1572
848556bc 1573 return ($ref||'SCALAR') . ('REF' x $n_steps);
96449e8e 1574}
1575
1576sub _try_refkind {
1577 my ($self, $data) = @_;
1578 my @try = ($self->_refkind($data));
1579 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1580 push @try, 'FALLBACK';
955e77ca 1581 return \@try;
96449e8e 1582}
1583
1584sub _METHOD_FOR_refkind {
1585 my ($self, $meth_prefix, $data) = @_;
f39eaa60 1586
1587 my $method;
955e77ca 1588 for (@{$self->_try_refkind($data)}) {
f39eaa60 1589 $method = $self->can($meth_prefix."_".$_)
1590 and last;
1591 }
1592
1593 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
96449e8e 1594}
1595
1596
1597sub _SWITCH_refkind {
1598 my ($self, $data, $dispatch_table) = @_;
1599
f39eaa60 1600 my $coderef;
955e77ca 1601 for (@{$self->_try_refkind($data)}) {
f39eaa60 1602 $coderef = $dispatch_table->{$_}
1603 and last;
1604 }
1605
1606 puke "no dispatch entry for ".$self->_refkind($data)
1607 unless $coderef;
1608
96449e8e 1609 $coderef->();
1610}
1611
1612
1613
1614
1615#======================================================================
1616# VALUES, GENERATE, AUTOLOAD
1617#======================================================================
1618
1619# LDNOTE: original code from nwiger, didn't touch code in that section
1620# I feel the AUTOLOAD stuff should not be the default, it should
1621# only be activated on explicit demand by user.
1622
1623sub values {
1624 my $self = shift;
1625 my $data = shift || return;
1626 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1627 unless ref $data eq 'HASH';
bab725ce 1628
1629 my @all_bind;
ca4f826a 1630 foreach my $k (sort keys %$data) {
bab725ce 1631 my $v = $data->{$k};
1632 $self->_SWITCH_refkind($v, {
9d48860e 1633 ARRAYREF => sub {
bab725ce 1634 if ($self->{array_datatypes}) { # array datatype
1635 push @all_bind, $self->_bindtype($k, $v);
1636 }
1637 else { # literal SQL with bind
1638 my ($sql, @bind) = @$v;
1639 $self->_assert_bindval_matches_bindtype(@bind);
1640 push @all_bind, @bind;
1641 }
1642 },
1643 ARRAYREFREF => sub { # literal SQL with bind
1644 my ($sql, @bind) = @${$v};
1645 $self->_assert_bindval_matches_bindtype(@bind);
1646 push @all_bind, @bind;
1647 },
1648 SCALARREF => sub { # literal SQL without bind
1649 },
1650 SCALAR_or_UNDEF => sub {
1651 push @all_bind, $self->_bindtype($k, $v);
1652 },
1653 });
1654 }
1655
1656 return @all_bind;
96449e8e 1657}
1658
1659sub generate {
1660 my $self = shift;
1661
1662 my(@sql, @sqlq, @sqlv);
1663
1664 for (@_) {
1665 my $ref = ref $_;
1666 if ($ref eq 'HASH') {
1667 for my $k (sort keys %$_) {
1668 my $v = $_->{$k};
1669 my $r = ref $v;
1670 my $label = $self->_quote($k);
1671 if ($r eq 'ARRAY') {
fe3ae272 1672 # literal SQL with bind
1673 my ($sql, @bind) = @$v;
1674 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 1675 push @sqlq, "$label = $sql";
fe3ae272 1676 push @sqlv, @bind;
96449e8e 1677 } elsif ($r eq 'SCALAR') {
fe3ae272 1678 # literal SQL without bind
96449e8e 1679 push @sqlq, "$label = $$v";
9d48860e 1680 } else {
96449e8e 1681 push @sqlq, "$label = ?";
1682 push @sqlv, $self->_bindtype($k, $v);
1683 }
1684 }
1685 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1686 } elsif ($ref eq 'ARRAY') {
1687 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1688 for my $v (@$_) {
1689 my $r = ref $v;
fe3ae272 1690 if ($r eq 'ARRAY') { # literal SQL with bind
1691 my ($sql, @bind) = @$v;
1692 $self->_assert_bindval_matches_bindtype(@bind);
1693 push @sqlq, $sql;
1694 push @sqlv, @bind;
1695 } elsif ($r eq 'SCALAR') { # literal SQL without bind
96449e8e 1696 # embedded literal SQL
1697 push @sqlq, $$v;
9d48860e 1698 } else {
96449e8e 1699 push @sqlq, '?';
1700 push @sqlv, $v;
1701 }
1702 }
1703 push @sql, '(' . join(', ', @sqlq) . ')';
1704 } elsif ($ref eq 'SCALAR') {
1705 # literal SQL
1706 push @sql, $$_;
1707 } else {
1708 # strings get case twiddled
1709 push @sql, $self->_sqlcase($_);
1710 }
1711 }
1712
1713 my $sql = join ' ', @sql;
1714
1715 # this is pretty tricky
1716 # if ask for an array, return ($stmt, @bind)
1717 # otherwise, s/?/shift @sqlv/ to put it inline
1718 if (wantarray) {
1719 return ($sql, @sqlv);
1720 } else {
1721 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1722 ref $d ? $d->[1] : $d/e;
1723 return $sql;
1724 }
1725}
1726
1727
1728sub DESTROY { 1 }
1729
1730sub AUTOLOAD {
1731 # This allows us to check for a local, then _form, attr
1732 my $self = shift;
1733 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1734 return $self->generate($name, @_);
1735}
1736
17371;
1738
1739
1740
1741__END__
32eab2da 1742
1743=head1 NAME
1744
1745SQL::Abstract - Generate SQL from Perl data structures
1746
1747=head1 SYNOPSIS
1748
1749 use SQL::Abstract;
1750
1751 my $sql = SQL::Abstract->new;
1752
85783f3c 1753 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
32eab2da 1754
1755 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1756
1757 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1758
1759 my($stmt, @bind) = $sql->delete($table, \%where);
1760
1761 # Then, use these in your DBI statements
1762 my $sth = $dbh->prepare($stmt);
1763 $sth->execute(@bind);
1764
1765 # Just generate the WHERE clause
85783f3c 1766 my($stmt, @bind) = $sql->where(\%where, $order);
32eab2da 1767
1768 # Return values in the same order, for hashed queries
1769 # See PERFORMANCE section for more details
1770 my @bind = $sql->values(\%fieldvals);
1771
1772=head1 DESCRIPTION
1773
1774This module was inspired by the excellent L<DBIx::Abstract>.
1775However, in using that module I found that what I really wanted
1776to do was generate SQL, but still retain complete control over my
1777statement handles and use the DBI interface. So, I set out to
1778create an abstract SQL generation module.
1779
1780While based on the concepts used by L<DBIx::Abstract>, there are
1781several important differences, especially when it comes to WHERE
1782clauses. I have modified the concepts used to make the SQL easier
1783to generate from Perl data structures and, IMO, more intuitive.
1784The underlying idea is for this module to do what you mean, based
1785on the data structures you provide it. The big advantage is that
1786you don't have to modify your code every time your data changes,
1787as this module figures it out.
1788
1789To begin with, an SQL INSERT is as easy as just specifying a hash
1790of C<key=value> pairs:
1791
1792 my %data = (
1793 name => 'Jimbo Bobson',
1794 phone => '123-456-7890',
1795 address => '42 Sister Lane',
1796 city => 'St. Louis',
1797 state => 'Louisiana',
1798 );
1799
1800The SQL can then be generated with this:
1801
1802 my($stmt, @bind) = $sql->insert('people', \%data);
1803
1804Which would give you something like this:
1805
1806 $stmt = "INSERT INTO people
1807 (address, city, name, phone, state)
1808 VALUES (?, ?, ?, ?, ?)";
1809 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1810 '123-456-7890', 'Louisiana');
1811
1812These are then used directly in your DBI code:
1813
1814 my $sth = $dbh->prepare($stmt);
1815 $sth->execute(@bind);
1816
96449e8e 1817=head2 Inserting and Updating Arrays
1818
1819If your database has array types (like for example Postgres),
1820activate the special option C<< array_datatypes => 1 >>
9d48860e 1821when creating the C<SQL::Abstract> object.
96449e8e 1822Then you may use an arrayref to insert and update database array types:
1823
1824 my $sql = SQL::Abstract->new(array_datatypes => 1);
1825 my %data = (
1826 planets => [qw/Mercury Venus Earth Mars/]
1827 );
9d48860e 1828
96449e8e 1829 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1830
1831This results in:
1832
1833 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1834
1835 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1836
1837
1838=head2 Inserting and Updating SQL
1839
1840In order to apply SQL functions to elements of your C<%data> you may
1841specify a reference to an arrayref for the given hash value. For example,
1842if you need to execute the Oracle C<to_date> function on a value, you can
1843say something like this:
32eab2da 1844
1845 my %data = (
1846 name => 'Bill',
3ae1c5e2 1847 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
9d48860e 1848 );
32eab2da 1849
1850The first value in the array is the actual SQL. Any other values are
1851optional and would be included in the bind values array. This gives
1852you:
1853
1854 my($stmt, @bind) = $sql->insert('people', \%data);
1855
9d48860e 1856 $stmt = "INSERT INTO people (name, date_entered)
32eab2da 1857 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1858 @bind = ('Bill', '03/02/2003');
1859
1860An UPDATE is just as easy, all you change is the name of the function:
1861
1862 my($stmt, @bind) = $sql->update('people', \%data);
1863
1864Notice that your C<%data> isn't touched; the module will generate
1865the appropriately quirky SQL for you automatically. Usually you'll
1866want to specify a WHERE clause for your UPDATE, though, which is
1867where handling C<%where> hashes comes in handy...
1868
96449e8e 1869=head2 Complex where statements
1870
32eab2da 1871This module can generate pretty complicated WHERE statements
1872easily. For example, simple C<key=value> pairs are taken to mean
1873equality, and if you want to see if a field is within a set
1874of values, you can use an arrayref. Let's say we wanted to
1875SELECT some data based on this criteria:
1876
1877 my %where = (
1878 requestor => 'inna',
1879 worker => ['nwiger', 'rcwe', 'sfz'],
1880 status => { '!=', 'completed' }
1881 );
1882
1883 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1884
1885The above would give you something like this:
1886
1887 $stmt = "SELECT * FROM tickets WHERE
1888 ( requestor = ? ) AND ( status != ? )
1889 AND ( worker = ? OR worker = ? OR worker = ? )";
1890 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1891
1892Which you could then use in DBI code like so:
1893
1894 my $sth = $dbh->prepare($stmt);
1895 $sth->execute(@bind);
1896
1897Easy, eh?
1898
0da0fe34 1899=head1 METHODS
32eab2da 1900
13cc86af 1901The methods are simple. There's one for every major SQL operation,
32eab2da 1902and a constructor you use first. The arguments are specified in a
13cc86af 1903similar order for each method (table, then fields, then a where
32eab2da 1904clause) to try and simplify things.
1905
32eab2da 1906=head2 new(option => 'value')
1907
1908The C<new()> function takes a list of options and values, and returns
1909a new B<SQL::Abstract> object which can then be used to generate SQL
1910through the methods below. The options accepted are:
1911
1912=over
1913
1914=item case
1915
1916If set to 'lower', then SQL will be generated in all lowercase. By
1917default SQL is generated in "textbook" case meaning something like:
1918
1919 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1920
96449e8e 1921Any setting other than 'lower' is ignored.
1922
32eab2da 1923=item cmp
1924
1925This determines what the default comparison operator is. By default
1926it is C<=>, meaning that a hash like this:
1927
1928 %where = (name => 'nwiger', email => 'nate@wiger.org');
1929
1930Will generate SQL like this:
1931
1932 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1933
1934However, you may want loose comparisons by default, so if you set
1935C<cmp> to C<like> you would get SQL such as:
1936
1937 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1938
3af02ccb 1939You can also override the comparison on an individual basis - see
32eab2da 1940the huge section on L</"WHERE CLAUSES"> at the bottom.
1941
96449e8e 1942=item sqltrue, sqlfalse
1943
1944Expressions for inserting boolean values within SQL statements.
6e0c6552 1945By default these are C<1=1> and C<1=0>. They are used
1946by the special operators C<-in> and C<-not_in> for generating
1947correct SQL even when the argument is an empty array (see below).
96449e8e 1948
32eab2da 1949=item logic
1950
1951This determines the default logical operator for multiple WHERE
7cac25e6 1952statements in arrays or hashes. If absent, the default logic is "or"
1953for arrays, and "and" for hashes. This means that a WHERE
32eab2da 1954array of the form:
1955
1956 @where = (
9d48860e 1957 event_date => {'>=', '2/13/99'},
1958 event_date => {'<=', '4/24/03'},
32eab2da 1959 );
1960
7cac25e6 1961will generate SQL like this:
32eab2da 1962
1963 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1964
1965This is probably not what you want given this query, though (look
1966at the dates). To change the "OR" to an "AND", simply specify:
1967
1968 my $sql = SQL::Abstract->new(logic => 'and');
1969
1970Which will change the above C<WHERE> to:
1971
1972 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1973
96449e8e 1974The logic can also be changed locally by inserting
be21dde3 1975a modifier in front of an arrayref:
96449e8e 1976
9d48860e 1977 @where = (-and => [event_date => {'>=', '2/13/99'},
7cac25e6 1978 event_date => {'<=', '4/24/03'} ]);
96449e8e 1979
1980See the L</"WHERE CLAUSES"> section for explanations.
1981
32eab2da 1982=item convert
1983
1984This will automatically convert comparisons using the specified SQL
1985function for both column and value. This is mostly used with an argument
1986of C<upper> or C<lower>, so that the SQL will have the effect of
1987case-insensitive "searches". For example, this:
1988
1989 $sql = SQL::Abstract->new(convert => 'upper');
1990 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1991
1992Will turn out the following SQL:
1993
1994 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1995
1996The conversion can be C<upper()>, C<lower()>, or any other SQL function
1997that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1998not validate this option; it will just pass through what you specify verbatim).
1999
2000=item bindtype
2001
2002This is a kludge because many databases suck. For example, you can't
2003just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
2004Instead, you have to use C<bind_param()>:
2005
2006 $sth->bind_param(1, 'reg data');
2007 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
2008
2009The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
2010which loses track of which field each slot refers to. Fear not.
2011
2012If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
2013Currently, you can specify either C<normal> (default) or C<columns>. If you
2014specify C<columns>, you will get an array that looks like this:
2015
2016 my $sql = SQL::Abstract->new(bindtype => 'columns');
2017 my($stmt, @bind) = $sql->insert(...);
2018
2019 @bind = (
2020 [ 'column1', 'value1' ],
2021 [ 'column2', 'value2' ],
2022 [ 'column3', 'value3' ],
2023 );
2024
2025You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 2026
32eab2da 2027 $sth->prepare($stmt);
2028 my $i = 1;
2029 for (@bind) {
2030 my($col, $data) = @$_;
2031 if ($col eq 'details' || $col eq 'comments') {
2032 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
2033 } elsif ($col eq 'image') {
2034 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
2035 } else {
2036 $sth->bind_param($i, $data);
2037 }
2038 $i++;
2039 }
2040 $sth->execute; # execute without @bind now
2041
2042Now, why would you still use B<SQL::Abstract> if you have to do this crap?
2043Basically, the advantage is still that you don't have to care which fields
2044are or are not included. You could wrap that above C<for> loop in a simple
2045sub called C<bind_fields()> or something and reuse it repeatedly. You still
2046get a layer of abstraction over manual SQL specification.
2047
3ae1c5e2 2048Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
deb148a2 2049construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
2050will expect the bind values in this format.
2051
32eab2da 2052=item quote_char
2053
2054This is the character that a table or column name will be quoted
9d48860e 2055with. By default this is an empty string, but you could set it to
32eab2da 2056the character C<`>, to generate SQL like this:
2057
2058 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
2059
96449e8e 2060Alternatively, you can supply an array ref of two items, the first being the left
2061hand quote character, and the second the right hand quote character. For
2062example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
2063that generates SQL like this:
2064
2065 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
2066
9d48860e 2067Quoting is useful if you have tables or columns names that are reserved
96449e8e 2068words in your database's SQL dialect.
32eab2da 2069
46be4313 2070=item escape_char
2071
2072This is the character that will be used to escape L</quote_char>s appearing
2073in an identifier before it has been quoted.
2074
80790166 2075The parameter default in case of a single L</quote_char> character is the quote
46be4313 2076character itself.
2077
2078When opening-closing-style quoting is used (L</quote_char> is an arrayref)
9de2bd86 2079this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
46be4313 2080of the B<opening (left)> L</quote_char> within the identifier are currently left
2081untouched. The default for opening-closing-style quotes may change in future
2082versions, thus you are B<strongly encouraged> to specify the escape character
2083explicitly.
2084
32eab2da 2085=item name_sep
2086
2087This is the character that separates a table and column name. It is
2088necessary to specify this when the C<quote_char> option is selected,
2089so that tables and column names can be individually quoted like this:
2090
2091 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
2092
b6251592 2093=item injection_guard
2094
2095A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
2096column name specified in a query structure. This is a safety mechanism to avoid
2097injection attacks when mishandling user input e.g.:
2098
2099 my %condition_as_column_value_pairs = get_values_from_user();
2100 $sqla->select( ... , \%condition_as_column_value_pairs );
2101
2102If the expression matches an exception is thrown. Note that literal SQL
2103supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
2104
2105Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
2106
96449e8e 2107=item array_datatypes
32eab2da 2108
9d48860e 2109When this option is true, arrayrefs in INSERT or UPDATE are
2110interpreted as array datatypes and are passed directly
96449e8e 2111to the DBI layer.
2112When this option is false, arrayrefs are interpreted
2113as literal SQL, just like refs to arrayrefs
2114(but this behavior is for backwards compatibility; when writing
2115new queries, use the "reference to arrayref" syntax
2116for literal SQL).
32eab2da 2117
32eab2da 2118
96449e8e 2119=item special_ops
32eab2da 2120
9d48860e 2121Takes a reference to a list of "special operators"
96449e8e 2122to extend the syntax understood by L<SQL::Abstract>.
2123See section L</"SPECIAL OPERATORS"> for details.
32eab2da 2124
59f23b3d 2125=item unary_ops
2126
9d48860e 2127Takes a reference to a list of "unary operators"
59f23b3d 2128to extend the syntax understood by L<SQL::Abstract>.
2129See section L</"UNARY OPERATORS"> for details.
2130
32eab2da 2131
32eab2da 2132
96449e8e 2133=back
32eab2da 2134
02288357 2135=head2 insert($table, \@values || \%fieldvals, \%options)
32eab2da 2136
2137This is the simplest function. You simply give it a table name
2138and either an arrayref of values or hashref of field/value pairs.
2139It returns an SQL INSERT statement and a list of bind values.
96449e8e 2140See the sections on L</"Inserting and Updating Arrays"> and
2141L</"Inserting and Updating SQL"> for information on how to insert
2142with those data types.
32eab2da 2143
02288357 2144The optional C<\%options> hash reference may contain additional
2145options to generate the insert SQL. Currently supported options
2146are:
2147
2148=over 4
2149
2150=item returning
2151
2152Takes either a scalar of raw SQL fields, or an array reference of
2153field names, and adds on an SQL C<RETURNING> statement at the end.
2154This allows you to return data generated by the insert statement
2155(such as row IDs) without performing another C<SELECT> statement.
2156Note, however, this is not part of the SQL standard and may not
2157be supported by all database engines.
2158
2159=back
2160
95904db5 2161=head2 update($table, \%fieldvals, \%where, \%options)
32eab2da 2162
2163This takes a table, hashref of field/value pairs, and an optional
86298391 2164hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 2165of bind values.
96449e8e 2166See the sections on L</"Inserting and Updating Arrays"> and
2167L</"Inserting and Updating SQL"> for information on how to insert
2168with those data types.
32eab2da 2169
95904db5 2170The optional C<\%options> hash reference may contain additional
2171options to generate the update SQL. Currently supported options
2172are:
2173
2174=over 4
2175
2176=item returning
2177
2178See the C<returning> option to
2179L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2180
2181=back
2182
96449e8e 2183=head2 select($source, $fields, $where, $order)
32eab2da 2184
9d48860e 2185This returns a SQL SELECT statement and associated list of bind values, as
be21dde3 2186specified by the arguments:
32eab2da 2187
96449e8e 2188=over
32eab2da 2189
96449e8e 2190=item $source
32eab2da 2191
9d48860e 2192Specification of the 'FROM' part of the statement.
96449e8e 2193The argument can be either a plain scalar (interpreted as a table
2194name, will be quoted), or an arrayref (interpreted as a list
2195of table names, joined by commas, quoted), or a scalarref
063097a3 2196(literal SQL, not quoted).
32eab2da 2197
96449e8e 2198=item $fields
32eab2da 2199
9d48860e 2200Specification of the list of fields to retrieve from
96449e8e 2201the source.
2202The argument can be either an arrayref (interpreted as a list
9d48860e 2203of field names, will be joined by commas and quoted), or a
96449e8e 2204plain scalar (literal SQL, not quoted).
521647e7 2205Please observe that this API is not as flexible as that of
2206the first argument C<$source>, for backwards compatibility reasons.
32eab2da 2207
96449e8e 2208=item $where
32eab2da 2209
96449e8e 2210Optional argument to specify the WHERE part of the query.
2211The argument is most often a hashref, but can also be
9d48860e 2212an arrayref or plain scalar --
96449e8e 2213see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 2214
96449e8e 2215=item $order
32eab2da 2216
96449e8e 2217Optional argument to specify the ORDER BY part of the query.
9d48860e 2218The argument can be a scalar, a hashref or an arrayref
96449e8e 2219-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
2220for details.
32eab2da 2221
96449e8e 2222=back
32eab2da 2223
32eab2da 2224
85327cd5 2225=head2 delete($table, \%where, \%options)
32eab2da 2226
86298391 2227This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 2228It returns an SQL DELETE statement and list of bind values.
2229
85327cd5 2230The optional C<\%options> hash reference may contain additional
2231options to generate the delete SQL. Currently supported options
2232are:
2233
2234=over 4
2235
2236=item returning
2237
2238See the C<returning> option to
2239L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2240
2241=back
2242
85783f3c 2243=head2 where(\%where, $order)
32eab2da 2244
2245This is used to generate just the WHERE clause. For example,
2246if you have an arbitrary data structure and know what the
2247rest of your SQL is going to look like, but want an easy way
2248to produce a WHERE clause, use this. It returns an SQL WHERE
2249clause and list of bind values.
2250
32eab2da 2251
2252=head2 values(\%data)
2253
2254This just returns the values from the hash C<%data>, in the same
2255order that would be returned from any of the other above queries.
2256Using this allows you to markedly speed up your queries if you
2257are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
2258
32eab2da 2259=head2 generate($any, 'number', $of, \@data, $struct, \%types)
2260
2261Warning: This is an experimental method and subject to change.
2262
2263This returns arbitrarily generated SQL. It's a really basic shortcut.
2264It will return two different things, depending on return context:
2265
2266 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
2267 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2268
2269These would return the following:
2270
2271 # First calling form
2272 $stmt = "CREATE TABLE test (?, ?)";
2273 @bind = (field1, field2);
2274
2275 # Second calling form
2276 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2277
2278Depending on what you're trying to do, it's up to you to choose the correct
2279format. In this example, the second form is what you would want.
2280
2281By the same token:
2282
2283 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2284
2285Might give you:
2286
2287 ALTER SESSION SET nls_date_format = 'MM/YY'
2288
2289You get the idea. Strings get their case twiddled, but everything
2290else remains verbatim.
2291
0da0fe34 2292=head1 EXPORTABLE FUNCTIONS
2293
2294=head2 is_plain_value
2295
2296Determines if the supplied argument is a plain value as understood by this
2297module:
2298
2299=over
2300
2301=item * The value is C<undef>
2302
2303=item * The value is a non-reference
2304
2305=item * The value is an object with stringification overloading
2306
2307=item * The value is of the form C<< { -value => $anything } >>
2308
2309=back
2310
9de2bd86 2311On failure returns C<undef>, on success returns a B<scalar> reference
966200cc 2312to the original supplied argument.
0da0fe34 2313
843a94b5 2314=over
2315
2316=item * Note
2317
2318The stringification overloading detection is rather advanced: it takes
2319into consideration not only the presence of a C<""> overload, but if that
2320fails also checks for enabled
2321L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2322on either C<0+> or C<bool>.
2323
2324Unfortunately testing in the field indicates that this
2325detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2326but only when very large numbers of stringifying objects are involved.
2327At the time of writing ( Sep 2014 ) there is no clear explanation of
2328the direct cause, nor is there a manageably small test case that reliably
2329reproduces the problem.
2330
2331If you encounter any of the following exceptions in B<random places within
2332your application stack> - this module may be to blame:
2333
2334 Operation "ne": no method found,
2335 left argument in overloaded package <something>,
2336 right argument in overloaded package <something>
2337
2338or perhaps even
2339
2340 Stub found while resolving method "???" overloading """" in package <something>
2341
2342If you fall victim to the above - please attempt to reduce the problem
2343to something that could be sent to the L<SQL::Abstract developers
1f490ae4 2344|DBIx::Class/GETTING HELP/SUPPORT>
843a94b5 2345(either publicly or privately). As a workaround in the meantime you can
2346set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2347value, which will most likely eliminate your problem (at the expense of
2348not being able to properly detect exotic forms of stringification).
2349
2350This notice and environment variable will be removed in a future version,
2351as soon as the underlying problem is found and a reliable workaround is
2352devised.
2353
2354=back
2355
0da0fe34 2356=head2 is_literal_value
2357
2358Determines if the supplied argument is a literal value as understood by this
2359module:
2360
2361=over
2362
2363=item * C<\$sql_string>
2364
2365=item * C<\[ $sql_string, @bind_values ]>
2366
0da0fe34 2367=back
2368
9de2bd86 2369On failure returns C<undef>, on success returns an B<array> reference
966200cc 2370containing the unpacked version of the supplied literal SQL and bind values.
0da0fe34 2371
32eab2da 2372=head1 WHERE CLAUSES
2373
96449e8e 2374=head2 Introduction
2375
32eab2da 2376This module uses a variation on the idea from L<DBIx::Abstract>. It
2377is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2378module is that things in arrays are OR'ed, and things in hashes
2379are AND'ed.>
2380
2381The easiest way to explain is to show lots of examples. After
2382each C<%where> hash shown, it is assumed you used:
2383
2384 my($stmt, @bind) = $sql->where(\%where);
2385
2386However, note that the C<%where> hash can be used directly in any
2387of the other functions as well, as described above.
2388
96449e8e 2389=head2 Key-value pairs
2390
32eab2da 2391So, let's get started. To begin, a simple hash:
2392
2393 my %where = (
2394 user => 'nwiger',
2395 status => 'completed'
2396 );
2397
2398Is converted to SQL C<key = val> statements:
2399
2400 $stmt = "WHERE user = ? AND status = ?";
2401 @bind = ('nwiger', 'completed');
2402
2403One common thing I end up doing is having a list of values that
2404a field can be in. To do this, simply specify a list inside of
2405an arrayref:
2406
2407 my %where = (
2408 user => 'nwiger',
2409 status => ['assigned', 'in-progress', 'pending'];
2410 );
2411
2412This simple code will create the following:
9d48860e 2413
32eab2da 2414 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2415 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2416
9d48860e 2417A field associated to an empty arrayref will be considered a
7cac25e6 2418logical false and will generate 0=1.
8a68b5be 2419
b864ba9b 2420=head2 Tests for NULL values
2421
2422If the value part is C<undef> then this is converted to SQL <IS NULL>
2423
2424 my %where = (
2425 user => 'nwiger',
2426 status => undef,
2427 );
2428
2429becomes:
2430
2431 $stmt = "WHERE user = ? AND status IS NULL";
2432 @bind = ('nwiger');
2433
e9614080 2434To test if a column IS NOT NULL:
2435
2436 my %where = (
2437 user => 'nwiger',
2438 status => { '!=', undef },
2439 );
cc422895 2440
6e0c6552 2441=head2 Specific comparison operators
96449e8e 2442
32eab2da 2443If you want to specify a different type of operator for your comparison,
2444you can use a hashref for a given column:
2445
2446 my %where = (
2447 user => 'nwiger',
2448 status => { '!=', 'completed' }
2449 );
2450
2451Which would generate:
2452
2453 $stmt = "WHERE user = ? AND status != ?";
2454 @bind = ('nwiger', 'completed');
2455
2456To test against multiple values, just enclose the values in an arrayref:
2457
96449e8e 2458 status => { '=', ['assigned', 'in-progress', 'pending'] };
2459
f2d5020d 2460Which would give you:
96449e8e 2461
2462 "WHERE status = ? OR status = ? OR status = ?"
2463
2464
2465The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 2466into an C<AND> of its elements:
2467
2468 my %where = (
2469 user => 'nwiger',
2470 status => { '!=', 'completed', -not_like => 'pending%' }
2471 );
2472
2473 # Or more dynamically, like from a form
2474 $where{user} = 'nwiger';
2475 $where{status}{'!='} = 'completed';
2476 $where{status}{'-not_like'} = 'pending%';
2477
2478 # Both generate this
2479 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2480 @bind = ('nwiger', 'completed', 'pending%');
2481
96449e8e 2482
32eab2da 2483To get an OR instead, you can combine it with the arrayref idea:
2484
2485 my %where => (
2486 user => 'nwiger',
1a6f2a03 2487 priority => [ { '=', 2 }, { '>', 5 } ]
32eab2da 2488 );
2489
2490Which would generate:
2491
1a6f2a03 2492 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2493 @bind = ('2', '5', 'nwiger');
32eab2da 2494
44b9e502 2495If you want to include literal SQL (with or without bind values), just use a
13cc86af 2496scalar reference or reference to an arrayref as the value:
44b9e502 2497
2498 my %where = (
2499 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2500 date_expires => { '<' => \"now()" }
2501 );
2502
2503Which would generate:
2504
13cc86af 2505 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
44b9e502 2506 @bind = ('11/26/2008');
2507
96449e8e 2508
2509=head2 Logic and nesting operators
2510
2511In the example above,
2512there is a subtle trap if you want to say something like
32eab2da 2513this (notice the C<AND>):
2514
2515 WHERE priority != ? AND priority != ?
2516
2517Because, in Perl you I<can't> do this:
2518
13cc86af 2519 priority => { '!=' => 2, '!=' => 1 }
32eab2da 2520
2521As the second C<!=> key will obliterate the first. The solution
2522is to use the special C<-modifier> form inside an arrayref:
2523
9d48860e 2524 priority => [ -and => {'!=', 2},
96449e8e 2525 {'!=', 1} ]
2526
32eab2da 2527
2528Normally, these would be joined by C<OR>, but the modifier tells it
2529to use C<AND> instead. (Hint: You can use this in conjunction with the
2530C<logic> option to C<new()> in order to change the way your queries
2531work by default.) B<Important:> Note that the C<-modifier> goes
2532B<INSIDE> the arrayref, as an extra first element. This will
2533B<NOT> do what you think it might:
2534
2535 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2536
2537Here is a quick list of equivalencies, since there is some overlap:
2538
2539 # Same
2540 status => {'!=', 'completed', 'not like', 'pending%' }
2541 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2542
2543 # Same
2544 status => {'=', ['assigned', 'in-progress']}
2545 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2546 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2547
e3f9dff4 2548
2549
be21dde3 2550=head2 Special operators: IN, BETWEEN, etc.
96449e8e 2551
32eab2da 2552You can also use the hashref format to compare a list of fields using the
2553C<IN> comparison operator, by specifying the list as an arrayref:
2554
2555 my %where = (
2556 status => 'completed',
2557 reportid => { -in => [567, 2335, 2] }
2558 );
2559
2560Which would generate:
2561
2562 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2563 @bind = ('completed', '567', '2335', '2');
2564
9d48860e 2565The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
96449e8e 2566the same way.
2567
6e0c6552 2568If the argument to C<-in> is an empty array, 'sqlfalse' is generated
be21dde3 2569(by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2570'sqltrue' (by default: C<1=1>).
6e0c6552 2571
e41c3bdd 2572In addition to the array you can supply a chunk of literal sql or
2573literal sql with bind:
6e0c6552 2574
e41c3bdd 2575 my %where = {
2576 customer => { -in => \[
2577 'SELECT cust_id FROM cust WHERE balance > ?',
2578 2000,
2579 ],
2580 status => { -in => \'SELECT status_codes FROM states' },
2581 };
6e0c6552 2582
e41c3bdd 2583would generate:
2584
2585 $stmt = "WHERE (
2586 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2587 AND status IN ( SELECT status_codes FROM states )
2588 )";
2589 @bind = ('2000');
2590
0dfd2442 2591Finally, if the argument to C<-in> is not a reference, it will be
2592treated as a single-element array.
e41c3bdd 2593
2594Another pair of operators is C<-between> and C<-not_between>,
96449e8e 2595used with an arrayref of two values:
32eab2da 2596
2597 my %where = (
2598 user => 'nwiger',
2599 completion_date => {
2600 -not_between => ['2002-10-01', '2003-02-06']
2601 }
2602 );
2603
2604Would give you:
2605
2606 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2607
e41c3bdd 2608Just like with C<-in> all plausible combinations of literal SQL
2609are possible:
2610
2611 my %where = {
2612 start0 => { -between => [ 1, 2 ] },
2613 start1 => { -between => \["? AND ?", 1, 2] },
2614 start2 => { -between => \"lower(x) AND upper(y)" },
9d48860e 2615 start3 => { -between => [
e41c3bdd 2616 \"lower(x)",
2617 \["upper(?)", 'stuff' ],
2618 ] },
2619 };
2620
2621Would give you:
2622
2623 $stmt = "WHERE (
2624 ( start0 BETWEEN ? AND ? )
2625 AND ( start1 BETWEEN ? AND ? )
2626 AND ( start2 BETWEEN lower(x) AND upper(y) )
2627 AND ( start3 BETWEEN lower(x) AND upper(?) )
2628 )";
2629 @bind = (1, 2, 1, 2, 'stuff');
2630
2631
9d48860e 2632These are the two builtin "special operators"; but the
be21dde3 2633list can be expanded: see section L</"SPECIAL OPERATORS"> below.
96449e8e 2634
59f23b3d 2635=head2 Unary operators: bool
97a920ef 2636
2637If you wish to test against boolean columns or functions within your
2638database you can use the C<-bool> and C<-not_bool> operators. For
2639example to test the column C<is_user> being true and the column
827bb0eb 2640C<is_enabled> being false you would use:-
97a920ef 2641
2642 my %where = (
2643 -bool => 'is_user',
2644 -not_bool => 'is_enabled',
2645 );
2646
2647Would give you:
2648
277b5d3f 2649 WHERE is_user AND NOT is_enabled
97a920ef 2650
0b604e9d 2651If a more complex combination is required, testing more conditions,
2652then you should use the and/or operators:-
2653
2654 my %where = (
2655 -and => [
2656 -bool => 'one',
23401b81 2657 -not_bool => { two=> { -rlike => 'bar' } },
2658 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
0b604e9d 2659 ],
2660 );
2661
2662Would give you:
2663
23401b81 2664 WHERE
2665 one
2666 AND
2667 (NOT two RLIKE ?)
2668 AND
2669 (NOT ( three = ? OR three > ? ))
97a920ef 2670
2671
107b72f1 2672=head2 Nested conditions, -and/-or prefixes
96449e8e 2673
32eab2da 2674So far, we've seen how multiple conditions are joined with a top-level
2675C<AND>. We can change this by putting the different conditions we want in
2676hashes and then putting those hashes in an array. For example:
2677
2678 my @where = (
2679 {
2680 user => 'nwiger',
2681 status => { -like => ['pending%', 'dispatched'] },
2682 },
2683 {
2684 user => 'robot',
2685 status => 'unassigned',
2686 }
2687 );
2688
2689This data structure would create the following:
2690
2691 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2692 OR ( user = ? AND status = ? ) )";
2693 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2694
107b72f1 2695
48d9f5f8 2696Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
be21dde3 2697to change the logic inside:
32eab2da 2698
2699 my @where = (
2700 -and => [
2701 user => 'nwiger',
48d9f5f8 2702 [
2703 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2704 -or => { workhrs => {'<', 50}, geo => 'EURO' },
32eab2da 2705 ],
2706 ],
2707 );
2708
2709That would yield:
2710
13cc86af 2711 $stmt = "WHERE ( user = ?
2712 AND ( ( workhrs > ? AND geo = ? )
2713 OR ( workhrs < ? OR geo = ? ) ) )";
2714 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
107b72f1 2715
cc422895 2716=head3 Algebraic inconsistency, for historical reasons
107b72f1 2717
7cac25e6 2718C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2719operator goes C<outside> of the nested structure; whereas when connecting
2720several constraints on one column, the C<-and> operator goes
be21dde3 2721C<inside> the arrayref. Here is an example combining both features:
7cac25e6 2722
2723 my @where = (
2724 -and => [a => 1, b => 2],
2725 -or => [c => 3, d => 4],
2726 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2727 )
2728
2729yielding
2730
9d48860e 2731 WHERE ( ( ( a = ? AND b = ? )
2732 OR ( c = ? OR d = ? )
7cac25e6 2733 OR ( e LIKE ? AND e LIKE ? ) ) )
2734
107b72f1 2735This difference in syntax is unfortunate but must be preserved for
be21dde3 2736historical reasons. So be careful: the two examples below would
107b72f1 2737seem algebraically equivalent, but they are not
2738
a948b1fe 2739 { col => [ -and =>
2740 { -like => 'foo%' },
2741 { -like => '%bar' },
2742 ] }
be21dde3 2743 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
107b72f1 2744
a948b1fe 2745 [ -and =>
2746 { col => { -like => 'foo%' } },
2747 { col => { -like => '%bar' } },
2748 ]
be21dde3 2749 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
107b72f1 2750
7cac25e6 2751
cc422895 2752=head2 Literal SQL and value type operators
96449e8e 2753
cc422895 2754The basic premise of SQL::Abstract is that in WHERE specifications the "left
2755side" is a column name and the "right side" is a value (normally rendered as
2756a placeholder). This holds true for both hashrefs and arrayref pairs as you
2757see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2758alter this behavior. There are several ways of doing so.
e9614080 2759
cc422895 2760=head3 -ident
2761
2762This is a virtual operator that signals the string to its right side is an
2763identifier (a column name) and not a value. For example to compare two
2764columns you would write:
32eab2da 2765
e9614080 2766 my %where = (
2767 priority => { '<', 2 },
cc422895 2768 requestor => { -ident => 'submitter' },
e9614080 2769 );
2770
2771which creates:
2772
2773 $stmt = "WHERE priority < ? AND requestor = submitter";
2774 @bind = ('2');
2775
cc422895 2776If you are maintaining legacy code you may see a different construct as
2777described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2778code.
2779
2780=head3 -value
e9614080 2781
cc422895 2782This is a virtual operator that signals that the construct to its right side
2783is a value to be passed to DBI. This is for example necessary when you want
2784to write a where clause against an array (for RDBMS that support such
2785datatypes). For example:
e9614080 2786
32eab2da 2787 my %where = (
cc422895 2788 array => { -value => [1, 2, 3] }
32eab2da 2789 );
2790
cc422895 2791will result in:
32eab2da 2792
cc422895 2793 $stmt = 'WHERE array = ?';
2794 @bind = ([1, 2, 3]);
32eab2da 2795
cc422895 2796Note that if you were to simply say:
32eab2da 2797
2798 my %where = (
cc422895 2799 array => [1, 2, 3]
32eab2da 2800 );
2801
3af02ccb 2802the result would probably not be what you wanted:
cc422895 2803
2804 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2805 @bind = (1, 2, 3);
2806
2807=head3 Literal SQL
96449e8e 2808
cc422895 2809Finally, sometimes only literal SQL will do. To include a random snippet
2810of SQL verbatim, you specify it as a scalar reference. Consider this only
2811as a last resort. Usually there is a better way. For example:
96449e8e 2812
2813 my %where = (
cc422895 2814 priority => { '<', 2 },
2815 requestor => { -in => \'(SELECT name FROM hitmen)' },
96449e8e 2816 );
2817
cc422895 2818Would create:
96449e8e 2819
cc422895 2820 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2821 @bind = (2);
2822
2823Note that in this example, you only get one bind parameter back, since
2824the verbatim SQL is passed as part of the statement.
2825
2826=head4 CAVEAT
2827
2828 Never use untrusted input as a literal SQL argument - this is a massive
2829 security risk (there is no way to check literal snippets for SQL
2830 injections and other nastyness). If you need to deal with untrusted input
2831 use literal SQL with placeholders as described next.
96449e8e 2832
cc422895 2833=head3 Literal SQL with placeholders and bind values (subqueries)
96449e8e 2834
2835If the literal SQL to be inserted has placeholders and bind values,
2836use a reference to an arrayref (yes this is a double reference --
2837not so common, but perfectly legal Perl). For example, to find a date
2838in Postgres you can use something like this:
2839
2840 my %where = (
3ae1c5e2 2841 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
96449e8e 2842 )
2843
2844This would create:
2845
d2a8fe1a 2846 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 2847 @bind = ('10');
2848
deb148a2 2849Note that you must pass the bind values in the same format as they are returned
85783f3c 2850by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
1f490ae4 2851to C<columns>, you must provide the bind values in the
2852C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2853scalar value; most commonly the column name, but you can use any scalar value
2854(including references and blessed references), L<SQL::Abstract> will simply
2855pass it through intact. So if C<bindtype> is set to C<columns> the above
2856example will look like:
deb148a2 2857
2858 my %where = (
3ae1c5e2 2859 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
deb148a2 2860 )
96449e8e 2861
2862Literal SQL is especially useful for nesting parenthesized clauses in the
be21dde3 2863main SQL query. Here is a first example:
96449e8e 2864
2865 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2866 100, "foo%");
2867 my %where = (
2868 foo => 1234,
2869 bar => \["IN ($sub_stmt)" => @sub_bind],
2870 );
2871
be21dde3 2872This yields:
96449e8e 2873
9d48860e 2874 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
96449e8e 2875 WHERE c2 < ? AND c3 LIKE ?))";
2876 @bind = (1234, 100, "foo%");
2877
9d48860e 2878Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
96449e8e 2879are expressed in the same way. Of course the C<$sub_stmt> and
9d48860e 2880its associated bind values can be generated through a former call
96449e8e 2881to C<select()> :
2882
2883 my ($sub_stmt, @sub_bind)
9d48860e 2884 = $sql->select("t1", "c1", {c2 => {"<" => 100},
96449e8e 2885 c3 => {-like => "foo%"}});
2886 my %where = (
2887 foo => 1234,
2888 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2889 );
2890
2891In the examples above, the subquery was used as an operator on a column;
9d48860e 2892but the same principle also applies for a clause within the main C<%where>
be21dde3 2893hash, like an EXISTS subquery:
96449e8e 2894
9d48860e 2895 my ($sub_stmt, @sub_bind)
96449e8e 2896 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
48d9f5f8 2897 my %where = ( -and => [
96449e8e 2898 foo => 1234,
48d9f5f8 2899 \["EXISTS ($sub_stmt)" => @sub_bind],
2900 ]);
96449e8e 2901
2902which yields
2903
9d48860e 2904 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
96449e8e 2905 WHERE c1 = ? AND c2 > t0.c0))";
2906 @bind = (1234, 1);
2907
2908
9d48860e 2909Observe that the condition on C<c2> in the subquery refers to
be21dde3 2910column C<t0.c0> of the main query: this is I<not> a bind
9d48860e 2911value, so we have to express it through a scalar ref.
96449e8e 2912Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2913C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2914what we wanted here.
2915
96449e8e 2916Finally, here is an example where a subquery is used
2917for expressing unary negation:
2918
9d48860e 2919 my ($sub_stmt, @sub_bind)
96449e8e 2920 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2921 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2922 my %where = (
2923 lname => {like => '%son%'},
48d9f5f8 2924 \["NOT ($sub_stmt)" => @sub_bind],
96449e8e 2925 );
2926
2927This yields
2928
2929 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2930 @bind = ('%son%', 10, 20)
2931
cc422895 2932=head3 Deprecated usage of Literal SQL
2933
2934Below are some examples of archaic use of literal SQL. It is shown only as
2935reference for those who deal with legacy code. Each example has a much
2936better, cleaner and safer alternative that users should opt for in new code.
2937
2938=over
2939
2940=item *
2941
2942 my %where = ( requestor => \'IS NOT NULL' )
2943
2944 $stmt = "WHERE requestor IS NOT NULL"
2945
2946This used to be the way of generating NULL comparisons, before the handling
2947of C<undef> got formalized. For new code please use the superior syntax as
2948described in L</Tests for NULL values>.
96449e8e 2949
cc422895 2950=item *
2951
2952 my %where = ( requestor => \'= submitter' )
2953
2954 $stmt = "WHERE requestor = submitter"
2955
2956This used to be the only way to compare columns. Use the superior L</-ident>
2957method for all new code. For example an identifier declared in such a way
2958will be properly quoted if L</quote_char> is properly set, while the legacy
2959form will remain as supplied.
2960
2961=item *
2962
2963 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2964
2965 $stmt = "WHERE completed > ? AND is_ready"
2966 @bind = ('2012-12-21')
2967
2968Using an empty string literal used to be the only way to express a boolean.
2969For all new code please use the much more readable
2970L<-bool|/Unary operators: bool> operator.
2971
2972=back
96449e8e 2973
2974=head2 Conclusion
2975
32eab2da 2976These pages could go on for a while, since the nesting of the data
2977structures this module can handle are pretty much unlimited (the
2978module implements the C<WHERE> expansion as a recursive function
2979internally). Your best bet is to "play around" with the module a
2980little to see how the data structures behave, and choose the best
2981format for your data based on that.
2982
2983And of course, all the values above will probably be replaced with
2984variables gotten from forms or the command line. After all, if you
2985knew everything ahead of time, you wouldn't have to worry about
2986dynamically-generating SQL and could just hardwire it into your
2987script.
2988
86298391 2989=head1 ORDER BY CLAUSES
2990
9d48860e 2991Some functions take an order by clause. This can either be a scalar (just a
18710f60 2992column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2993>>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2994forms. Examples:
1cfa1db3 2995
8c15b421 2996 Given | Will Generate
18710f60 2997 ---------------------------------------------------------------
8c15b421 2998 |
2999 'colA' | ORDER BY colA
3000 |
3001 [qw/colA colB/] | ORDER BY colA, colB
3002 |
3003 {-asc => 'colA'} | ORDER BY colA ASC
3004 |
3005 {-desc => 'colB'} | ORDER BY colB DESC
3006 |
3007 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
3008 |
3009 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
3010 |
3011 \'colA DESC' | ORDER BY colA DESC
3012 |
3013 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
3014 | /* ...with $x bound to ? */
3015 |
bd805d85 3016 [ | ORDER BY
3017 { -asc => 'colA' }, | colA ASC,
3018 { -desc => [qw/colB/] }, | colB DESC,
3019 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
3020 \'colE DESC', | colE DESC,
3021 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
3022 ] | /* ...with $x bound to ? */
18710f60 3023 ===============================================================
86298391 3024
96449e8e 3025
3026
3027=head1 SPECIAL OPERATORS
3028
e3f9dff4 3029 my $sqlmaker = SQL::Abstract->new(special_ops => [
3a2e1a5e 3030 {
3031 regex => qr/.../,
e3f9dff4 3032 handler => sub {
3033 my ($self, $field, $op, $arg) = @_;
3034 ...
3a2e1a5e 3035 },
3036 },
3037 {
3038 regex => qr/.../,
3039 handler => 'method_name',
e3f9dff4 3040 },
3041 ]);
3042
9d48860e 3043A "special operator" is a SQL syntactic clause that can be
e3f9dff4 3044applied to a field, instead of a usual binary operator.
be21dde3 3045For example:
e3f9dff4 3046
3047 WHERE field IN (?, ?, ?)
3048 WHERE field BETWEEN ? AND ?
3049 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 3050
e3f9dff4 3051Special operators IN and BETWEEN are fairly standard and therefore
3a2e1a5e 3052are builtin within C<SQL::Abstract> (as the overridable methods
3053C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
3054like the MATCH .. AGAINST example above which is specific to MySQL,
3055you can write your own operator handlers - supply a C<special_ops>
3056argument to the C<new> method. That argument takes an arrayref of
3057operator definitions; each operator definition is a hashref with two
3058entries:
96449e8e 3059
e3f9dff4 3060=over
3061
3062=item regex
3063
3064the regular expression to match the operator
96449e8e 3065
e3f9dff4 3066=item handler
3067
3a2e1a5e 3068Either a coderef or a plain scalar method name. In both cases
3069the expected return is C<< ($sql, @bind) >>.
3070
3071When supplied with a method name, it is simply called on the
13cc86af 3072L<SQL::Abstract> object as:
3a2e1a5e 3073
ca4f826a 3074 $self->$method_name($field, $op, $arg)
3a2e1a5e 3075
3076 Where:
3077
3a2e1a5e 3078 $field is the LHS of the operator
13cc86af 3079 $op is the part that matched the handler regex
3a2e1a5e 3080 $arg is the RHS
3081
3082When supplied with a coderef, it is called as:
3083
3084 $coderef->($self, $field, $op, $arg)
3085
e3f9dff4 3086
3087=back
3088
9d48860e 3089For example, here is an implementation
e3f9dff4 3090of the MATCH .. AGAINST syntax for MySQL
3091
3092 my $sqlmaker = SQL::Abstract->new(special_ops => [
9d48860e 3093
e3f9dff4 3094 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
9d48860e 3095 {regex => qr/^match$/i,
e3f9dff4 3096 handler => sub {
3097 my ($self, $field, $op, $arg) = @_;
3098 $arg = [$arg] if not ref $arg;
3099 my $label = $self->_quote($field);
3100 my ($placeholder) = $self->_convert('?');
3101 my $placeholders = join ", ", (($placeholder) x @$arg);
3102 my $sql = $self->_sqlcase('match') . " ($label) "
3103 . $self->_sqlcase('against') . " ($placeholders) ";
3104 my @bind = $self->_bindtype($field, @$arg);
3105 return ($sql, @bind);
3106 }
3107 },
9d48860e 3108
e3f9dff4 3109 ]);
96449e8e 3110
3111
59f23b3d 3112=head1 UNARY OPERATORS
3113
112b5232 3114 my $sqlmaker = SQL::Abstract->new(unary_ops => [
59f23b3d 3115 {
3116 regex => qr/.../,
3117 handler => sub {
3118 my ($self, $op, $arg) = @_;
3119 ...
3120 },
3121 },
3122 {
3123 regex => qr/.../,
3124 handler => 'method_name',
3125 },
3126 ]);
3127
9d48860e 3128A "unary operator" is a SQL syntactic clause that can be
59f23b3d 3129applied to a field - the operator goes before the field
3130
3131You can write your own operator handlers - supply a C<unary_ops>
3132argument to the C<new> method. That argument takes an arrayref of
3133operator definitions; each operator definition is a hashref with two
3134entries:
3135
3136=over
3137
3138=item regex
3139
3140the regular expression to match the operator
3141
3142=item handler
3143
3144Either a coderef or a plain scalar method name. In both cases
3145the expected return is C<< $sql >>.
3146
3147When supplied with a method name, it is simply called on the
13cc86af 3148L<SQL::Abstract> object as:
59f23b3d 3149
ca4f826a 3150 $self->$method_name($op, $arg)
59f23b3d 3151
3152 Where:
3153
3154 $op is the part that matched the handler regex
3155 $arg is the RHS or argument of the operator
3156
3157When supplied with a coderef, it is called as:
3158
3159 $coderef->($self, $op, $arg)
3160
3161
3162=back
3163
3164
32eab2da 3165=head1 PERFORMANCE
3166
3167Thanks to some benchmarking by Mark Stosberg, it turns out that
3168this module is many orders of magnitude faster than using C<DBIx::Abstract>.
3169I must admit this wasn't an intentional design issue, but it's a
3170byproduct of the fact that you get to control your C<DBI> handles
3171yourself.
3172
3173To maximize performance, use a code snippet like the following:
3174
3175 # prepare a statement handle using the first row
3176 # and then reuse it for the rest of the rows
3177 my($sth, $stmt);
3178 for my $href (@array_of_hashrefs) {
3179 $stmt ||= $sql->insert('table', $href);
3180 $sth ||= $dbh->prepare($stmt);
3181 $sth->execute($sql->values($href));
3182 }
3183
3184The reason this works is because the keys in your C<$href> are sorted
3185internally by B<SQL::Abstract>. Thus, as long as your data retains
3186the same structure, you only have to generate the SQL the first time
3187around. On subsequent queries, simply use the C<values> function provided
3188by this module to return your values in the correct order.
3189
b864ba9b 3190However this depends on the values having the same type - if, for
3191example, the values of a where clause may either have values
3192(resulting in sql of the form C<column = ?> with a single bind
3193value), or alternatively the values might be C<undef> (resulting in
3194sql of the form C<column IS NULL> with no bind value) then the
3195caching technique suggested will not work.
96449e8e 3196
32eab2da 3197=head1 FORMBUILDER
3198
3199If you use my C<CGI::FormBuilder> module at all, you'll hopefully
3200really like this part (I do, at least). Building up a complex query
3201can be as simple as the following:
3202
3203 #!/usr/bin/perl
3204
46dc2f3e 3205 use warnings;
3206 use strict;
3207
32eab2da 3208 use CGI::FormBuilder;
3209 use SQL::Abstract;
3210
3211 my $form = CGI::FormBuilder->new(...);
3212 my $sql = SQL::Abstract->new;
3213
3214 if ($form->submitted) {
3215 my $field = $form->field;
3216 my $id = delete $field->{id};
3217 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
3218 }
3219
3220Of course, you would still have to connect using C<DBI> to run the
3221query, but the point is that if you make your form look like your
3222table, the actual query script can be extremely simplistic.
3223
3224If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
9d48860e 3225a fast interface to returning and formatting data. I frequently
32eab2da 3226use these three modules together to write complex database query
3227apps in under 50 lines.
3228
af733667 3229=head1 HOW TO CONTRIBUTE
3230
3231Contributions are always welcome, in all usable forms (we especially
3232welcome documentation improvements). The delivery methods include git-
3233or unified-diff formatted patches, GitHub pull requests, or plain bug
3234reports either via RT or the Mailing list. Contributors are generally
3235granted full access to the official repository after their first several
3236patches pass successful review.
3237
3238This project is maintained in a git repository. The code and related tools are
3239accessible at the following locations:
d8cc1792 3240
3241=over
3242
af733667 3243=item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
3244
3245=item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
3246
3247=item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
d8cc1792 3248
af733667 3249=item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
d8cc1792 3250
3251=back
32eab2da 3252
96449e8e 3253=head1 CHANGES
3254
3255Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
3256Great care has been taken to preserve the I<published> behavior
3257documented in previous versions in the 1.* family; however,
9d48860e 3258some features that were previously undocumented, or behaved
96449e8e 3259differently from the documentation, had to be changed in order
3260to clarify the semantics. Hence, client code that was relying
9d48860e 3261on some dark areas of C<SQL::Abstract> v1.*
96449e8e 3262B<might behave differently> in v1.50.
32eab2da 3263
be21dde3 3264The main changes are:
d2a8fe1a 3265
96449e8e 3266=over
32eab2da 3267
9d48860e 3268=item *
32eab2da 3269
3ae1c5e2 3270support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
96449e8e 3271
3272=item *
3273
145fbfc8 3274support for the { operator => \"..." } construct (to embed literal SQL)
3275
3276=item *
3277
9c37b9c0 3278support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
3279
3280=item *
3281
96449e8e 3282optional support for L<array datatypes|/"Inserting and Updating Arrays">
3283
9d48860e 3284=item *
96449e8e 3285
be21dde3 3286defensive programming: check arguments
96449e8e 3287
3288=item *
3289
3290fixed bug with global logic, which was previously implemented
7cac25e6 3291through global variables yielding side-effects. Prior versions would
96449e8e 3292interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3293as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3294Now this is interpreted
3295as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3296
96449e8e 3297
3298=item *
3299
3300fixed semantics of _bindtype on array args
3301
9d48860e 3302=item *
96449e8e 3303
3304dropped the C<_anoncopy> of the %where tree. No longer necessary,
3305we just avoid shifting arrays within that tree.
3306
3307=item *
3308
3309dropped the C<_modlogic> function
3310
3311=back
32eab2da 3312
32eab2da 3313=head1 ACKNOWLEDGEMENTS
3314
3315There are a number of individuals that have really helped out with
3316this module. Unfortunately, most of them submitted bugs via CPAN
3317so I have no idea who they are! But the people I do know are:
3318
9d48860e 3319 Ash Berlin (order_by hash term support)
b643abe1 3320 Matt Trout (DBIx::Class support)
32eab2da 3321 Mark Stosberg (benchmarking)
3322 Chas Owens (initial "IN" operator support)
3323 Philip Collins (per-field SQL functions)
3324 Eric Kolve (hashref "AND" support)
3325 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3326 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 3327 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
48d9f5f8 3328 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
dbdf7648 3329 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
e96c510a 3330 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
02288357 3331 Oliver Charles (support for "RETURNING" after "INSERT")
32eab2da 3332
3333Thanks!
3334
32eab2da 3335=head1 SEE ALSO
3336
86298391 3337L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 3338
32eab2da 3339=head1 AUTHOR
3340
b643abe1 3341Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3342
3343This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 3344
abe72f94 3345For support, your best bet is to try the C<DBIx::Class> users mailing list.
3346While not an official support venue, C<DBIx::Class> makes heavy use of
3347C<SQL::Abstract>, and as such list members there are very familiar with
3348how to create queries.
3349
0d067ded 3350=head1 LICENSE
3351
d988ab87 3352This module is free software; you may copy this under the same
3353terms as perl itself (either the GNU General Public License or
3354the Artistic License)
32eab2da 3355
3356=cut