We already have Storable as a dep, this is pointless
[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
4d8b3dc4 964 my ($clause, @bind) = $self->_SWITCH_refkind($vals, {
965 ARRAYREFREF => sub {
c94a6c93 966 my ($s, @b) = @$$vals;
967 $self->_assert_bindval_matches_bindtype(@b);
968 ($s, @b);
4d8b3dc4 969 },
970 SCALARREF => sub {
971 return $$vals;
972 },
973 ARRAYREF => sub {
974 puke "special op 'between' accepts an arrayref with exactly two values"
975 if @$vals != 2;
976
977 my (@all_sql, @all_bind);
978 foreach my $val (@$vals) {
979 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
980 SCALAR => sub {
5e5cbf51 981 return ($placeholder, $self->_bindtype($k, $val) );
4d8b3dc4 982 },
983 SCALARREF => sub {
0336eddb 984 return $$val;
4d8b3dc4 985 },
986 ARRAYREFREF => sub {
987 my ($sql, @bind) = @$$val;
c94a6c93 988 $self->_assert_bindval_matches_bindtype(@bind);
0336eddb 989 return ($sql, @bind);
4d8b3dc4 990 },
0336eddb 991 HASHREF => sub {
992 my ($func, $arg, @rest) = %$val;
993 puke ("Only simple { -func => arg } functions accepted as sub-arguments to BETWEEN")
994 if (@rest or $func !~ /^ \- (.+)/x);
995 local $self->{_nested_func_lhs} = $k;
0ec3aec7 996 $self->_where_unary_op ($1 => $arg);
0336eddb 997 }
4d8b3dc4 998 });
999 push @all_sql, $sql;
1000 push @all_bind, @bind;
1001 }
1002
1003 return (
1004 (join $and, @all_sql),
5e5cbf51 1005 @all_bind
4d8b3dc4 1006 );
1007 },
1008 FALLBACK => sub {
1009 puke "special op 'between' accepts an arrayref with two values, or a single literal scalarref/arrayref-ref";
1010 },
1011 });
cf02fc47 1012
cf02fc47 1013 my $sql = "( $label $op $clause )";
96449e8e 1014 return ($sql, @bind)
1015}
1016
1017
1018sub _where_field_IN {
1019 my ($self, $k, $op, $vals) = @_;
1020
1021 # backwards compatibility : if scalar, force into an arrayref
1022 $vals = [$vals] if defined $vals && ! ref $vals;
1023
96449e8e 1024 my ($label) = $self->_convert($self->_quote($k));
1025 my ($placeholder) = $self->_convert('?');
96449e8e 1026 $op = $self->_sqlcase($op);
1027
8a0d798a 1028 my ($sql, @bind) = $self->_SWITCH_refkind($vals, {
1029 ARRAYREF => sub { # list of choices
1030 if (@$vals) { # nonempty list
0336eddb 1031 my (@all_sql, @all_bind);
1032
1033 for my $val (@$vals) {
1034 my ($sql, @bind) = $self->_SWITCH_refkind($val, {
1035 SCALAR => sub {
1036 return ($placeholder, $val);
1037 },
1038 SCALARREF => sub {
1039 return $$val;
1040 },
1041 ARRAYREFREF => sub {
1042 my ($sql, @bind) = @$$val;
1043 $self->_assert_bindval_matches_bindtype(@bind);
1044 return ($sql, @bind);
1045 },
1046 HASHREF => sub {
1047 my ($func, $arg, @rest) = %$val;
1048 puke ("Only simple { -func => arg } functions accepted as sub-arguments to IN")
1049 if (@rest or $func !~ /^ \- (.+)/x);
1050 local $self->{_nested_func_lhs} = $k;
0ec3aec7 1051 $self->_where_unary_op ($1 => $arg);
279eb282 1052 },
1053 UNDEF => sub {
032dfe20 1054 puke(
1055 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
1056 . "-$op operator was given an undef-containing list: !!!AUDIT YOUR CODE "
1057 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
1058 . 'will emit the logically correct SQL instead of raising this exception)'
1059 );
279eb282 1060 },
0336eddb 1061 });
1062 push @all_sql, $sql;
1063 push @all_bind, @bind;
1064 }
96449e8e 1065
88a89939 1066 return (
1067 sprintf ('%s %s ( %s )',
1068 $label,
1069 $op,
1070 join (', ', @all_sql)
1071 ),
1072 $self->_bindtype($k, @all_bind),
0336eddb 1073 );
8a0d798a 1074 }
1075 else { # empty list : some databases won't understand "IN ()", so DWIM
1076 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
1077 return ($sql);
1078 }
1079 },
1080
4a1f01a3 1081 SCALARREF => sub { # literal SQL
1082 my $sql = $self->_open_outer_paren ($$vals);
1083 return ("$label $op ( $sql )");
1084 },
8a0d798a 1085 ARRAYREFREF => sub { # literal SQL with bind
1086 my ($sql, @bind) = @$$vals;
fe3ae272 1087 $self->_assert_bindval_matches_bindtype(@bind);
4a1f01a3 1088 $sql = $self->_open_outer_paren ($sql);
8a0d798a 1089 return ("$label $op ( $sql )", @bind);
1090 },
1091
ff8ca6b4 1092 UNDEF => sub {
1093 puke "Argument passed to the '$op' operator can not be undefined";
1094 },
1095
8a0d798a 1096 FALLBACK => sub {
ff8ca6b4 1097 puke "special op $op requires an arrayref (or scalarref/arrayref-ref)";
8a0d798a 1098 },
1099 });
1100
1101 return ($sql, @bind);
96449e8e 1102}
1103
4a1f01a3 1104# Some databases (SQLite) treat col IN (1, 2) different from
1105# col IN ( (1, 2) ). Use this to strip all outer parens while
1106# adding them back in the corresponding method
1107sub _open_outer_paren {
1108 my ($self, $sql) = @_;
171a709f 1109 $sql = $1 while $sql =~ /^ \s* \( (.*) \) \s* $/xs;
4a1f01a3 1110 return $sql;
1111}
1112
96449e8e 1113
96449e8e 1114#======================================================================
1115# ORDER BY
1116#======================================================================
1117
1118sub _order_by {
1119 my ($self, $arg) = @_;
1120
f267b646 1121 my (@sql, @bind);
1122 for my $c ($self->_order_by_chunks ($arg) ) {
1123 $self->_SWITCH_refkind ($c, {
1124 SCALAR => sub { push @sql, $c },
1125 ARRAYREF => sub { push @sql, shift @$c; push @bind, @$c },
1126 });
1127 }
1128
1129 my $sql = @sql
1130 ? sprintf ('%s %s',
1131 $self->_sqlcase(' order by'),
1132 join (', ', @sql)
1133 )
1134 : ''
1135 ;
1136
1137 return wantarray ? ($sql, @bind) : $sql;
1138}
1139
1140sub _order_by_chunks {
1141 my ($self, $arg) = @_;
1142
1143 return $self->_SWITCH_refkind($arg, {
96449e8e 1144
1145 ARRAYREF => sub {
f267b646 1146 map { $self->_order_by_chunks ($_ ) } @$arg;
96449e8e 1147 },
1148
c94a6c93 1149 ARRAYREFREF => sub {
1150 my ($s, @b) = @$$arg;
1151 $self->_assert_bindval_matches_bindtype(@b);
1152 [ $s, @b ];
1153 },
f267b646 1154
96449e8e 1155 SCALAR => sub {$self->_quote($arg)},
f267b646 1156
1157 UNDEF => sub {return () },
1158
96449e8e 1159 SCALARREF => sub {$$arg}, # literal SQL, no quoting
96449e8e 1160
f267b646 1161 HASHREF => sub {
5e436130 1162 # get first pair in hash
1163 my ($key, $val, @rest) = %$arg;
1164
1165 return () unless $key;
1166
1167 if ( @rest or not $key =~ /^-(desc|asc)/i ) {
1168 puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
f267b646 1169 }
5e436130 1170
1171 my $direction = $1;
96449e8e 1172
e9bd3547 1173 my @ret;
f267b646 1174 for my $c ($self->_order_by_chunks ($val)) {
e9bd3547 1175 my ($sql, @bind);
96449e8e 1176
f267b646 1177 $self->_SWITCH_refkind ($c, {
1178 SCALAR => sub {
e9bd3547 1179 $sql = $c;
f267b646 1180 },
1181 ARRAYREF => sub {
e9bd3547 1182 ($sql, @bind) = @$c;
f267b646 1183 },
1184 });
96449e8e 1185
5e436130 1186 $sql = $sql . ' ' . $self->_sqlcase($direction);
96449e8e 1187
e9bd3547 1188 push @ret, [ $sql, @bind];
1189 }
96449e8e 1190
e9bd3547 1191 return @ret;
f267b646 1192 },
1193 });
96449e8e 1194}
1195
1196
96449e8e 1197#======================================================================
1198# DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1199#======================================================================
1200
1201sub _table {
1202 my $self = shift;
1203 my $from = shift;
1204 $self->_SWITCH_refkind($from, {
1205 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
1206 SCALAR => sub {$self->_quote($from)},
1207 SCALARREF => sub {$$from},
96449e8e 1208 });
1209}
1210
1211
1212#======================================================================
1213# UTILITY FUNCTIONS
1214#======================================================================
1215
955e77ca 1216# highly optimized, as it's called way too often
96449e8e 1217sub _quote {
955e77ca 1218 # my ($self, $label) = @_;
96449e8e 1219
955e77ca 1220 return '' unless defined $_[1];
955e77ca 1221 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
96449e8e 1222
b6251592 1223 unless ($_[0]->{quote_char}) {
170e6c33 1224 $_[0]->_assert_pass_injection_guard($_[1]);
b6251592 1225 return $_[1];
1226 }
96449e8e 1227
07d7c35c 1228 my $qref = ref $_[0]->{quote_char};
955e77ca 1229 my ($l, $r);
07d7c35c 1230 if (!$qref) {
1231 ($l, $r) = ( $_[0]->{quote_char}, $_[0]->{quote_char} );
955e77ca 1232 }
07d7c35c 1233 elsif ($qref eq 'ARRAY') {
1234 ($l, $r) = @{$_[0]->{quote_char}};
955e77ca 1235 }
1236 else {
1237 puke "Unsupported quote_char format: $_[0]->{quote_char}";
1238 }
96449e8e 1239
07d7c35c 1240 # parts containing * are naturally unquoted
1241 return join( $_[0]->{name_sep}||'', map
955e77ca 1242 { $_ eq '*' ? $_ : $l . $_ . $r }
1243 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
1244 );
96449e8e 1245}
1246
1247
1248# Conversion, if applicable
1249sub _convert ($) {
07d7c35c 1250 #my ($self, $arg) = @_;
96449e8e 1251
1252# LDNOTE : modified the previous implementation below because
1253# it was not consistent : the first "return" is always an array,
1254# the second "return" is context-dependent. Anyway, _convert
9d48860e 1255# seems always used with just a single argument, so make it a
96449e8e 1256# scalar function.
1257# return @_ unless $self->{convert};
1258# my $conv = $self->_sqlcase($self->{convert});
1259# my @ret = map { $conv.'('.$_.')' } @_;
1260# return wantarray ? @ret : $ret[0];
07d7c35c 1261 if ($_[0]->{convert}) {
1262 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
96449e8e 1263 }
07d7c35c 1264 return $_[1];
96449e8e 1265}
1266
1267# And bindtype
1268sub _bindtype (@) {
07d7c35c 1269 #my ($self, $col, @vals) = @_;
96449e8e 1270
9d48860e 1271 #LDNOTE : changed original implementation below because it did not make
96449e8e 1272 # sense when bindtype eq 'columns' and @vals > 1.
1273# return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
1274
07d7c35c 1275 # called often - tighten code
1276 return $_[0]->{bindtype} eq 'columns'
1277 ? map {[$_[1], $_]} @_[2 .. $#_]
1278 : @_[2 .. $#_]
1279 ;
96449e8e 1280}
1281
fe3ae272 1282# Dies if any element of @bind is not in [colname => value] format
1283# if bindtype is 'columns'.
1284sub _assert_bindval_matches_bindtype {
c94a6c93 1285# my ($self, @bind) = @_;
1286 my $self = shift;
fe3ae272 1287 if ($self->{bindtype} eq 'columns') {
c94a6c93 1288 for (@_) {
1289 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
3a06278c 1290 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
fe3ae272 1291 }
1292 }
1293 }
1294}
1295
96449e8e 1296sub _join_sql_clauses {
1297 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1298
1299 if (@$clauses_aref > 1) {
1300 my $join = " " . $self->_sqlcase($logic) . " ";
1301 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1302 return ($sql, @$bind_aref);
1303 }
1304 elsif (@$clauses_aref) {
1305 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1306 }
1307 else {
1308 return (); # if no SQL, ignore @$bind_aref
1309 }
1310}
1311
1312
1313# Fix SQL case, if so requested
1314sub _sqlcase {
96449e8e 1315 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1316 # don't touch the argument ... crooked logic, but let's not change it!
07d7c35c 1317 return $_[0]->{case} ? $_[1] : uc($_[1]);
96449e8e 1318}
1319
1320
1321#======================================================================
1322# DISPATCHING FROM REFKIND
1323#======================================================================
1324
1325sub _refkind {
1326 my ($self, $data) = @_;
96449e8e 1327
955e77ca 1328 return 'UNDEF' unless defined $data;
1329
1330 # blessed objects are treated like scalars
1331 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1332
1333 return 'SCALAR' unless $ref;
1334
1335 my $n_steps = 1;
1336 while ($ref eq 'REF') {
96449e8e 1337 $data = $$data;
955e77ca 1338 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1339 $n_steps++ if $ref;
96449e8e 1340 }
1341
848556bc 1342 return ($ref||'SCALAR') . ('REF' x $n_steps);
96449e8e 1343}
1344
1345sub _try_refkind {
1346 my ($self, $data) = @_;
1347 my @try = ($self->_refkind($data));
1348 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1349 push @try, 'FALLBACK';
955e77ca 1350 return \@try;
96449e8e 1351}
1352
1353sub _METHOD_FOR_refkind {
1354 my ($self, $meth_prefix, $data) = @_;
f39eaa60 1355
1356 my $method;
955e77ca 1357 for (@{$self->_try_refkind($data)}) {
f39eaa60 1358 $method = $self->can($meth_prefix."_".$_)
1359 and last;
1360 }
1361
1362 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
96449e8e 1363}
1364
1365
1366sub _SWITCH_refkind {
1367 my ($self, $data, $dispatch_table) = @_;
1368
f39eaa60 1369 my $coderef;
955e77ca 1370 for (@{$self->_try_refkind($data)}) {
f39eaa60 1371 $coderef = $dispatch_table->{$_}
1372 and last;
1373 }
1374
1375 puke "no dispatch entry for ".$self->_refkind($data)
1376 unless $coderef;
1377
96449e8e 1378 $coderef->();
1379}
1380
1381
1382
1383
1384#======================================================================
1385# VALUES, GENERATE, AUTOLOAD
1386#======================================================================
1387
1388# LDNOTE: original code from nwiger, didn't touch code in that section
1389# I feel the AUTOLOAD stuff should not be the default, it should
1390# only be activated on explicit demand by user.
1391
1392sub values {
1393 my $self = shift;
1394 my $data = shift || return;
1395 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1396 unless ref $data eq 'HASH';
bab725ce 1397
1398 my @all_bind;
1399 foreach my $k ( sort keys %$data ) {
1400 my $v = $data->{$k};
1401 $self->_SWITCH_refkind($v, {
9d48860e 1402 ARRAYREF => sub {
bab725ce 1403 if ($self->{array_datatypes}) { # array datatype
1404 push @all_bind, $self->_bindtype($k, $v);
1405 }
1406 else { # literal SQL with bind
1407 my ($sql, @bind) = @$v;
1408 $self->_assert_bindval_matches_bindtype(@bind);
1409 push @all_bind, @bind;
1410 }
1411 },
1412 ARRAYREFREF => sub { # literal SQL with bind
1413 my ($sql, @bind) = @${$v};
1414 $self->_assert_bindval_matches_bindtype(@bind);
1415 push @all_bind, @bind;
1416 },
1417 SCALARREF => sub { # literal SQL without bind
1418 },
1419 SCALAR_or_UNDEF => sub {
1420 push @all_bind, $self->_bindtype($k, $v);
1421 },
1422 });
1423 }
1424
1425 return @all_bind;
96449e8e 1426}
1427
1428sub generate {
1429 my $self = shift;
1430
1431 my(@sql, @sqlq, @sqlv);
1432
1433 for (@_) {
1434 my $ref = ref $_;
1435 if ($ref eq 'HASH') {
1436 for my $k (sort keys %$_) {
1437 my $v = $_->{$k};
1438 my $r = ref $v;
1439 my $label = $self->_quote($k);
1440 if ($r eq 'ARRAY') {
fe3ae272 1441 # literal SQL with bind
1442 my ($sql, @bind) = @$v;
1443 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 1444 push @sqlq, "$label = $sql";
fe3ae272 1445 push @sqlv, @bind;
96449e8e 1446 } elsif ($r eq 'SCALAR') {
fe3ae272 1447 # literal SQL without bind
96449e8e 1448 push @sqlq, "$label = $$v";
9d48860e 1449 } else {
96449e8e 1450 push @sqlq, "$label = ?";
1451 push @sqlv, $self->_bindtype($k, $v);
1452 }
1453 }
1454 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1455 } elsif ($ref eq 'ARRAY') {
1456 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1457 for my $v (@$_) {
1458 my $r = ref $v;
fe3ae272 1459 if ($r eq 'ARRAY') { # literal SQL with bind
1460 my ($sql, @bind) = @$v;
1461 $self->_assert_bindval_matches_bindtype(@bind);
1462 push @sqlq, $sql;
1463 push @sqlv, @bind;
1464 } elsif ($r eq 'SCALAR') { # literal SQL without bind
96449e8e 1465 # embedded literal SQL
1466 push @sqlq, $$v;
9d48860e 1467 } else {
96449e8e 1468 push @sqlq, '?';
1469 push @sqlv, $v;
1470 }
1471 }
1472 push @sql, '(' . join(', ', @sqlq) . ')';
1473 } elsif ($ref eq 'SCALAR') {
1474 # literal SQL
1475 push @sql, $$_;
1476 } else {
1477 # strings get case twiddled
1478 push @sql, $self->_sqlcase($_);
1479 }
1480 }
1481
1482 my $sql = join ' ', @sql;
1483
1484 # this is pretty tricky
1485 # if ask for an array, return ($stmt, @bind)
1486 # otherwise, s/?/shift @sqlv/ to put it inline
1487 if (wantarray) {
1488 return ($sql, @sqlv);
1489 } else {
1490 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1491 ref $d ? $d->[1] : $d/e;
1492 return $sql;
1493 }
1494}
1495
1496
1497sub DESTROY { 1 }
1498
1499sub AUTOLOAD {
1500 # This allows us to check for a local, then _form, attr
1501 my $self = shift;
1502 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1503 return $self->generate($name, @_);
1504}
1505
15061;
1507
1508
1509
1510__END__
32eab2da 1511
1512=head1 NAME
1513
1514SQL::Abstract - Generate SQL from Perl data structures
1515
1516=head1 SYNOPSIS
1517
1518 use SQL::Abstract;
1519
1520 my $sql = SQL::Abstract->new;
1521
521647e7 1522 my($stmt, @bind) = $sql->select($source, \@fields, \%where, \@order);
32eab2da 1523
1524 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1525
1526 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1527
1528 my($stmt, @bind) = $sql->delete($table, \%where);
1529
1530 # Then, use these in your DBI statements
1531 my $sth = $dbh->prepare($stmt);
1532 $sth->execute(@bind);
1533
1534 # Just generate the WHERE clause
abe72f94 1535 my($stmt, @bind) = $sql->where(\%where, \@order);
32eab2da 1536
1537 # Return values in the same order, for hashed queries
1538 # See PERFORMANCE section for more details
1539 my @bind = $sql->values(\%fieldvals);
1540
1541=head1 DESCRIPTION
1542
1543This module was inspired by the excellent L<DBIx::Abstract>.
1544However, in using that module I found that what I really wanted
1545to do was generate SQL, but still retain complete control over my
1546statement handles and use the DBI interface. So, I set out to
1547create an abstract SQL generation module.
1548
1549While based on the concepts used by L<DBIx::Abstract>, there are
1550several important differences, especially when it comes to WHERE
1551clauses. I have modified the concepts used to make the SQL easier
1552to generate from Perl data structures and, IMO, more intuitive.
1553The underlying idea is for this module to do what you mean, based
1554on the data structures you provide it. The big advantage is that
1555you don't have to modify your code every time your data changes,
1556as this module figures it out.
1557
1558To begin with, an SQL INSERT is as easy as just specifying a hash
1559of C<key=value> pairs:
1560
1561 my %data = (
1562 name => 'Jimbo Bobson',
1563 phone => '123-456-7890',
1564 address => '42 Sister Lane',
1565 city => 'St. Louis',
1566 state => 'Louisiana',
1567 );
1568
1569The SQL can then be generated with this:
1570
1571 my($stmt, @bind) = $sql->insert('people', \%data);
1572
1573Which would give you something like this:
1574
1575 $stmt = "INSERT INTO people
1576 (address, city, name, phone, state)
1577 VALUES (?, ?, ?, ?, ?)";
1578 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1579 '123-456-7890', 'Louisiana');
1580
1581These are then used directly in your DBI code:
1582
1583 my $sth = $dbh->prepare($stmt);
1584 $sth->execute(@bind);
1585
96449e8e 1586=head2 Inserting and Updating Arrays
1587
1588If your database has array types (like for example Postgres),
1589activate the special option C<< array_datatypes => 1 >>
9d48860e 1590when creating the C<SQL::Abstract> object.
96449e8e 1591Then you may use an arrayref to insert and update database array types:
1592
1593 my $sql = SQL::Abstract->new(array_datatypes => 1);
1594 my %data = (
1595 planets => [qw/Mercury Venus Earth Mars/]
1596 );
9d48860e 1597
96449e8e 1598 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1599
1600This results in:
1601
1602 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1603
1604 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1605
1606
1607=head2 Inserting and Updating SQL
1608
1609In order to apply SQL functions to elements of your C<%data> you may
1610specify a reference to an arrayref for the given hash value. For example,
1611if you need to execute the Oracle C<to_date> function on a value, you can
1612say something like this:
32eab2da 1613
1614 my %data = (
1615 name => 'Bill',
96449e8e 1616 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
9d48860e 1617 );
32eab2da 1618
1619The first value in the array is the actual SQL. Any other values are
1620optional and would be included in the bind values array. This gives
1621you:
1622
1623 my($stmt, @bind) = $sql->insert('people', \%data);
1624
9d48860e 1625 $stmt = "INSERT INTO people (name, date_entered)
32eab2da 1626 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1627 @bind = ('Bill', '03/02/2003');
1628
1629An UPDATE is just as easy, all you change is the name of the function:
1630
1631 my($stmt, @bind) = $sql->update('people', \%data);
1632
1633Notice that your C<%data> isn't touched; the module will generate
1634the appropriately quirky SQL for you automatically. Usually you'll
1635want to specify a WHERE clause for your UPDATE, though, which is
1636where handling C<%where> hashes comes in handy...
1637
96449e8e 1638=head2 Complex where statements
1639
32eab2da 1640This module can generate pretty complicated WHERE statements
1641easily. For example, simple C<key=value> pairs are taken to mean
1642equality, and if you want to see if a field is within a set
1643of values, you can use an arrayref. Let's say we wanted to
1644SELECT some data based on this criteria:
1645
1646 my %where = (
1647 requestor => 'inna',
1648 worker => ['nwiger', 'rcwe', 'sfz'],
1649 status => { '!=', 'completed' }
1650 );
1651
1652 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1653
1654The above would give you something like this:
1655
1656 $stmt = "SELECT * FROM tickets WHERE
1657 ( requestor = ? ) AND ( status != ? )
1658 AND ( worker = ? OR worker = ? OR worker = ? )";
1659 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1660
1661Which you could then use in DBI code like so:
1662
1663 my $sth = $dbh->prepare($stmt);
1664 $sth->execute(@bind);
1665
1666Easy, eh?
1667
1668=head1 FUNCTIONS
1669
1670The functions are simple. There's one for each major SQL operation,
1671and a constructor you use first. The arguments are specified in a
9d48860e 1672similar order to each function (table, then fields, then a where
32eab2da 1673clause) to try and simplify things.
1674
83cab70b 1675
83cab70b 1676
32eab2da 1677
1678=head2 new(option => 'value')
1679
1680The C<new()> function takes a list of options and values, and returns
1681a new B<SQL::Abstract> object which can then be used to generate SQL
1682through the methods below. The options accepted are:
1683
1684=over
1685
1686=item case
1687
1688If set to 'lower', then SQL will be generated in all lowercase. By
1689default SQL is generated in "textbook" case meaning something like:
1690
1691 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1692
96449e8e 1693Any setting other than 'lower' is ignored.
1694
32eab2da 1695=item cmp
1696
1697This determines what the default comparison operator is. By default
1698it is C<=>, meaning that a hash like this:
1699
1700 %where = (name => 'nwiger', email => 'nate@wiger.org');
1701
1702Will generate SQL like this:
1703
1704 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1705
1706However, you may want loose comparisons by default, so if you set
1707C<cmp> to C<like> you would get SQL such as:
1708
1709 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1710
3af02ccb 1711You can also override the comparison on an individual basis - see
32eab2da 1712the huge section on L</"WHERE CLAUSES"> at the bottom.
1713
96449e8e 1714=item sqltrue, sqlfalse
1715
1716Expressions for inserting boolean values within SQL statements.
6e0c6552 1717By default these are C<1=1> and C<1=0>. They are used
1718by the special operators C<-in> and C<-not_in> for generating
1719correct SQL even when the argument is an empty array (see below).
96449e8e 1720
32eab2da 1721=item logic
1722
1723This determines the default logical operator for multiple WHERE
7cac25e6 1724statements in arrays or hashes. If absent, the default logic is "or"
1725for arrays, and "and" for hashes. This means that a WHERE
32eab2da 1726array of the form:
1727
1728 @where = (
9d48860e 1729 event_date => {'>=', '2/13/99'},
1730 event_date => {'<=', '4/24/03'},
32eab2da 1731 );
1732
7cac25e6 1733will generate SQL like this:
32eab2da 1734
1735 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1736
1737This is probably not what you want given this query, though (look
1738at the dates). To change the "OR" to an "AND", simply specify:
1739
1740 my $sql = SQL::Abstract->new(logic => 'and');
1741
1742Which will change the above C<WHERE> to:
1743
1744 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1745
96449e8e 1746The logic can also be changed locally by inserting
7cac25e6 1747a modifier in front of an arrayref :
96449e8e 1748
9d48860e 1749 @where = (-and => [event_date => {'>=', '2/13/99'},
7cac25e6 1750 event_date => {'<=', '4/24/03'} ]);
96449e8e 1751
1752See the L</"WHERE CLAUSES"> section for explanations.
1753
32eab2da 1754=item convert
1755
1756This will automatically convert comparisons using the specified SQL
1757function for both column and value. This is mostly used with an argument
1758of C<upper> or C<lower>, so that the SQL will have the effect of
1759case-insensitive "searches". For example, this:
1760
1761 $sql = SQL::Abstract->new(convert => 'upper');
1762 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1763
1764Will turn out the following SQL:
1765
1766 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1767
1768The conversion can be C<upper()>, C<lower()>, or any other SQL function
1769that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1770not validate this option; it will just pass through what you specify verbatim).
1771
1772=item bindtype
1773
1774This is a kludge because many databases suck. For example, you can't
1775just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1776Instead, you have to use C<bind_param()>:
1777
1778 $sth->bind_param(1, 'reg data');
1779 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1780
1781The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1782which loses track of which field each slot refers to. Fear not.
1783
1784If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1785Currently, you can specify either C<normal> (default) or C<columns>. If you
1786specify C<columns>, you will get an array that looks like this:
1787
1788 my $sql = SQL::Abstract->new(bindtype => 'columns');
1789 my($stmt, @bind) = $sql->insert(...);
1790
1791 @bind = (
1792 [ 'column1', 'value1' ],
1793 [ 'column2', 'value2' ],
1794 [ 'column3', 'value3' ],
1795 );
1796
1797You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 1798
32eab2da 1799 $sth->prepare($stmt);
1800 my $i = 1;
1801 for (@bind) {
1802 my($col, $data) = @$_;
1803 if ($col eq 'details' || $col eq 'comments') {
1804 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1805 } elsif ($col eq 'image') {
1806 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1807 } else {
1808 $sth->bind_param($i, $data);
1809 }
1810 $i++;
1811 }
1812 $sth->execute; # execute without @bind now
1813
1814Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1815Basically, the advantage is still that you don't have to care which fields
1816are or are not included. You could wrap that above C<for> loop in a simple
1817sub called C<bind_fields()> or something and reuse it repeatedly. You still
1818get a layer of abstraction over manual SQL specification.
1819
deb148a2 1820Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
1821construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1822will expect the bind values in this format.
1823
32eab2da 1824=item quote_char
1825
1826This is the character that a table or column name will be quoted
9d48860e 1827with. By default this is an empty string, but you could set it to
32eab2da 1828the character C<`>, to generate SQL like this:
1829
1830 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1831
96449e8e 1832Alternatively, you can supply an array ref of two items, the first being the left
1833hand quote character, and the second the right hand quote character. For
1834example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1835that generates SQL like this:
1836
1837 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1838
9d48860e 1839Quoting is useful if you have tables or columns names that are reserved
96449e8e 1840words in your database's SQL dialect.
32eab2da 1841
1842=item name_sep
1843
1844This is the character that separates a table and column name. It is
1845necessary to specify this when the C<quote_char> option is selected,
1846so that tables and column names can be individually quoted like this:
1847
1848 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1849
b6251592 1850=item injection_guard
1851
1852A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1853column name specified in a query structure. This is a safety mechanism to avoid
1854injection attacks when mishandling user input e.g.:
1855
1856 my %condition_as_column_value_pairs = get_values_from_user();
1857 $sqla->select( ... , \%condition_as_column_value_pairs );
1858
1859If the expression matches an exception is thrown. Note that literal SQL
1860supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1861
1862Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1863
96449e8e 1864=item array_datatypes
32eab2da 1865
9d48860e 1866When this option is true, arrayrefs in INSERT or UPDATE are
1867interpreted as array datatypes and are passed directly
96449e8e 1868to the DBI layer.
1869When this option is false, arrayrefs are interpreted
1870as literal SQL, just like refs to arrayrefs
1871(but this behavior is for backwards compatibility; when writing
1872new queries, use the "reference to arrayref" syntax
1873for literal SQL).
32eab2da 1874
32eab2da 1875
96449e8e 1876=item special_ops
32eab2da 1877
9d48860e 1878Takes a reference to a list of "special operators"
96449e8e 1879to extend the syntax understood by L<SQL::Abstract>.
1880See section L</"SPECIAL OPERATORS"> for details.
32eab2da 1881
59f23b3d 1882=item unary_ops
1883
9d48860e 1884Takes a reference to a list of "unary operators"
59f23b3d 1885to extend the syntax understood by L<SQL::Abstract>.
1886See section L</"UNARY OPERATORS"> for details.
1887
32eab2da 1888
32eab2da 1889
96449e8e 1890=back
32eab2da 1891
02288357 1892=head2 insert($table, \@values || \%fieldvals, \%options)
32eab2da 1893
1894This is the simplest function. You simply give it a table name
1895and either an arrayref of values or hashref of field/value pairs.
1896It returns an SQL INSERT statement and a list of bind values.
96449e8e 1897See the sections on L</"Inserting and Updating Arrays"> and
1898L</"Inserting and Updating SQL"> for information on how to insert
1899with those data types.
32eab2da 1900
02288357 1901The optional C<\%options> hash reference may contain additional
1902options to generate the insert SQL. Currently supported options
1903are:
1904
1905=over 4
1906
1907=item returning
1908
1909Takes either a scalar of raw SQL fields, or an array reference of
1910field names, and adds on an SQL C<RETURNING> statement at the end.
1911This allows you to return data generated by the insert statement
1912(such as row IDs) without performing another C<SELECT> statement.
1913Note, however, this is not part of the SQL standard and may not
1914be supported by all database engines.
1915
1916=back
1917
32eab2da 1918=head2 update($table, \%fieldvals, \%where)
1919
1920This takes a table, hashref of field/value pairs, and an optional
86298391 1921hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 1922of bind values.
96449e8e 1923See the sections on L</"Inserting and Updating Arrays"> and
1924L</"Inserting and Updating SQL"> for information on how to insert
1925with those data types.
32eab2da 1926
96449e8e 1927=head2 select($source, $fields, $where, $order)
32eab2da 1928
9d48860e 1929This returns a SQL SELECT statement and associated list of bind values, as
96449e8e 1930specified by the arguments :
32eab2da 1931
96449e8e 1932=over
32eab2da 1933
96449e8e 1934=item $source
32eab2da 1935
9d48860e 1936Specification of the 'FROM' part of the statement.
96449e8e 1937The argument can be either a plain scalar (interpreted as a table
1938name, will be quoted), or an arrayref (interpreted as a list
1939of table names, joined by commas, quoted), or a scalarref
1940(literal table name, not quoted), or a ref to an arrayref
1941(list of literal table names, joined by commas, not quoted).
32eab2da 1942
96449e8e 1943=item $fields
32eab2da 1944
9d48860e 1945Specification of the list of fields to retrieve from
96449e8e 1946the source.
1947The argument can be either an arrayref (interpreted as a list
9d48860e 1948of field names, will be joined by commas and quoted), or a
96449e8e 1949plain scalar (literal SQL, not quoted).
521647e7 1950Please observe that this API is not as flexible as that of
1951the first argument C<$source>, for backwards compatibility reasons.
32eab2da 1952
96449e8e 1953=item $where
32eab2da 1954
96449e8e 1955Optional argument to specify the WHERE part of the query.
1956The argument is most often a hashref, but can also be
9d48860e 1957an arrayref or plain scalar --
96449e8e 1958see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 1959
96449e8e 1960=item $order
32eab2da 1961
96449e8e 1962Optional argument to specify the ORDER BY part of the query.
9d48860e 1963The argument can be a scalar, a hashref or an arrayref
96449e8e 1964-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1965for details.
32eab2da 1966
96449e8e 1967=back
32eab2da 1968
32eab2da 1969
1970=head2 delete($table, \%where)
1971
86298391 1972This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 1973It returns an SQL DELETE statement and list of bind values.
1974
32eab2da 1975=head2 where(\%where, \@order)
1976
1977This is used to generate just the WHERE clause. For example,
1978if you have an arbitrary data structure and know what the
1979rest of your SQL is going to look like, but want an easy way
1980to produce a WHERE clause, use this. It returns an SQL WHERE
1981clause and list of bind values.
1982
32eab2da 1983
1984=head2 values(\%data)
1985
1986This just returns the values from the hash C<%data>, in the same
1987order that would be returned from any of the other above queries.
1988Using this allows you to markedly speed up your queries if you
1989are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1990
32eab2da 1991=head2 generate($any, 'number', $of, \@data, $struct, \%types)
1992
1993Warning: This is an experimental method and subject to change.
1994
1995This returns arbitrarily generated SQL. It's a really basic shortcut.
1996It will return two different things, depending on return context:
1997
1998 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1999 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2000
2001These would return the following:
2002
2003 # First calling form
2004 $stmt = "CREATE TABLE test (?, ?)";
2005 @bind = (field1, field2);
2006
2007 # Second calling form
2008 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2009
2010Depending on what you're trying to do, it's up to you to choose the correct
2011format. In this example, the second form is what you would want.
2012
2013By the same token:
2014
2015 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2016
2017Might give you:
2018
2019 ALTER SESSION SET nls_date_format = 'MM/YY'
2020
2021You get the idea. Strings get their case twiddled, but everything
2022else remains verbatim.
2023
32eab2da 2024=head1 WHERE CLAUSES
2025
96449e8e 2026=head2 Introduction
2027
32eab2da 2028This module uses a variation on the idea from L<DBIx::Abstract>. It
2029is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2030module is that things in arrays are OR'ed, and things in hashes
2031are AND'ed.>
2032
2033The easiest way to explain is to show lots of examples. After
2034each C<%where> hash shown, it is assumed you used:
2035
2036 my($stmt, @bind) = $sql->where(\%where);
2037
2038However, note that the C<%where> hash can be used directly in any
2039of the other functions as well, as described above.
2040
96449e8e 2041=head2 Key-value pairs
2042
32eab2da 2043So, let's get started. To begin, a simple hash:
2044
2045 my %where = (
2046 user => 'nwiger',
2047 status => 'completed'
2048 );
2049
2050Is converted to SQL C<key = val> statements:
2051
2052 $stmt = "WHERE user = ? AND status = ?";
2053 @bind = ('nwiger', 'completed');
2054
2055One common thing I end up doing is having a list of values that
2056a field can be in. To do this, simply specify a list inside of
2057an arrayref:
2058
2059 my %where = (
2060 user => 'nwiger',
2061 status => ['assigned', 'in-progress', 'pending'];
2062 );
2063
2064This simple code will create the following:
9d48860e 2065
32eab2da 2066 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2067 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2068
9d48860e 2069A field associated to an empty arrayref will be considered a
7cac25e6 2070logical false and will generate 0=1.
8a68b5be 2071
b864ba9b 2072=head2 Tests for NULL values
2073
2074If the value part is C<undef> then this is converted to SQL <IS NULL>
2075
2076 my %where = (
2077 user => 'nwiger',
2078 status => undef,
2079 );
2080
2081becomes:
2082
2083 $stmt = "WHERE user = ? AND status IS NULL";
2084 @bind = ('nwiger');
2085
e9614080 2086To test if a column IS NOT NULL:
2087
2088 my %where = (
2089 user => 'nwiger',
2090 status => { '!=', undef },
2091 );
cc422895 2092
6e0c6552 2093=head2 Specific comparison operators
96449e8e 2094
32eab2da 2095If you want to specify a different type of operator for your comparison,
2096you can use a hashref for a given column:
2097
2098 my %where = (
2099 user => 'nwiger',
2100 status => { '!=', 'completed' }
2101 );
2102
2103Which would generate:
2104
2105 $stmt = "WHERE user = ? AND status != ?";
2106 @bind = ('nwiger', 'completed');
2107
2108To test against multiple values, just enclose the values in an arrayref:
2109
96449e8e 2110 status => { '=', ['assigned', 'in-progress', 'pending'] };
2111
f2d5020d 2112Which would give you:
96449e8e 2113
2114 "WHERE status = ? OR status = ? OR status = ?"
2115
2116
2117The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 2118into an C<AND> of its elements:
2119
2120 my %where = (
2121 user => 'nwiger',
2122 status => { '!=', 'completed', -not_like => 'pending%' }
2123 );
2124
2125 # Or more dynamically, like from a form
2126 $where{user} = 'nwiger';
2127 $where{status}{'!='} = 'completed';
2128 $where{status}{'-not_like'} = 'pending%';
2129
2130 # Both generate this
2131 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2132 @bind = ('nwiger', 'completed', 'pending%');
2133
96449e8e 2134
32eab2da 2135To get an OR instead, you can combine it with the arrayref idea:
2136
2137 my %where => (
2138 user => 'nwiger',
1a6f2a03 2139 priority => [ { '=', 2 }, { '>', 5 } ]
32eab2da 2140 );
2141
2142Which would generate:
2143
1a6f2a03 2144 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2145 @bind = ('2', '5', 'nwiger');
32eab2da 2146
44b9e502 2147If you want to include literal SQL (with or without bind values), just use a
2148scalar reference or array reference as the value:
2149
2150 my %where = (
2151 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2152 date_expires => { '<' => \"now()" }
2153 );
2154
2155Which would generate:
2156
2157 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
2158 @bind = ('11/26/2008');
2159
96449e8e 2160
2161=head2 Logic and nesting operators
2162
2163In the example above,
2164there is a subtle trap if you want to say something like
32eab2da 2165this (notice the C<AND>):
2166
2167 WHERE priority != ? AND priority != ?
2168
2169Because, in Perl you I<can't> do this:
2170
2171 priority => { '!=', 2, '!=', 1 }
2172
2173As the second C<!=> key will obliterate the first. The solution
2174is to use the special C<-modifier> form inside an arrayref:
2175
9d48860e 2176 priority => [ -and => {'!=', 2},
96449e8e 2177 {'!=', 1} ]
2178
32eab2da 2179
2180Normally, these would be joined by C<OR>, but the modifier tells it
2181to use C<AND> instead. (Hint: You can use this in conjunction with the
2182C<logic> option to C<new()> in order to change the way your queries
2183work by default.) B<Important:> Note that the C<-modifier> goes
2184B<INSIDE> the arrayref, as an extra first element. This will
2185B<NOT> do what you think it might:
2186
2187 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2188
2189Here is a quick list of equivalencies, since there is some overlap:
2190
2191 # Same
2192 status => {'!=', 'completed', 'not like', 'pending%' }
2193 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2194
2195 # Same
2196 status => {'=', ['assigned', 'in-progress']}
2197 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2198 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2199
e3f9dff4 2200
2201
96449e8e 2202=head2 Special operators : IN, BETWEEN, etc.
2203
32eab2da 2204You can also use the hashref format to compare a list of fields using the
2205C<IN> comparison operator, by specifying the list as an arrayref:
2206
2207 my %where = (
2208 status => 'completed',
2209 reportid => { -in => [567, 2335, 2] }
2210 );
2211
2212Which would generate:
2213
2214 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2215 @bind = ('completed', '567', '2335', '2');
2216
9d48860e 2217The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
96449e8e 2218the same way.
2219
6e0c6552 2220If the argument to C<-in> is an empty array, 'sqlfalse' is generated
2221(by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
2222'sqltrue' (by default : C<1=1>).
2223
e41c3bdd 2224In addition to the array you can supply a chunk of literal sql or
2225literal sql with bind:
6e0c6552 2226
e41c3bdd 2227 my %where = {
2228 customer => { -in => \[
2229 'SELECT cust_id FROM cust WHERE balance > ?',
2230 2000,
2231 ],
2232 status => { -in => \'SELECT status_codes FROM states' },
2233 };
6e0c6552 2234
e41c3bdd 2235would generate:
2236
2237 $stmt = "WHERE (
2238 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2239 AND status IN ( SELECT status_codes FROM states )
2240 )";
2241 @bind = ('2000');
2242
0dfd2442 2243Finally, if the argument to C<-in> is not a reference, it will be
2244treated as a single-element array.
e41c3bdd 2245
2246Another pair of operators is C<-between> and C<-not_between>,
96449e8e 2247used with an arrayref of two values:
32eab2da 2248
2249 my %where = (
2250 user => 'nwiger',
2251 completion_date => {
2252 -not_between => ['2002-10-01', '2003-02-06']
2253 }
2254 );
2255
2256Would give you:
2257
2258 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2259
e41c3bdd 2260Just like with C<-in> all plausible combinations of literal SQL
2261are possible:
2262
2263 my %where = {
2264 start0 => { -between => [ 1, 2 ] },
2265 start1 => { -between => \["? AND ?", 1, 2] },
2266 start2 => { -between => \"lower(x) AND upper(y)" },
9d48860e 2267 start3 => { -between => [
e41c3bdd 2268 \"lower(x)",
2269 \["upper(?)", 'stuff' ],
2270 ] },
2271 };
2272
2273Would give you:
2274
2275 $stmt = "WHERE (
2276 ( start0 BETWEEN ? AND ? )
2277 AND ( start1 BETWEEN ? AND ? )
2278 AND ( start2 BETWEEN lower(x) AND upper(y) )
2279 AND ( start3 BETWEEN lower(x) AND upper(?) )
2280 )";
2281 @bind = (1, 2, 1, 2, 'stuff');
2282
2283
9d48860e 2284These are the two builtin "special operators"; but the
96449e8e 2285list can be expanded : see section L</"SPECIAL OPERATORS"> below.
2286
59f23b3d 2287=head2 Unary operators: bool
97a920ef 2288
2289If you wish to test against boolean columns or functions within your
2290database you can use the C<-bool> and C<-not_bool> operators. For
2291example to test the column C<is_user> being true and the column
827bb0eb 2292C<is_enabled> being false you would use:-
97a920ef 2293
2294 my %where = (
2295 -bool => 'is_user',
2296 -not_bool => 'is_enabled',
2297 );
2298
2299Would give you:
2300
277b5d3f 2301 WHERE is_user AND NOT is_enabled
97a920ef 2302
0b604e9d 2303If a more complex combination is required, testing more conditions,
2304then you should use the and/or operators:-
2305
2306 my %where = (
2307 -and => [
2308 -bool => 'one',
2309 -bool => 'two',
2310 -bool => 'three',
2311 -not_bool => 'four',
2312 ],
2313 );
2314
2315Would give you:
2316
2317 WHERE one AND two AND three AND NOT four
97a920ef 2318
2319
107b72f1 2320=head2 Nested conditions, -and/-or prefixes
96449e8e 2321
32eab2da 2322So far, we've seen how multiple conditions are joined with a top-level
2323C<AND>. We can change this by putting the different conditions we want in
2324hashes and then putting those hashes in an array. For example:
2325
2326 my @where = (
2327 {
2328 user => 'nwiger',
2329 status => { -like => ['pending%', 'dispatched'] },
2330 },
2331 {
2332 user => 'robot',
2333 status => 'unassigned',
2334 }
2335 );
2336
2337This data structure would create the following:
2338
2339 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2340 OR ( user = ? AND status = ? ) )";
2341 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2342
107b72f1 2343
48d9f5f8 2344Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
2345to change the logic inside :
32eab2da 2346
2347 my @where = (
2348 -and => [
2349 user => 'nwiger',
48d9f5f8 2350 [
2351 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2352 -or => { workhrs => {'<', 50}, geo => 'EURO' },
32eab2da 2353 ],
2354 ],
2355 );
2356
2357That would yield:
2358
48d9f5f8 2359 WHERE ( user = ? AND (
2360 ( workhrs > ? AND geo = ? )
2361 OR ( workhrs < ? OR geo = ? )
2362 ) )
107b72f1 2363
cc422895 2364=head3 Algebraic inconsistency, for historical reasons
107b72f1 2365
7cac25e6 2366C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2367operator goes C<outside> of the nested structure; whereas when connecting
2368several constraints on one column, the C<-and> operator goes
2369C<inside> the arrayref. Here is an example combining both features :
2370
2371 my @where = (
2372 -and => [a => 1, b => 2],
2373 -or => [c => 3, d => 4],
2374 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2375 )
2376
2377yielding
2378
9d48860e 2379 WHERE ( ( ( a = ? AND b = ? )
2380 OR ( c = ? OR d = ? )
7cac25e6 2381 OR ( e LIKE ? AND e LIKE ? ) ) )
2382
107b72f1 2383This difference in syntax is unfortunate but must be preserved for
2384historical reasons. So be careful : the two examples below would
2385seem algebraically equivalent, but they are not
2386
9d48860e 2387 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
107b72f1 2388 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
2389
9d48860e 2390 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
107b72f1 2391 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
2392
7cac25e6 2393
cc422895 2394=head2 Literal SQL and value type operators
96449e8e 2395
cc422895 2396The basic premise of SQL::Abstract is that in WHERE specifications the "left
2397side" is a column name and the "right side" is a value (normally rendered as
2398a placeholder). This holds true for both hashrefs and arrayref pairs as you
2399see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2400alter this behavior. There are several ways of doing so.
e9614080 2401
cc422895 2402=head3 -ident
2403
2404This is a virtual operator that signals the string to its right side is an
2405identifier (a column name) and not a value. For example to compare two
2406columns you would write:
32eab2da 2407
e9614080 2408 my %where = (
2409 priority => { '<', 2 },
cc422895 2410 requestor => { -ident => 'submitter' },
e9614080 2411 );
2412
2413which creates:
2414
2415 $stmt = "WHERE priority < ? AND requestor = submitter";
2416 @bind = ('2');
2417
cc422895 2418If you are maintaining legacy code you may see a different construct as
2419described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2420code.
2421
2422=head3 -value
e9614080 2423
cc422895 2424This is a virtual operator that signals that the construct to its right side
2425is a value to be passed to DBI. This is for example necessary when you want
2426to write a where clause against an array (for RDBMS that support such
2427datatypes). For example:
e9614080 2428
32eab2da 2429 my %where = (
cc422895 2430 array => { -value => [1, 2, 3] }
32eab2da 2431 );
2432
cc422895 2433will result in:
32eab2da 2434
cc422895 2435 $stmt = 'WHERE array = ?';
2436 @bind = ([1, 2, 3]);
32eab2da 2437
cc422895 2438Note that if you were to simply say:
32eab2da 2439
2440 my %where = (
cc422895 2441 array => [1, 2, 3]
32eab2da 2442 );
2443
3af02ccb 2444the result would probably not be what you wanted:
cc422895 2445
2446 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2447 @bind = (1, 2, 3);
2448
2449=head3 Literal SQL
96449e8e 2450
cc422895 2451Finally, sometimes only literal SQL will do. To include a random snippet
2452of SQL verbatim, you specify it as a scalar reference. Consider this only
2453as a last resort. Usually there is a better way. For example:
96449e8e 2454
2455 my %where = (
cc422895 2456 priority => { '<', 2 },
2457 requestor => { -in => \'(SELECT name FROM hitmen)' },
96449e8e 2458 );
2459
cc422895 2460Would create:
96449e8e 2461
cc422895 2462 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2463 @bind = (2);
2464
2465Note that in this example, you only get one bind parameter back, since
2466the verbatim SQL is passed as part of the statement.
2467
2468=head4 CAVEAT
2469
2470 Never use untrusted input as a literal SQL argument - this is a massive
2471 security risk (there is no way to check literal snippets for SQL
2472 injections and other nastyness). If you need to deal with untrusted input
2473 use literal SQL with placeholders as described next.
96449e8e 2474
cc422895 2475=head3 Literal SQL with placeholders and bind values (subqueries)
96449e8e 2476
2477If the literal SQL to be inserted has placeholders and bind values,
2478use a reference to an arrayref (yes this is a double reference --
2479not so common, but perfectly legal Perl). For example, to find a date
2480in Postgres you can use something like this:
2481
2482 my %where = (
2483 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
2484 )
2485
2486This would create:
2487
d2a8fe1a 2488 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 2489 @bind = ('10');
2490
deb148a2 2491Note that you must pass the bind values in the same format as they are returned
62552e7d 2492by L</where>. That means that if you set L</bindtype> to C<columns>, you must
26f2dca5 2493provide the bind values in the C<< [ column_meta => value ] >> format, where
2494C<column_meta> is an opaque scalar value; most commonly the column name, but
62552e7d 2495you can use any scalar value (including references and blessed references),
2496L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
2497to C<columns> the above example will look like:
deb148a2 2498
2499 my %where = (
2500 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
2501 )
96449e8e 2502
2503Literal SQL is especially useful for nesting parenthesized clauses in the
2504main SQL query. Here is a first example :
2505
2506 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2507 100, "foo%");
2508 my %where = (
2509 foo => 1234,
2510 bar => \["IN ($sub_stmt)" => @sub_bind],
2511 );
2512
2513This yields :
2514
9d48860e 2515 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
96449e8e 2516 WHERE c2 < ? AND c3 LIKE ?))";
2517 @bind = (1234, 100, "foo%");
2518
9d48860e 2519Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
96449e8e 2520are expressed in the same way. Of course the C<$sub_stmt> and
9d48860e 2521its associated bind values can be generated through a former call
96449e8e 2522to C<select()> :
2523
2524 my ($sub_stmt, @sub_bind)
9d48860e 2525 = $sql->select("t1", "c1", {c2 => {"<" => 100},
96449e8e 2526 c3 => {-like => "foo%"}});
2527 my %where = (
2528 foo => 1234,
2529 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2530 );
2531
2532In the examples above, the subquery was used as an operator on a column;
9d48860e 2533but the same principle also applies for a clause within the main C<%where>
96449e8e 2534hash, like an EXISTS subquery :
2535
9d48860e 2536 my ($sub_stmt, @sub_bind)
96449e8e 2537 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
48d9f5f8 2538 my %where = ( -and => [
96449e8e 2539 foo => 1234,
48d9f5f8 2540 \["EXISTS ($sub_stmt)" => @sub_bind],
2541 ]);
96449e8e 2542
2543which yields
2544
9d48860e 2545 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
96449e8e 2546 WHERE c1 = ? AND c2 > t0.c0))";
2547 @bind = (1234, 1);
2548
2549
9d48860e 2550Observe that the condition on C<c2> in the subquery refers to
2551column C<t0.c0> of the main query : this is I<not> a bind
2552value, so we have to express it through a scalar ref.
96449e8e 2553Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2554C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2555what we wanted here.
2556
96449e8e 2557Finally, here is an example where a subquery is used
2558for expressing unary negation:
2559
9d48860e 2560 my ($sub_stmt, @sub_bind)
96449e8e 2561 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2562 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2563 my %where = (
2564 lname => {like => '%son%'},
48d9f5f8 2565 \["NOT ($sub_stmt)" => @sub_bind],
96449e8e 2566 );
2567
2568This yields
2569
2570 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2571 @bind = ('%son%', 10, 20)
2572
cc422895 2573=head3 Deprecated usage of Literal SQL
2574
2575Below are some examples of archaic use of literal SQL. It is shown only as
2576reference for those who deal with legacy code. Each example has a much
2577better, cleaner and safer alternative that users should opt for in new code.
2578
2579=over
2580
2581=item *
2582
2583 my %where = ( requestor => \'IS NOT NULL' )
2584
2585 $stmt = "WHERE requestor IS NOT NULL"
2586
2587This used to be the way of generating NULL comparisons, before the handling
2588of C<undef> got formalized. For new code please use the superior syntax as
2589described in L</Tests for NULL values>.
96449e8e 2590
cc422895 2591=item *
2592
2593 my %where = ( requestor => \'= submitter' )
2594
2595 $stmt = "WHERE requestor = submitter"
2596
2597This used to be the only way to compare columns. Use the superior L</-ident>
2598method for all new code. For example an identifier declared in such a way
2599will be properly quoted if L</quote_char> is properly set, while the legacy
2600form will remain as supplied.
2601
2602=item *
2603
2604 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2605
2606 $stmt = "WHERE completed > ? AND is_ready"
2607 @bind = ('2012-12-21')
2608
2609Using an empty string literal used to be the only way to express a boolean.
2610For all new code please use the much more readable
2611L<-bool|/Unary operators: bool> operator.
2612
2613=back
96449e8e 2614
2615=head2 Conclusion
2616
32eab2da 2617These pages could go on for a while, since the nesting of the data
2618structures this module can handle are pretty much unlimited (the
2619module implements the C<WHERE> expansion as a recursive function
2620internally). Your best bet is to "play around" with the module a
2621little to see how the data structures behave, and choose the best
2622format for your data based on that.
2623
2624And of course, all the values above will probably be replaced with
2625variables gotten from forms or the command line. After all, if you
2626knew everything ahead of time, you wouldn't have to worry about
2627dynamically-generating SQL and could just hardwire it into your
2628script.
2629
86298391 2630=head1 ORDER BY CLAUSES
2631
9d48860e 2632Some functions take an order by clause. This can either be a scalar (just a
86298391 2633column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1cfa1db3 2634or an array of either of the two previous forms. Examples:
2635
952f9e2d 2636 Given | Will Generate
1cfa1db3 2637 ----------------------------------------------------------
952f9e2d 2638 |
2639 \'colA DESC' | ORDER BY colA DESC
2640 |
2641 'colA' | ORDER BY colA
2642 |
2643 [qw/colA colB/] | ORDER BY colA, colB
2644 |
2645 {-asc => 'colA'} | ORDER BY colA ASC
2646 |
2647 {-desc => 'colB'} | ORDER BY colB DESC
2648 |
2649 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2650 |
855e6047 2651 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
952f9e2d 2652 |
2653 [ |
2654 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
2655 { -desc => [qw/colB/], | colC ASC, colD ASC
2656 { -asc => [qw/colC colD/],|
2657 ] |
2658 ===========================================================
86298391 2659
96449e8e 2660
2661
2662=head1 SPECIAL OPERATORS
2663
e3f9dff4 2664 my $sqlmaker = SQL::Abstract->new(special_ops => [
3a2e1a5e 2665 {
2666 regex => qr/.../,
e3f9dff4 2667 handler => sub {
2668 my ($self, $field, $op, $arg) = @_;
2669 ...
3a2e1a5e 2670 },
2671 },
2672 {
2673 regex => qr/.../,
2674 handler => 'method_name',
e3f9dff4 2675 },
2676 ]);
2677
9d48860e 2678A "special operator" is a SQL syntactic clause that can be
e3f9dff4 2679applied to a field, instead of a usual binary operator.
9d48860e 2680For example :
e3f9dff4 2681
2682 WHERE field IN (?, ?, ?)
2683 WHERE field BETWEEN ? AND ?
2684 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 2685
e3f9dff4 2686Special operators IN and BETWEEN are fairly standard and therefore
3a2e1a5e 2687are builtin within C<SQL::Abstract> (as the overridable methods
2688C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2689like the MATCH .. AGAINST example above which is specific to MySQL,
2690you can write your own operator handlers - supply a C<special_ops>
2691argument to the C<new> method. That argument takes an arrayref of
2692operator definitions; each operator definition is a hashref with two
2693entries:
96449e8e 2694
e3f9dff4 2695=over
2696
2697=item regex
2698
2699the regular expression to match the operator
96449e8e 2700
e3f9dff4 2701=item handler
2702
3a2e1a5e 2703Either a coderef or a plain scalar method name. In both cases
2704the expected return is C<< ($sql, @bind) >>.
2705
2706When supplied with a method name, it is simply called on the
2707L<SQL::Abstract/> object as:
2708
2709 $self->$method_name ($field, $op, $arg)
2710
2711 Where:
2712
2713 $op is the part that matched the handler regex
2714 $field is the LHS of the operator
2715 $arg is the RHS
2716
2717When supplied with a coderef, it is called as:
2718
2719 $coderef->($self, $field, $op, $arg)
2720
e3f9dff4 2721
2722=back
2723
9d48860e 2724For example, here is an implementation
e3f9dff4 2725of the MATCH .. AGAINST syntax for MySQL
2726
2727 my $sqlmaker = SQL::Abstract->new(special_ops => [
9d48860e 2728
e3f9dff4 2729 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
9d48860e 2730 {regex => qr/^match$/i,
e3f9dff4 2731 handler => sub {
2732 my ($self, $field, $op, $arg) = @_;
2733 $arg = [$arg] if not ref $arg;
2734 my $label = $self->_quote($field);
2735 my ($placeholder) = $self->_convert('?');
2736 my $placeholders = join ", ", (($placeholder) x @$arg);
2737 my $sql = $self->_sqlcase('match') . " ($label) "
2738 . $self->_sqlcase('against') . " ($placeholders) ";
2739 my @bind = $self->_bindtype($field, @$arg);
2740 return ($sql, @bind);
2741 }
2742 },
9d48860e 2743
e3f9dff4 2744 ]);
96449e8e 2745
2746
59f23b3d 2747=head1 UNARY OPERATORS
2748
112b5232 2749 my $sqlmaker = SQL::Abstract->new(unary_ops => [
59f23b3d 2750 {
2751 regex => qr/.../,
2752 handler => sub {
2753 my ($self, $op, $arg) = @_;
2754 ...
2755 },
2756 },
2757 {
2758 regex => qr/.../,
2759 handler => 'method_name',
2760 },
2761 ]);
2762
9d48860e 2763A "unary operator" is a SQL syntactic clause that can be
59f23b3d 2764applied to a field - the operator goes before the field
2765
2766You can write your own operator handlers - supply a C<unary_ops>
2767argument to the C<new> method. That argument takes an arrayref of
2768operator definitions; each operator definition is a hashref with two
2769entries:
2770
2771=over
2772
2773=item regex
2774
2775the regular expression to match the operator
2776
2777=item handler
2778
2779Either a coderef or a plain scalar method name. In both cases
2780the expected return is C<< $sql >>.
2781
2782When supplied with a method name, it is simply called on the
2783L<SQL::Abstract/> object as:
2784
2785 $self->$method_name ($op, $arg)
2786
2787 Where:
2788
2789 $op is the part that matched the handler regex
2790 $arg is the RHS or argument of the operator
2791
2792When supplied with a coderef, it is called as:
2793
2794 $coderef->($self, $op, $arg)
2795
2796
2797=back
2798
2799
32eab2da 2800=head1 PERFORMANCE
2801
2802Thanks to some benchmarking by Mark Stosberg, it turns out that
2803this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2804I must admit this wasn't an intentional design issue, but it's a
2805byproduct of the fact that you get to control your C<DBI> handles
2806yourself.
2807
2808To maximize performance, use a code snippet like the following:
2809
2810 # prepare a statement handle using the first row
2811 # and then reuse it for the rest of the rows
2812 my($sth, $stmt);
2813 for my $href (@array_of_hashrefs) {
2814 $stmt ||= $sql->insert('table', $href);
2815 $sth ||= $dbh->prepare($stmt);
2816 $sth->execute($sql->values($href));
2817 }
2818
2819The reason this works is because the keys in your C<$href> are sorted
2820internally by B<SQL::Abstract>. Thus, as long as your data retains
2821the same structure, you only have to generate the SQL the first time
2822around. On subsequent queries, simply use the C<values> function provided
2823by this module to return your values in the correct order.
2824
b864ba9b 2825However this depends on the values having the same type - if, for
2826example, the values of a where clause may either have values
2827(resulting in sql of the form C<column = ?> with a single bind
2828value), or alternatively the values might be C<undef> (resulting in
2829sql of the form C<column IS NULL> with no bind value) then the
2830caching technique suggested will not work.
96449e8e 2831
32eab2da 2832=head1 FORMBUILDER
2833
2834If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2835really like this part (I do, at least). Building up a complex query
2836can be as simple as the following:
2837
2838 #!/usr/bin/perl
2839
2840 use CGI::FormBuilder;
2841 use SQL::Abstract;
2842
2843 my $form = CGI::FormBuilder->new(...);
2844 my $sql = SQL::Abstract->new;
2845
2846 if ($form->submitted) {
2847 my $field = $form->field;
2848 my $id = delete $field->{id};
2849 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2850 }
2851
2852Of course, you would still have to connect using C<DBI> to run the
2853query, but the point is that if you make your form look like your
2854table, the actual query script can be extremely simplistic.
2855
2856If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
9d48860e 2857a fast interface to returning and formatting data. I frequently
32eab2da 2858use these three modules together to write complex database query
2859apps in under 50 lines.
2860
d8cc1792 2861=head1 REPO
2862
2863=over
2864
6d19fbf9 2865=item * gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
d8cc1792 2866
6d19fbf9 2867=item * git: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
d8cc1792 2868
2869=back
32eab2da 2870
96449e8e 2871=head1 CHANGES
2872
2873Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2874Great care has been taken to preserve the I<published> behavior
2875documented in previous versions in the 1.* family; however,
9d48860e 2876some features that were previously undocumented, or behaved
96449e8e 2877differently from the documentation, had to be changed in order
2878to clarify the semantics. Hence, client code that was relying
9d48860e 2879on some dark areas of C<SQL::Abstract> v1.*
96449e8e 2880B<might behave differently> in v1.50.
32eab2da 2881
d2a8fe1a 2882The main changes are :
2883
96449e8e 2884=over
32eab2da 2885
9d48860e 2886=item *
32eab2da 2887
96449e8e 2888support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2889
2890=item *
2891
145fbfc8 2892support for the { operator => \"..." } construct (to embed literal SQL)
2893
2894=item *
2895
9c37b9c0 2896support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2897
2898=item *
2899
96449e8e 2900optional support for L<array datatypes|/"Inserting and Updating Arrays">
2901
9d48860e 2902=item *
96449e8e 2903
2904defensive programming : check arguments
2905
2906=item *
2907
2908fixed bug with global logic, which was previously implemented
7cac25e6 2909through global variables yielding side-effects. Prior versions would
96449e8e 2910interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2911as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2912Now this is interpreted
2913as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2914
96449e8e 2915
2916=item *
2917
2918fixed semantics of _bindtype on array args
2919
9d48860e 2920=item *
96449e8e 2921
2922dropped the C<_anoncopy> of the %where tree. No longer necessary,
2923we just avoid shifting arrays within that tree.
2924
2925=item *
2926
2927dropped the C<_modlogic> function
2928
2929=back
32eab2da 2930
32eab2da 2931=head1 ACKNOWLEDGEMENTS
2932
2933There are a number of individuals that have really helped out with
2934this module. Unfortunately, most of them submitted bugs via CPAN
2935so I have no idea who they are! But the people I do know are:
2936
9d48860e 2937 Ash Berlin (order_by hash term support)
b643abe1 2938 Matt Trout (DBIx::Class support)
32eab2da 2939 Mark Stosberg (benchmarking)
2940 Chas Owens (initial "IN" operator support)
2941 Philip Collins (per-field SQL functions)
2942 Eric Kolve (hashref "AND" support)
2943 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2944 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 2945 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
48d9f5f8 2946 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
dbdf7648 2947 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
e96c510a 2948 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
02288357 2949 Oliver Charles (support for "RETURNING" after "INSERT")
32eab2da 2950
2951Thanks!
2952
32eab2da 2953=head1 SEE ALSO
2954
86298391 2955L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 2956
32eab2da 2957=head1 AUTHOR
2958
b643abe1 2959Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2960
2961This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 2962
abe72f94 2963For support, your best bet is to try the C<DBIx::Class> users mailing list.
2964While not an official support venue, C<DBIx::Class> makes heavy use of
2965C<SQL::Abstract>, and as such list members there are very familiar with
2966how to create queries.
2967
0d067ded 2968=head1 LICENSE
2969
d988ab87 2970This module is free software; you may copy this under the same
2971terms as perl itself (either the GNU General Public License or
2972the Artistic License)
32eab2da 2973
2974=cut
2975