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