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