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