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