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