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