Fixed a bug in hashpair with literal SQL and bind value (ie. col => { op => \[$sql...
[dbsrgits/SQL-Abstract.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;
fffe6900 11use List::Util qw/first/;
12use Scalar::Util qw/blessed/;
96449e8e 13
14#======================================================================
15# GLOBALS
16#======================================================================
17
18our $VERSION = '1.49_01';
7479e27e 19$VERSION = eval $VERSION; # numify for warning-free dev releases
20
96449e8e 21
22our $AUTOLOAD;
23
24# special operators (-in, -between). May be extended/overridden by user.
25# See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
26my @BUILTIN_SPECIAL_OPS = (
27 {regex => qr/^(not )?between$/i, handler => \&_where_field_BETWEEN},
28 {regex => qr/^(not )?in$/i, handler => \&_where_field_IN},
29);
30
31#======================================================================
32# DEBUGGING AND ERROR REPORTING
33#======================================================================
34
35sub _debug {
36 return unless $_[0]->{debug}; shift; # a little faster
37 my $func = (caller(1))[3];
38 warn "[$func] ", @_, "\n";
39}
40
41sub belch (@) {
42 my($func) = (caller(1))[3];
43 carp "[$func] Warning: ", @_;
44}
45
46sub puke (@) {
47 my($func) = (caller(1))[3];
48 croak "[$func] Fatal: ", @_;
49}
50
51
52#======================================================================
53# NEW
54#======================================================================
55
56sub new {
57 my $self = shift;
58 my $class = ref($self) || $self;
59 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
60
61 # choose our case by keeping an option around
62 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
63
64 # default logic for interpreting arrayrefs
65 $opt{logic} = uc $opt{logic} || 'OR';
66
67 # how to return bind vars
68 # LDNOTE: changed nwiger code : why this 'delete' ??
69 # $opt{bindtype} ||= delete($opt{bind_type}) || 'normal';
70 $opt{bindtype} ||= 'normal';
71
72 # default comparison is "=", but can be overridden
73 $opt{cmp} ||= '=';
74
75 # try to recognize which are the 'equality' and 'unequality' ops
76 # (temporary quickfix, should go through a more seasoned API)
77 $opt{equality_op} = qr/^(\Q$opt{cmp}\E|is|(is\s+)?like)$/i;
78 $opt{inequality_op} = qr/^(!=|<>|(is\s+)?not(\s+like)?)$/i;
79
80 # SQL booleans
81 $opt{sqltrue} ||= '1=1';
82 $opt{sqlfalse} ||= '0=1';
83
84 # special operators
85 $opt{special_ops} ||= [];
86 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
87
88 return bless \%opt, $class;
89}
90
91
92
93#======================================================================
94# INSERT methods
95#======================================================================
96
97sub insert {
98 my $self = shift;
99 my $table = $self->_table(shift);
100 my $data = shift || return;
101
102 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
103 my ($sql, @bind) = $self->$method($data);
104 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
105 return wantarray ? ($sql, @bind) : $sql;
106}
107
108sub _insert_HASHREF { # explicit list of fields and then values
109 my ($self, $data) = @_;
110
111 my @fields = sort keys %$data;
112
113 my ($sql, @bind);
114 { # get values (need temporary override of bindtype to avoid an error)
115 local $self->{bindtype} = 'normal';
116 ($sql, @bind) = $self->_insert_ARRAYREF([@{$data}{@fields}]);
117 }
118
119 # if necessary, transform values according to 'bindtype'
120 if ($self->{bindtype} eq 'columns') {
121 for my $i (0 .. $#fields) {
122 ($bind[$i]) = $self->_bindtype($fields[$i], $bind[$i]);
123 }
124 }
125
126 # assemble SQL
127 $_ = $self->_quote($_) foreach @fields;
128 $sql = "( ".join(", ", @fields).") ".$sql;
129
130 return ($sql, @bind);
131}
132
133sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
134 my ($self, $data) = @_;
135
136 # no names (arrayref) so can't generate bindtype
137 $self->{bindtype} ne 'columns'
138 or belch "can't do 'columns' bindtype when called with arrayref";
139
140 my (@values, @all_bind);
141 for my $v (@$data) {
142
143 $self->_SWITCH_refkind($v, {
144
145 ARRAYREF => sub {
146 if ($self->{array_datatypes}) { # if array datatype are activated
147 push @values, '?';
d82b8afb 148 push @all_bind, $v;
96449e8e 149 }
150 else { # else literal SQL with bind
151 my ($sql, @bind) = @$v;
152 push @values, $sql;
153 push @all_bind, @bind;
154 }
155 },
156
157 ARRAYREFREF => sub { # literal SQL with bind
158 my ($sql, @bind) = @${$v};
159 push @values, $sql;
160 push @all_bind, @bind;
161 },
162
163 # THINK : anything useful to do with a HASHREF ?
5db47f9f 164 HASHREF => sub { # (nothing, but old SQLA passed it through)
165 #TODO in SQLA >= 2.0 it will die instead
166 belch "HASH ref as bind value in insert is not supported";
167 push @values, '?';
168 push @all_bind, $v;
169 },
96449e8e 170
171 SCALARREF => sub { # literal SQL without bind
172 push @values, $$v;
173 },
174
175 SCALAR_or_UNDEF => sub {
176 push @values, '?';
177 push @all_bind, $v;
178 },
179
180 });
181
182 }
183
184 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
185 return ($sql, @all_bind);
186}
187
188
189sub _insert_ARRAYREFREF { # literal SQL with bind
190 my ($self, $data) = @_;
191 return @${$data};
192}
193
194
195sub _insert_SCALARREF { # literal SQL without bind
196 my ($self, $data) = @_;
197
198 return ($$data);
199}
200
201
202
203#======================================================================
204# UPDATE methods
205#======================================================================
206
207
208sub update {
209 my $self = shift;
210 my $table = $self->_table(shift);
211 my $data = shift || return;
212 my $where = shift;
213
214 # first build the 'SET' part of the sql statement
215 my (@set, @all_bind);
216 puke "Unsupported data type specified to \$sql->update"
217 unless ref $data eq 'HASH';
218
219 for my $k (sort keys %$data) {
220 my $v = $data->{$k};
221 my $r = ref $v;
222 my $label = $self->_quote($k);
223
224 $self->_SWITCH_refkind($v, {
225 ARRAYREF => sub {
226 if ($self->{array_datatypes}) { # array datatype
227 push @set, "$label = ?";
228 push @all_bind, $self->_bindtype($k, $v);
229 }
230 else { # literal SQL with bind
231 my ($sql, @bind) = @$v;
232 push @set, "$label = $sql";
233 push @all_bind, $self->_bindtype($k, @bind);
234 }
235 },
236 ARRAYREFREF => sub { # literal SQL with bind
237 my ($sql, @bind) = @${$v};
238 push @set, "$label = $sql";
239 push @all_bind, $self->_bindtype($k, @bind);
240 },
241 SCALARREF => sub { # literal SQL without bind
242 push @set, "$label = $$v";
243 },
244 SCALAR_or_UNDEF => sub {
245 push @set, "$label = ?";
246 push @all_bind, $self->_bindtype($k, $v);
247 },
248 });
249 }
250
251 # generate sql
252 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ')
253 . join ', ', @set;
254
255 if ($where) {
256 my($where_sql, @where_bind) = $self->where($where);
257 $sql .= $where_sql;
258 push @all_bind, @where_bind;
259 }
260
261 return wantarray ? ($sql, @all_bind) : $sql;
262}
263
264
265
266
267#======================================================================
268# SELECT
269#======================================================================
270
271
272sub select {
273 my $self = shift;
274 my $table = $self->_table(shift);
275 my $fields = shift || '*';
276 my $where = shift;
277 my $order = shift;
278
279 my($where_sql, @bind) = $self->where($where, $order);
280
281 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields
282 : $fields;
283 my $sql = join(' ', $self->_sqlcase('select'), $f,
284 $self->_sqlcase('from'), $table)
285 . $where_sql;
286
287 return wantarray ? ($sql, @bind) : $sql;
288}
289
290#======================================================================
291# DELETE
292#======================================================================
293
294
295sub delete {
296 my $self = shift;
297 my $table = $self->_table(shift);
298 my $where = shift;
299
300
301 my($where_sql, @bind) = $self->where($where);
302 my $sql = $self->_sqlcase('delete from') . " $table" . $where_sql;
303
304 return wantarray ? ($sql, @bind) : $sql;
305}
306
307
308#======================================================================
309# WHERE: entry point
310#======================================================================
311
312
313
314# Finally, a separate routine just to handle WHERE clauses
315sub where {
316 my ($self, $where, $order) = @_;
317
318 # where ?
319 my ($sql, @bind) = $self->_recurse_where($where);
320 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
321
322 # order by?
323 if ($order) {
324 $sql .= $self->_order_by($order);
325 }
326
327 return wantarray ? ($sql, @bind) : $sql;
328}
329
330
331sub _recurse_where {
332 my ($self, $where, $logic) = @_;
333
334 # dispatch on appropriate method according to refkind of $where
335 my $method = $self->_METHOD_FOR_refkind("_where", $where);
311b2151 336
337
338 my ($sql, @bind) = $self->$method($where, $logic);
339
340 # DBIx::Class directly calls _recurse_where in scalar context, so
341 # we must implement it, even if not in the official API
342 return wantarray ? ($sql, @bind) : $sql;
96449e8e 343}
344
345
346
347#======================================================================
348# WHERE: top-level ARRAYREF
349#======================================================================
350
351
352sub _where_ARRAYREF {
353 my ($self, $where, $logic) = @_;
354
355 $logic = uc($logic || $self->{logic});
356 $logic eq 'AND' or $logic eq 'OR' or puke "unknown logic: $logic";
357
358 my @clauses = @$where;
359
360 # if the array starts with [-and|or => ...], recurse with that logic
361 my $first = $clauses[0] || '';
362 if ($first =~ /^-(and|or)/i) {
363 $logic = $1;
364 shift @clauses;
365 return $self->_where_ARRAYREF(\@clauses, $logic);
366 }
367
368 #otherwise..
369 my (@sql_clauses, @all_bind);
370
371 # need to use while() so can shift() for pairs
372 while (my $el = shift @clauses) {
373
374 # switch according to kind of $el and get corresponding ($sql, @bind)
375 my ($sql, @bind) = $self->_SWITCH_refkind($el, {
376
377 # skip empty elements, otherwise get invalid trailing AND stuff
378 ARRAYREF => sub {$self->_recurse_where($el) if @$el},
379
380 HASHREF => sub {$self->_recurse_where($el, 'and') if %$el},
381 # LDNOTE : previous SQLA code for hashrefs was creating a dirty
382 # side-effect: the first hashref within an array would change
383 # the global logic to 'AND'. So [ {cond1, cond2}, [cond3, cond4] ]
384 # was interpreted as "(cond1 AND cond2) OR (cond3 AND cond4)",
385 # whereas it should be "(cond1 AND cond2) OR (cond3 OR cond4)".
386
387 SCALARREF => sub { ($$el); },
388
389 SCALAR => sub {# top-level arrayref with scalars, recurse in pairs
390 $self->_recurse_where({$el => shift(@clauses)})},
391
392 UNDEF => sub {puke "not supported : UNDEF in arrayref" },
393 });
394
4b7b6026 395 if ($sql) {
396 push @sql_clauses, $sql;
397 push @all_bind, @bind;
398 }
96449e8e 399 }
400
401 return $self->_join_sql_clauses($logic, \@sql_clauses, \@all_bind);
402}
403
404
405
406#======================================================================
407# WHERE: top-level HASHREF
408#======================================================================
409
410sub _where_HASHREF {
411 my ($self, $where) = @_;
412 my (@sql_clauses, @all_bind);
413
414 # LDNOTE : don't really know why we need to sort keys
415 for my $k (sort keys %$where) {
416 my $v = $where->{$k};
417
418 # ($k => $v) is either a special op or a regular hashpair
419 my ($sql, @bind) = ($k =~ /^-(.+)/) ? $self->_where_op_in_hash($1, $v)
420 : do {
421 my $method = $self->_METHOD_FOR_refkind("_where_hashpair", $v);
422 $self->$method($k, $v);
423 };
424
425 push @sql_clauses, $sql;
426 push @all_bind, @bind;
427 }
428
429 return $self->_join_sql_clauses('and', \@sql_clauses, \@all_bind);
430}
431
432
433sub _where_op_in_hash {
434 my ($self, $op, $v) = @_;
435
436 $op =~ /^(AND|OR|NEST)[_\d]*/i
437 or puke "unknown operator: -$op";
438 $op = uc($1); # uppercase, remove trailing digits
439 $self->_debug("OP(-$op) within hashref, recursing...");
440
441 $self->_SWITCH_refkind($v, {
442
443 ARRAYREF => sub {
444 # LDNOTE : should deprecate {-or => [...]} and {-and => [...]}
445 # because they are misleading; the only proper way would be
446 # -nest => [-or => ...], -nest => [-and ...]
447 return $self->_where_ARRAYREF($v, $op eq 'NEST' ? '' : $op);
448 },
449
450 HASHREF => sub {
451 if ($op eq 'OR') {
452 belch "-or => {...} should be -nest => [...]";
453 return $self->_where_ARRAYREF([%$v], 'OR');
454 }
455 else { # NEST | AND
456 return $self->_where_HASHREF($v);
457 }
458 },
459
460 SCALARREF => sub { # literal SQL
461 $op eq 'NEST'
462 or puke "-$op => \\\$scalar not supported, use -nest => ...";
463 return ($$v);
464 },
465
466 ARRAYREFREF => sub { # literal SQL
467 $op eq 'NEST'
468 or puke "-$op => \\[..] not supported, use -nest => ...";
469 return @{${$v}};
470 },
471
472 SCALAR => sub { # permissively interpreted as SQL
473 $op eq 'NEST'
474 or puke "-$op => 'scalar' not supported, use -nest => \\'scalar'";
475 belch "literal SQL should be -nest => \\'scalar' "
476 . "instead of -nest => 'scalar' ";
477 return ($v);
478 },
479
480 UNDEF => sub {
481 puke "-$op => undef not supported";
482 },
483 });
484}
485
486
487sub _where_hashpair_ARRAYREF {
488 my ($self, $k, $v) = @_;
489
490 if( @$v ) {
491 my @v = @$v; # need copy because of shift below
492 $self->_debug("ARRAY($k) means distribute over elements");
493
494 # put apart first element if it is an operator (-and, -or)
495 my $op = $v[0] =~ /^-/ ? shift @v : undef;
496 $self->_debug("OP($op) reinjected into the distributed array") if $op;
497
498 my @distributed = map { {$k => $_} } @v;
499 unshift @distributed, $op if $op;
500
501 return $self->_recurse_where(\@distributed);
502 }
503 else {
504 # LDNOTE : not sure of this one. What does "distribute over nothing" mean?
505 $self->_debug("empty ARRAY($k) means 0=1");
506 return ($self->{sqlfalse});
507 }
508}
509
510sub _where_hashpair_HASHREF {
511 my ($self, $k, $v) = @_;
512
513 my (@all_sql, @all_bind);
514
515 for my $op (sort keys %$v) {
516 my $val = $v->{$op};
517
518 # put the operator in canonical form
519 $op =~ s/^-//; # remove initial dash
520 $op =~ tr/_/ /; # underscores become spaces
521 $op =~ s/^\s+//; # no initial space
522 $op =~ s/\s+$//; # no final space
523 $op =~ s/\s+/ /; # multiple spaces become one
524
525 my ($sql, @bind);
526
527 # CASE: special operators like -in or -between
528 my $special_op = first {$op =~ $_->{regex}} @{$self->{special_ops}};
529 if ($special_op) {
530 ($sql, @bind) = $special_op->{handler}->($self, $k, $op, $val);
531 }
96449e8e 532 else {
cf838930 533 $self->_SWITCH_refkind($val, {
534
535 ARRAYREF => sub { # CASE: col => {op => \@vals}
536 ($sql, @bind) = $self->_where_field_op_ARRAYREF($k, $op, $val);
537 },
538
539 SCALARREF => sub { # CASE: col => {op => \$scalar}
540 $sql = join ' ', $self->_convert($self->_quote($k)),
541 $self->_sqlcase($op),
542 $$val;
543 },
544
b3be7bd0 545 ARRAYREFREF => sub { # CASE: col => {op => \[$sql, @bind]}
546 my ($sub_sql, @sub_bind) = @$$val;
547 $sql = join ' ', $self->_convert($self->_quote($k)),
548 $self->_sqlcase($op),
549 $sub_sql;
cd87fd4c 550 @bind = $self->_bindtype($k, @sub_bind);
b3be7bd0 551 },
552
cf838930 553 UNDEF => sub { # CASE: col => {op => undef} : sql "IS (NOT)? NULL"
554 my $is = ($op =~ $self->{equality_op}) ? 'is' :
555 ($op =~ $self->{inequality_op}) ? 'is not' :
556 puke "unexpected operator '$op' with undef operand";
557 $sql = $self->_quote($k) . $self->_sqlcase(" $is null");
558 },
559
560 FALLBACK => sub { # CASE: col => {op => $scalar}
561 $sql = join ' ', $self->_convert($self->_quote($k)),
562 $self->_sqlcase($op),
563 $self->_convert('?');
564 @bind = $self->_bindtype($k, $val);
565 },
566 });
96449e8e 567 }
568
569 push @all_sql, $sql;
570 push @all_bind, @bind;
571 }
572
573 return $self->_join_sql_clauses('and', \@all_sql, \@all_bind);
574}
575
576
577
578sub _where_field_op_ARRAYREF {
579 my ($self, $k, $op, $vals) = @_;
580
581 if(@$vals) {
582 $self->_debug("ARRAY($vals) means multiple elements: [ @$vals ]");
583
584
585
586 # LDNOTE : change the distribution logic when
587 # $op =~ $self->{inequality_op}, because of Morgan laws :
588 # with {field => {'!=' => [22, 33]}}, it would be ridiculous to generate
589 # WHERE field != 22 OR field != 33 : the user probably means
590 # WHERE field != 22 AND field != 33.
591 my $logic = ($op =~ $self->{inequality_op}) ? 'AND' : 'OR';
592
593 # distribute $op over each member of @$vals
594 return $self->_recurse_where([map { {$k => {$op, $_}} } @$vals], $logic);
595
596 }
597 else {
598 # try to DWIM on equality operators
599 # LDNOTE : not 100% sure this is the correct thing to do ...
600 return ($self->{sqlfalse}) if $op =~ $self->{equality_op};
601 return ($self->{sqltrue}) if $op =~ $self->{inequality_op};
602
603 # otherwise
604 puke "operator '$op' applied on an empty array (field '$k')";
605 }
606}
607
608
609sub _where_hashpair_SCALARREF {
610 my ($self, $k, $v) = @_;
611 $self->_debug("SCALAR($k) means literal SQL: $$v");
612 my $sql = $self->_quote($k) . " " . $$v;
613 return ($sql);
614}
615
616sub _where_hashpair_ARRAYREFREF {
617 my ($self, $k, $v) = @_;
618 $self->_debug("REF($k) means literal SQL: @${$v}");
619 my ($sql, @bind) = @${$v};
620 $sql = $self->_quote($k) . " " . $sql;
621 @bind = $self->_bindtype($k, @bind);
622 return ($sql, @bind );
623}
624
625sub _where_hashpair_SCALAR {
626 my ($self, $k, $v) = @_;
627 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
628 my $sql = join ' ', $self->_convert($self->_quote($k)),
629 $self->_sqlcase($self->{cmp}),
630 $self->_convert('?');
631 my @bind = $self->_bindtype($k, $v);
632 return ( $sql, @bind);
633}
634
635
636sub _where_hashpair_UNDEF {
637 my ($self, $k, $v) = @_;
638 $self->_debug("UNDEF($k) means IS NULL");
639 my $sql = $self->_quote($k) . $self->_sqlcase(' is null');
640 return ($sql);
641}
642
643#======================================================================
644# WHERE: TOP-LEVEL OTHERS (SCALARREF, SCALAR, UNDEF)
645#======================================================================
646
647
648sub _where_SCALARREF {
649 my ($self, $where) = @_;
650
651 # literal sql
652 $self->_debug("SCALAR(*top) means literal SQL: $$where");
653 return ($$where);
654}
655
656
657sub _where_SCALAR {
658 my ($self, $where) = @_;
659
660 # literal sql
661 $self->_debug("NOREF(*top) means literal SQL: $where");
662 return ($where);
663}
664
665
666sub _where_UNDEF {
667 my ($self) = @_;
668 return ();
669}
670
671
672#======================================================================
673# WHERE: BUILTIN SPECIAL OPERATORS (-in, -between)
674#======================================================================
675
676
677sub _where_field_BETWEEN {
678 my ($self, $k, $op, $vals) = @_;
679
680 ref $vals eq 'ARRAY' && @$vals == 2
681 or puke "special op 'between' requires an arrayref of two values";
682
683 my ($label) = $self->_convert($self->_quote($k));
684 my ($placeholder) = $self->_convert('?');
685 my $and = $self->_sqlcase('and');
686 $op = $self->_sqlcase($op);
687
688 my $sql = "( $label $op $placeholder $and $placeholder )";
689 my @bind = $self->_bindtype($k, @$vals);
690 return ($sql, @bind)
691}
692
693
694sub _where_field_IN {
695 my ($self, $k, $op, $vals) = @_;
696
697 # backwards compatibility : if scalar, force into an arrayref
698 $vals = [$vals] if defined $vals && ! ref $vals;
699
700 ref $vals eq 'ARRAY'
701 or puke "special op 'in' requires an arrayref";
702
703 my ($label) = $self->_convert($self->_quote($k));
704 my ($placeholder) = $self->_convert('?');
705 my $and = $self->_sqlcase('and');
706 $op = $self->_sqlcase($op);
707
708 if (@$vals) { # nonempty list
709 my $placeholders = join ", ", (($placeholder) x @$vals);
710 my $sql = "$label $op ( $placeholders )";
711 my @bind = $self->_bindtype($k, @$vals);
712
713 return ($sql, @bind);
714 }
715 else { # empty list : some databases won't understand "IN ()", so DWIM
716 my $sql = ($op =~ /\bnot\b/i) ? $self->{sqltrue} : $self->{sqlfalse};
717 return ($sql);
718 }
719}
720
721
722
723
724
725
726#======================================================================
727# ORDER BY
728#======================================================================
729
730sub _order_by {
731 my ($self, $arg) = @_;
732
733 # construct list of ordering instructions
734 my @order = $self->_SWITCH_refkind($arg, {
735
736 ARRAYREF => sub {
737 map {$self->_SWITCH_refkind($_, {
738 SCALAR => sub {$self->_quote($_)},
fffe6900 739 UNDEF => sub {},
96449e8e 740 SCALARREF => sub {$$_}, # literal SQL, no quoting
741 HASHREF => sub {$self->_order_by_hash($_)}
742 }) } @$arg;
743 },
744
745 SCALAR => sub {$self->_quote($arg)},
b6475fb1 746 UNDEF => sub {},
96449e8e 747 SCALARREF => sub {$$arg}, # literal SQL, no quoting
748 HASHREF => sub {$self->_order_by_hash($arg)},
749
750 });
751
752 # build SQL
753 my $order = join ', ', @order;
754 return $order ? $self->_sqlcase(' order by')." $order" : '';
755}
756
757
758sub _order_by_hash {
759 my ($self, $hash) = @_;
760
761 # get first pair in hash
762 my ($key, $val) = each %$hash;
763
764 # check if one pair was found and no other pair in hash
765 $key && !(each %$hash)
766 or puke "hash passed to _order_by must have exactly one key (-desc or -asc)";
767
768 my ($order) = ($key =~ /^-(desc|asc)/i)
769 or puke "invalid key in _order_by hash : $key";
770
771 return $self->_quote($val) ." ". $self->_sqlcase($order);
772}
773
774
775
776#======================================================================
777# DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
778#======================================================================
779
780sub _table {
781 my $self = shift;
782 my $from = shift;
783 $self->_SWITCH_refkind($from, {
784 ARRAYREF => sub {join ', ', map { $self->_quote($_) } @$from;},
785 SCALAR => sub {$self->_quote($from)},
786 SCALARREF => sub {$$from},
787 ARRAYREFREF => sub {join ', ', @$from;},
788 });
789}
790
791
792#======================================================================
793# UTILITY FUNCTIONS
794#======================================================================
795
796sub _quote {
797 my $self = shift;
798 my $label = shift;
799
800 $label or puke "can't quote an empty label";
801
802 # left and right quote characters
803 my ($ql, $qr, @other) = $self->_SWITCH_refkind($self->{quote_char}, {
804 SCALAR => sub {($self->{quote_char}, $self->{quote_char})},
805 ARRAYREF => sub {@{$self->{quote_char}}},
806 UNDEF => sub {()},
807 });
808 not @other
809 or puke "quote_char must be an arrayref of 2 values";
810
811 # no quoting if no quoting chars
812 $ql or return $label;
813
814 # no quoting for literal SQL
815 return $$label if ref($label) eq 'SCALAR';
816
817 # separate table / column (if applicable)
818 my $sep = $self->{name_sep} || '';
819 my @to_quote = $sep ? split /\Q$sep\E/, $label : ($label);
820
821 # do the quoting, except for "*" or for `table`.*
822 my @quoted = map { $_ eq '*' ? $_: $ql.$_.$qr} @to_quote;
823
824 # reassemble and return.
825 return join $sep, @quoted;
826}
827
828
829# Conversion, if applicable
830sub _convert ($) {
831 my ($self, $arg) = @_;
832
833# LDNOTE : modified the previous implementation below because
834# it was not consistent : the first "return" is always an array,
835# the second "return" is context-dependent. Anyway, _convert
836# seems always used with just a single argument, so make it a
837# scalar function.
838# return @_ unless $self->{convert};
839# my $conv = $self->_sqlcase($self->{convert});
840# my @ret = map { $conv.'('.$_.')' } @_;
841# return wantarray ? @ret : $ret[0];
842 if ($self->{convert}) {
843 my $conv = $self->_sqlcase($self->{convert});
844 $arg = $conv.'('.$arg.')';
845 }
846 return $arg;
847}
848
849# And bindtype
850sub _bindtype (@) {
851 my $self = shift;
852 my($col, @vals) = @_;
853
854 #LDNOTE : changed original implementation below because it did not make
855 # sense when bindtype eq 'columns' and @vals > 1.
856# return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
857
858 return $self->{bindtype} eq 'columns' ? map {[$col, $_]} @vals : @vals;
859}
860
861sub _join_sql_clauses {
862 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
863
864 if (@$clauses_aref > 1) {
865 my $join = " " . $self->_sqlcase($logic) . " ";
866 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
867 return ($sql, @$bind_aref);
868 }
869 elsif (@$clauses_aref) {
870 return ($clauses_aref->[0], @$bind_aref); # no parentheses
871 }
872 else {
873 return (); # if no SQL, ignore @$bind_aref
874 }
875}
876
877
878# Fix SQL case, if so requested
879sub _sqlcase {
880 my $self = shift;
881
882 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
883 # don't touch the argument ... crooked logic, but let's not change it!
884 return $self->{case} ? $_[0] : uc($_[0]);
885}
886
887
888#======================================================================
889# DISPATCHING FROM REFKIND
890#======================================================================
891
892sub _refkind {
893 my ($self, $data) = @_;
894 my $suffix = '';
895 my $ref;
90aab162 896 my $n_steps = 0;
96449e8e 897
96449e8e 898 while (1) {
90aab162 899 # blessed objects are treated like scalars
900 $ref = (blessed $data) ? '' : ref $data;
901 $n_steps += 1 if $ref;
902 last if $ref ne 'REF';
96449e8e 903 $data = $$data;
904 }
905
90aab162 906 my $base = $ref || (defined $data ? 'SCALAR' : 'UNDEF');
907
908 return $base . ('REF' x $n_steps);
96449e8e 909}
910
90aab162 911
912
96449e8e 913sub _try_refkind {
914 my ($self, $data) = @_;
915 my @try = ($self->_refkind($data));
916 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
917 push @try, 'FALLBACK';
918 return @try;
919}
920
921sub _METHOD_FOR_refkind {
922 my ($self, $meth_prefix, $data) = @_;
923 my $method = first {$_} map {$self->can($meth_prefix."_".$_)}
924 $self->_try_refkind($data)
925 or puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
926 return $method;
927}
928
929
930sub _SWITCH_refkind {
931 my ($self, $data, $dispatch_table) = @_;
932
933 my $coderef = first {$_} map {$dispatch_table->{$_}}
934 $self->_try_refkind($data)
935 or puke "no dispatch entry for ".$self->_refkind($data);
936 $coderef->();
937}
938
939
940
941
942#======================================================================
943# VALUES, GENERATE, AUTOLOAD
944#======================================================================
945
946# LDNOTE: original code from nwiger, didn't touch code in that section
947# I feel the AUTOLOAD stuff should not be the default, it should
948# only be activated on explicit demand by user.
949
950sub values {
951 my $self = shift;
952 my $data = shift || return;
953 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
954 unless ref $data eq 'HASH';
955 return map { $self->_bindtype($_, $data->{$_}) } sort keys %$data;
956}
957
958sub generate {
959 my $self = shift;
960
961 my(@sql, @sqlq, @sqlv);
962
963 for (@_) {
964 my $ref = ref $_;
965 if ($ref eq 'HASH') {
966 for my $k (sort keys %$_) {
967 my $v = $_->{$k};
968 my $r = ref $v;
969 my $label = $self->_quote($k);
970 if ($r eq 'ARRAY') {
971 # SQL included for values
972 my @bind = @$v;
973 my $sql = shift @bind;
974 push @sqlq, "$label = $sql";
975 push @sqlv, $self->_bindtype($k, @bind);
976 } elsif ($r eq 'SCALAR') {
977 # embedded literal SQL
978 push @sqlq, "$label = $$v";
979 } else {
980 push @sqlq, "$label = ?";
981 push @sqlv, $self->_bindtype($k, $v);
982 }
983 }
984 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
985 } elsif ($ref eq 'ARRAY') {
986 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
987 for my $v (@$_) {
988 my $r = ref $v;
989 if ($r eq 'ARRAY') {
990 my @val = @$v;
991 push @sqlq, shift @val;
992 push @sqlv, @val;
993 } elsif ($r eq 'SCALAR') {
994 # embedded literal SQL
995 push @sqlq, $$v;
996 } else {
997 push @sqlq, '?';
998 push @sqlv, $v;
999 }
1000 }
1001 push @sql, '(' . join(', ', @sqlq) . ')';
1002 } elsif ($ref eq 'SCALAR') {
1003 # literal SQL
1004 push @sql, $$_;
1005 } else {
1006 # strings get case twiddled
1007 push @sql, $self->_sqlcase($_);
1008 }
1009 }
1010
1011 my $sql = join ' ', @sql;
1012
1013 # this is pretty tricky
1014 # if ask for an array, return ($stmt, @bind)
1015 # otherwise, s/?/shift @sqlv/ to put it inline
1016 if (wantarray) {
1017 return ($sql, @sqlv);
1018 } else {
1019 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1020 ref $d ? $d->[1] : $d/e;
1021 return $sql;
1022 }
1023}
1024
1025
1026sub DESTROY { 1 }
1027
1028sub AUTOLOAD {
1029 # This allows us to check for a local, then _form, attr
1030 my $self = shift;
1031 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1032 return $self->generate($name, @_);
1033}
1034
10351;
1036
1037
1038
1039__END__
32eab2da 1040
1041=head1 NAME
1042
1043SQL::Abstract - Generate SQL from Perl data structures
1044
1045=head1 SYNOPSIS
1046
1047 use SQL::Abstract;
1048
1049 my $sql = SQL::Abstract->new;
1050
1051 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
1052
1053 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1054
1055 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1056
1057 my($stmt, @bind) = $sql->delete($table, \%where);
1058
1059 # Then, use these in your DBI statements
1060 my $sth = $dbh->prepare($stmt);
1061 $sth->execute(@bind);
1062
1063 # Just generate the WHERE clause
abe72f94 1064 my($stmt, @bind) = $sql->where(\%where, \@order);
32eab2da 1065
1066 # Return values in the same order, for hashed queries
1067 # See PERFORMANCE section for more details
1068 my @bind = $sql->values(\%fieldvals);
1069
1070=head1 DESCRIPTION
1071
1072This module was inspired by the excellent L<DBIx::Abstract>.
1073However, in using that module I found that what I really wanted
1074to do was generate SQL, but still retain complete control over my
1075statement handles and use the DBI interface. So, I set out to
1076create an abstract SQL generation module.
1077
1078While based on the concepts used by L<DBIx::Abstract>, there are
1079several important differences, especially when it comes to WHERE
1080clauses. I have modified the concepts used to make the SQL easier
1081to generate from Perl data structures and, IMO, more intuitive.
1082The underlying idea is for this module to do what you mean, based
1083on the data structures you provide it. The big advantage is that
1084you don't have to modify your code every time your data changes,
1085as this module figures it out.
1086
1087To begin with, an SQL INSERT is as easy as just specifying a hash
1088of C<key=value> pairs:
1089
1090 my %data = (
1091 name => 'Jimbo Bobson',
1092 phone => '123-456-7890',
1093 address => '42 Sister Lane',
1094 city => 'St. Louis',
1095 state => 'Louisiana',
1096 );
1097
1098The SQL can then be generated with this:
1099
1100 my($stmt, @bind) = $sql->insert('people', \%data);
1101
1102Which would give you something like this:
1103
1104 $stmt = "INSERT INTO people
1105 (address, city, name, phone, state)
1106 VALUES (?, ?, ?, ?, ?)";
1107 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1108 '123-456-7890', 'Louisiana');
1109
1110These are then used directly in your DBI code:
1111
1112 my $sth = $dbh->prepare($stmt);
1113 $sth->execute(@bind);
1114
96449e8e 1115=head2 Inserting and Updating Arrays
1116
1117If your database has array types (like for example Postgres),
1118activate the special option C<< array_datatypes => 1 >>
1119when creating the C<SQL::Abstract> object.
1120Then you may use an arrayref to insert and update database array types:
1121
1122 my $sql = SQL::Abstract->new(array_datatypes => 1);
1123 my %data = (
1124 planets => [qw/Mercury Venus Earth Mars/]
1125 );
1126
1127 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1128
1129This results in:
1130
1131 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1132
1133 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1134
1135
1136=head2 Inserting and Updating SQL
1137
1138In order to apply SQL functions to elements of your C<%data> you may
1139specify a reference to an arrayref for the given hash value. For example,
1140if you need to execute the Oracle C<to_date> function on a value, you can
1141say something like this:
32eab2da 1142
1143 my %data = (
1144 name => 'Bill',
96449e8e 1145 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
32eab2da 1146 );
1147
1148The first value in the array is the actual SQL. Any other values are
1149optional and would be included in the bind values array. This gives
1150you:
1151
1152 my($stmt, @bind) = $sql->insert('people', \%data);
1153
1154 $stmt = "INSERT INTO people (name, date_entered)
1155 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1156 @bind = ('Bill', '03/02/2003');
1157
1158An UPDATE is just as easy, all you change is the name of the function:
1159
1160 my($stmt, @bind) = $sql->update('people', \%data);
1161
1162Notice that your C<%data> isn't touched; the module will generate
1163the appropriately quirky SQL for you automatically. Usually you'll
1164want to specify a WHERE clause for your UPDATE, though, which is
1165where handling C<%where> hashes comes in handy...
1166
96449e8e 1167=head2 Complex where statements
1168
32eab2da 1169This module can generate pretty complicated WHERE statements
1170easily. For example, simple C<key=value> pairs are taken to mean
1171equality, and if you want to see if a field is within a set
1172of values, you can use an arrayref. Let's say we wanted to
1173SELECT some data based on this criteria:
1174
1175 my %where = (
1176 requestor => 'inna',
1177 worker => ['nwiger', 'rcwe', 'sfz'],
1178 status => { '!=', 'completed' }
1179 );
1180
1181 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1182
1183The above would give you something like this:
1184
1185 $stmt = "SELECT * FROM tickets WHERE
1186 ( requestor = ? ) AND ( status != ? )
1187 AND ( worker = ? OR worker = ? OR worker = ? )";
1188 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1189
1190Which you could then use in DBI code like so:
1191
1192 my $sth = $dbh->prepare($stmt);
1193 $sth->execute(@bind);
1194
1195Easy, eh?
1196
1197=head1 FUNCTIONS
1198
1199The functions are simple. There's one for each major SQL operation,
1200and a constructor you use first. The arguments are specified in a
1201similar order to each function (table, then fields, then a where
1202clause) to try and simplify things.
1203
83cab70b 1204
83cab70b 1205
32eab2da 1206
1207=head2 new(option => 'value')
1208
1209The C<new()> function takes a list of options and values, and returns
1210a new B<SQL::Abstract> object which can then be used to generate SQL
1211through the methods below. The options accepted are:
1212
1213=over
1214
1215=item case
1216
1217If set to 'lower', then SQL will be generated in all lowercase. By
1218default SQL is generated in "textbook" case meaning something like:
1219
1220 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1221
96449e8e 1222Any setting other than 'lower' is ignored.
1223
32eab2da 1224=item cmp
1225
1226This determines what the default comparison operator is. By default
1227it is C<=>, meaning that a hash like this:
1228
1229 %where = (name => 'nwiger', email => 'nate@wiger.org');
1230
1231Will generate SQL like this:
1232
1233 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1234
1235However, you may want loose comparisons by default, so if you set
1236C<cmp> to C<like> you would get SQL such as:
1237
1238 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1239
1240You can also override the comparsion on an individual basis - see
1241the huge section on L</"WHERE CLAUSES"> at the bottom.
1242
96449e8e 1243=item sqltrue, sqlfalse
1244
1245Expressions for inserting boolean values within SQL statements.
1246By default these are C<1=1> and C<1=0>.
1247
32eab2da 1248=item logic
1249
1250This determines the default logical operator for multiple WHERE
1251statements in arrays. By default it is "or", meaning that a WHERE
1252array of the form:
1253
1254 @where = (
1255 event_date => {'>=', '2/13/99'},
1256 event_date => {'<=', '4/24/03'},
1257 );
1258
1259Will generate SQL like this:
1260
1261 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1262
1263This is probably not what you want given this query, though (look
1264at the dates). To change the "OR" to an "AND", simply specify:
1265
1266 my $sql = SQL::Abstract->new(logic => 'and');
1267
1268Which will change the above C<WHERE> to:
1269
1270 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1271
96449e8e 1272The logic can also be changed locally by inserting
1273an extra first element in the array :
1274
1275 @where = (-and => event_date => {'>=', '2/13/99'},
1276 event_date => {'<=', '4/24/03'} );
1277
1278See the L</"WHERE CLAUSES"> section for explanations.
1279
32eab2da 1280=item convert
1281
1282This will automatically convert comparisons using the specified SQL
1283function for both column and value. This is mostly used with an argument
1284of C<upper> or C<lower>, so that the SQL will have the effect of
1285case-insensitive "searches". For example, this:
1286
1287 $sql = SQL::Abstract->new(convert => 'upper');
1288 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1289
1290Will turn out the following SQL:
1291
1292 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1293
1294The conversion can be C<upper()>, C<lower()>, or any other SQL function
1295that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1296not validate this option; it will just pass through what you specify verbatim).
1297
1298=item bindtype
1299
1300This is a kludge because many databases suck. For example, you can't
1301just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1302Instead, you have to use C<bind_param()>:
1303
1304 $sth->bind_param(1, 'reg data');
1305 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1306
1307The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1308which loses track of which field each slot refers to. Fear not.
1309
1310If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1311Currently, you can specify either C<normal> (default) or C<columns>. If you
1312specify C<columns>, you will get an array that looks like this:
1313
1314 my $sql = SQL::Abstract->new(bindtype => 'columns');
1315 my($stmt, @bind) = $sql->insert(...);
1316
1317 @bind = (
1318 [ 'column1', 'value1' ],
1319 [ 'column2', 'value2' ],
1320 [ 'column3', 'value3' ],
1321 );
1322
1323You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 1324
32eab2da 1325 $sth->prepare($stmt);
1326 my $i = 1;
1327 for (@bind) {
1328 my($col, $data) = @$_;
1329 if ($col eq 'details' || $col eq 'comments') {
1330 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1331 } elsif ($col eq 'image') {
1332 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1333 } else {
1334 $sth->bind_param($i, $data);
1335 }
1336 $i++;
1337 }
1338 $sth->execute; # execute without @bind now
1339
1340Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1341Basically, the advantage is still that you don't have to care which fields
1342are or are not included. You could wrap that above C<for> loop in a simple
1343sub called C<bind_fields()> or something and reuse it repeatedly. You still
1344get a layer of abstraction over manual SQL specification.
1345
1346=item quote_char
1347
1348This is the character that a table or column name will be quoted
1349with. By default this is an empty string, but you could set it to
1350the character C<`>, to generate SQL like this:
1351
1352 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1353
96449e8e 1354Alternatively, you can supply an array ref of two items, the first being the left
1355hand quote character, and the second the right hand quote character. For
1356example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1357that generates SQL like this:
1358
1359 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1360
1361Quoting is useful if you have tables or columns names that are reserved
1362words in your database's SQL dialect.
32eab2da 1363
1364=item name_sep
1365
1366This is the character that separates a table and column name. It is
1367necessary to specify this when the C<quote_char> option is selected,
1368so that tables and column names can be individually quoted like this:
1369
1370 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1371
96449e8e 1372=item array_datatypes
32eab2da 1373
96449e8e 1374When this option is true, arrayrefs in INSERT or UPDATE are
1375interpreted as array datatypes and are passed directly
1376to the DBI layer.
1377When this option is false, arrayrefs are interpreted
1378as literal SQL, just like refs to arrayrefs
1379(but this behavior is for backwards compatibility; when writing
1380new queries, use the "reference to arrayref" syntax
1381for literal SQL).
32eab2da 1382
32eab2da 1383
96449e8e 1384=item special_ops
32eab2da 1385
96449e8e 1386Takes a reference to a list of "special operators"
1387to extend the syntax understood by L<SQL::Abstract>.
1388See section L</"SPECIAL OPERATORS"> for details.
32eab2da 1389
32eab2da 1390
32eab2da 1391
96449e8e 1392=back
32eab2da 1393
1394=head2 insert($table, \@values || \%fieldvals)
1395
1396This is the simplest function. You simply give it a table name
1397and either an arrayref of values or hashref of field/value pairs.
1398It returns an SQL INSERT statement and a list of bind values.
96449e8e 1399See the sections on L</"Inserting and Updating Arrays"> and
1400L</"Inserting and Updating SQL"> for information on how to insert
1401with those data types.
32eab2da 1402
1403=head2 update($table, \%fieldvals, \%where)
1404
1405This takes a table, hashref of field/value pairs, and an optional
86298391 1406hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 1407of bind values.
96449e8e 1408See the sections on L</"Inserting and Updating Arrays"> and
1409L</"Inserting and Updating SQL"> for information on how to insert
1410with those data types.
32eab2da 1411
96449e8e 1412=head2 select($source, $fields, $where, $order)
32eab2da 1413
96449e8e 1414This returns a SQL SELECT statement and associated list of bind values, as
1415specified by the arguments :
32eab2da 1416
96449e8e 1417=over
32eab2da 1418
96449e8e 1419=item $source
32eab2da 1420
96449e8e 1421Specification of the 'FROM' part of the statement.
1422The argument can be either a plain scalar (interpreted as a table
1423name, will be quoted), or an arrayref (interpreted as a list
1424of table names, joined by commas, quoted), or a scalarref
1425(literal table name, not quoted), or a ref to an arrayref
1426(list of literal table names, joined by commas, not quoted).
32eab2da 1427
96449e8e 1428=item $fields
32eab2da 1429
96449e8e 1430Specification of the list of fields to retrieve from
1431the source.
1432The argument can be either an arrayref (interpreted as a list
1433of field names, will be joined by commas and quoted), or a
1434plain scalar (literal SQL, not quoted).
1435Please observe that this API is not as flexible as for
e3f9dff4 1436the first argument C<$table>, for backwards compatibility reasons.
32eab2da 1437
96449e8e 1438=item $where
32eab2da 1439
96449e8e 1440Optional argument to specify the WHERE part of the query.
1441The argument is most often a hashref, but can also be
1442an arrayref or plain scalar --
1443see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 1444
96449e8e 1445=item $order
32eab2da 1446
96449e8e 1447Optional argument to specify the ORDER BY part of the query.
1448The argument can be a scalar, a hashref or an arrayref
1449-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1450for details.
32eab2da 1451
96449e8e 1452=back
32eab2da 1453
32eab2da 1454
1455=head2 delete($table, \%where)
1456
86298391 1457This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 1458It returns an SQL DELETE statement and list of bind values.
1459
32eab2da 1460=head2 where(\%where, \@order)
1461
1462This is used to generate just the WHERE clause. For example,
1463if you have an arbitrary data structure and know what the
1464rest of your SQL is going to look like, but want an easy way
1465to produce a WHERE clause, use this. It returns an SQL WHERE
1466clause and list of bind values.
1467
32eab2da 1468
1469=head2 values(\%data)
1470
1471This just returns the values from the hash C<%data>, in the same
1472order that would be returned from any of the other above queries.
1473Using this allows you to markedly speed up your queries if you
1474are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
1475
32eab2da 1476=head2 generate($any, 'number', $of, \@data, $struct, \%types)
1477
1478Warning: This is an experimental method and subject to change.
1479
1480This returns arbitrarily generated SQL. It's a really basic shortcut.
1481It will return two different things, depending on return context:
1482
1483 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
1484 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
1485
1486These would return the following:
1487
1488 # First calling form
1489 $stmt = "CREATE TABLE test (?, ?)";
1490 @bind = (field1, field2);
1491
1492 # Second calling form
1493 $stmt_and_val = "CREATE TABLE test (field1, field2)";
1494
1495Depending on what you're trying to do, it's up to you to choose the correct
1496format. In this example, the second form is what you would want.
1497
1498By the same token:
1499
1500 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
1501
1502Might give you:
1503
1504 ALTER SESSION SET nls_date_format = 'MM/YY'
1505
1506You get the idea. Strings get their case twiddled, but everything
1507else remains verbatim.
1508
32eab2da 1509
32eab2da 1510
32eab2da 1511
1512=head1 WHERE CLAUSES
1513
96449e8e 1514=head2 Introduction
1515
32eab2da 1516This module uses a variation on the idea from L<DBIx::Abstract>. It
1517is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
1518module is that things in arrays are OR'ed, and things in hashes
1519are AND'ed.>
1520
1521The easiest way to explain is to show lots of examples. After
1522each C<%where> hash shown, it is assumed you used:
1523
1524 my($stmt, @bind) = $sql->where(\%where);
1525
1526However, note that the C<%where> hash can be used directly in any
1527of the other functions as well, as described above.
1528
96449e8e 1529=head2 Key-value pairs
1530
32eab2da 1531So, let's get started. To begin, a simple hash:
1532
1533 my %where = (
1534 user => 'nwiger',
1535 status => 'completed'
1536 );
1537
1538Is converted to SQL C<key = val> statements:
1539
1540 $stmt = "WHERE user = ? AND status = ?";
1541 @bind = ('nwiger', 'completed');
1542
1543One common thing I end up doing is having a list of values that
1544a field can be in. To do this, simply specify a list inside of
1545an arrayref:
1546
1547 my %where = (
1548 user => 'nwiger',
1549 status => ['assigned', 'in-progress', 'pending'];
1550 );
1551
1552This simple code will create the following:
1553
1554 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1555 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1556
96449e8e 1557An empty arrayref will be considered a logical false and
8a68b5be 1558will generate 0=1.
1559
96449e8e 1560=head2 Key-value pairs
1561
32eab2da 1562If you want to specify a different type of operator for your comparison,
1563you can use a hashref for a given column:
1564
1565 my %where = (
1566 user => 'nwiger',
1567 status => { '!=', 'completed' }
1568 );
1569
1570Which would generate:
1571
1572 $stmt = "WHERE user = ? AND status != ?";
1573 @bind = ('nwiger', 'completed');
1574
1575To test against multiple values, just enclose the values in an arrayref:
1576
1577 status => { '!=', ['assigned', 'in-progress', 'pending'] };
1578
1579Which would give you:
1580
96449e8e 1581 "WHERE status != ? AND status != ? AND status != ?"
32eab2da 1582
96449e8e 1583Notice that since the operator was recognized as being a 'negative'
1584operator, the arrayref was interpreted with 'AND' logic (because
1585of Morgan's laws). By contrast, the reverse
1586
1587 status => { '=', ['assigned', 'in-progress', 'pending'] };
1588
1589would generate :
1590
1591 "WHERE status = ? OR status = ? OR status = ?"
1592
1593
1594The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 1595into an C<AND> of its elements:
1596
1597 my %where = (
1598 user => 'nwiger',
1599 status => { '!=', 'completed', -not_like => 'pending%' }
1600 );
1601
1602 # Or more dynamically, like from a form
1603 $where{user} = 'nwiger';
1604 $where{status}{'!='} = 'completed';
1605 $where{status}{'-not_like'} = 'pending%';
1606
1607 # Both generate this
1608 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1609 @bind = ('nwiger', 'completed', 'pending%');
1610
96449e8e 1611
32eab2da 1612To get an OR instead, you can combine it with the arrayref idea:
1613
1614 my %where => (
1615 user => 'nwiger',
1616 priority => [ {'=', 2}, {'!=', 1} ]
1617 );
1618
1619Which would generate:
1620
1621 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1622 @bind = ('nwiger', '2', '1');
1623
44b9e502 1624If you want to include literal SQL (with or without bind values), just use a
1625scalar reference or array reference as the value:
1626
1627 my %where = (
1628 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1629 date_expires => { '<' => \"now()" }
1630 );
1631
1632Which would generate:
1633
1634 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1635 @bind = ('11/26/2008');
1636
96449e8e 1637
1638=head2 Logic and nesting operators
1639
1640In the example above,
1641there is a subtle trap if you want to say something like
32eab2da 1642this (notice the C<AND>):
1643
1644 WHERE priority != ? AND priority != ?
1645
1646Because, in Perl you I<can't> do this:
1647
1648 priority => { '!=', 2, '!=', 1 }
1649
1650As the second C<!=> key will obliterate the first. The solution
1651is to use the special C<-modifier> form inside an arrayref:
1652
96449e8e 1653 priority => [ -and => {'!=', 2},
1654 {'!=', 1} ]
1655
32eab2da 1656
1657Normally, these would be joined by C<OR>, but the modifier tells it
1658to use C<AND> instead. (Hint: You can use this in conjunction with the
1659C<logic> option to C<new()> in order to change the way your queries
1660work by default.) B<Important:> Note that the C<-modifier> goes
1661B<INSIDE> the arrayref, as an extra first element. This will
1662B<NOT> do what you think it might:
1663
1664 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1665
1666Here is a quick list of equivalencies, since there is some overlap:
1667
1668 # Same
1669 status => {'!=', 'completed', 'not like', 'pending%' }
1670 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1671
1672 # Same
1673 status => {'=', ['assigned', 'in-progress']}
1674 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1675 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1676
1677In addition to C<-and> and C<-or>, there is also a special C<-nest>
1678operator which adds an additional set of parens, to create a subquery.
1679For example, to get something like this:
1680
86298391 1681 $stmt = "WHERE user = ? AND ( workhrs > ? OR geo = ? )";
32eab2da 1682 @bind = ('nwiger', '20', 'ASIA');
1683
1684You would do:
1685
1686 my %where = (
1687 user => 'nwiger',
1688 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1689 );
1690
e3f9dff4 1691If you need several nested subexpressions, you can number
1692the C<-nest> branches :
1693
1694 my %where = (
1695 user => 'nwiger',
1696 -nest1 => ...,
1697 -nest2 => ...,
1698 ...
1699 );
1700
1701
96449e8e 1702=head2 Special operators : IN, BETWEEN, etc.
1703
32eab2da 1704You can also use the hashref format to compare a list of fields using the
1705C<IN> comparison operator, by specifying the list as an arrayref:
1706
1707 my %where = (
1708 status => 'completed',
1709 reportid => { -in => [567, 2335, 2] }
1710 );
1711
1712Which would generate:
1713
1714 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1715 @bind = ('completed', '567', '2335', '2');
1716
96449e8e 1717The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1718the same way.
1719
1720Another pair of operators is C<-between> and C<-not_between>,
1721used with an arrayref of two values:
32eab2da 1722
1723 my %where = (
1724 user => 'nwiger',
1725 completion_date => {
1726 -not_between => ['2002-10-01', '2003-02-06']
1727 }
1728 );
1729
1730Would give you:
1731
1732 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1733
96449e8e 1734These are the two builtin "special operators"; but the
1735list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1736
1737=head2 Nested conditions
1738
32eab2da 1739So far, we've seen how multiple conditions are joined with a top-level
1740C<AND>. We can change this by putting the different conditions we want in
1741hashes and then putting those hashes in an array. For example:
1742
1743 my @where = (
1744 {
1745 user => 'nwiger',
1746 status => { -like => ['pending%', 'dispatched'] },
1747 },
1748 {
1749 user => 'robot',
1750 status => 'unassigned',
1751 }
1752 );
1753
1754This data structure would create the following:
1755
1756 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1757 OR ( user = ? AND status = ? ) )";
1758 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1759
1760This can be combined with the C<-nest> operator to properly group
1761SQL statements:
1762
1763 my @where = (
1764 -and => [
1765 user => 'nwiger',
1766 -nest => [
d2a8fe1a 1767 ["-and", workhrs => {'>', 20}, geo => 'ASIA' ],
1768 ["-and", workhrs => {'<', 50}, geo => 'EURO' ]
32eab2da 1769 ],
1770 ],
1771 );
1772
1773That would yield:
1774
1775 WHERE ( user = ? AND
1776 ( ( workhrs > ? AND geo = ? )
1777 OR ( workhrs < ? AND geo = ? ) ) )
1778
96449e8e 1779=head2 Literal SQL
1780
32eab2da 1781Finally, sometimes only literal SQL will do. If you want to include
1782literal SQL verbatim, you can specify it as a scalar reference, namely:
1783
1784 my $inn = 'is Not Null';
1785 my %where = (
1786 priority => { '<', 2 },
1787 requestor => \$inn
1788 );
1789
1790This would create:
1791
1792 $stmt = "WHERE priority < ? AND requestor is Not Null";
1793 @bind = ('2');
1794
1795Note that in this example, you only get one bind parameter back, since
1796the verbatim SQL is passed as part of the statement.
1797
1798Of course, just to prove a point, the above can also be accomplished
1799with this:
1800
1801 my %where = (
1802 priority => { '<', 2 },
1803 requestor => { '!=', undef },
1804 );
1805
96449e8e 1806
32eab2da 1807TMTOWTDI.
1808
96449e8e 1809Conditions on boolean columns can be expressed in the
1810same way, passing a reference to an empty string :
1811
1812 my %where = (
1813 priority => { '<', 2 },
1814 is_ready => \"";
1815 );
1816
1817which yields
1818
1819 $stmt = "WHERE priority < ? AND is_ready";
1820 @bind = ('2');
1821
1822
1823=head2 Literal SQL with placeholders and bind values (subqueries)
1824
1825If the literal SQL to be inserted has placeholders and bind values,
1826use a reference to an arrayref (yes this is a double reference --
1827not so common, but perfectly legal Perl). For example, to find a date
1828in Postgres you can use something like this:
1829
1830 my %where = (
1831 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1832 )
1833
1834This would create:
1835
d2a8fe1a 1836 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 1837 @bind = ('10');
1838
1839
1840Literal SQL is especially useful for nesting parenthesized clauses in the
1841main SQL query. Here is a first example :
1842
1843 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1844 100, "foo%");
1845 my %where = (
1846 foo => 1234,
1847 bar => \["IN ($sub_stmt)" => @sub_bind],
1848 );
1849
1850This yields :
1851
1852 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
1853 WHERE c2 < ? AND c3 LIKE ?))";
1854 @bind = (1234, 100, "foo%");
1855
1856Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
1857are expressed in the same way. Of course the C<$sub_stmt> and
1858its associated bind values can be generated through a former call
1859to C<select()> :
1860
1861 my ($sub_stmt, @sub_bind)
1862 = $sql->select("t1", "c1", {c2 => {"<" => 100},
1863 c3 => {-like => "foo%"}});
1864 my %where = (
1865 foo => 1234,
1866 bar => \["> ALL ($sub_stmt)" => @sub_bind],
1867 );
1868
1869In the examples above, the subquery was used as an operator on a column;
1870but the same principle also applies for a clause within the main C<%where>
1871hash, like an EXISTS subquery :
1872
1873 my ($sub_stmt, @sub_bind)
1874 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
1875 my %where = (
1876 foo => 1234,
1877 -nest => \["EXISTS ($sub_stmt)" => @sub_bind],
1878 );
1879
1880which yields
1881
1882 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
1883 WHERE c1 = ? AND c2 > t0.c0))";
1884 @bind = (1234, 1);
1885
1886
1887Observe that the condition on C<c2> in the subquery refers to
1888column C<t0.c0> of the main query : this is I<not> a bind
1889value, so we have to express it through a scalar ref.
1890Writing C<< c2 => {">" => "t0.c0"} >> would have generated
1891C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
1892what we wanted here.
1893
1894Another use of the subquery technique is when some SQL clauses need
1895parentheses, as it often occurs with some proprietary SQL extensions
1896like for example fulltext expressions, geospatial expressions,
1897NATIVE clauses, etc. Here is an example of a fulltext query in MySQL :
1898
1899 my %where = (
1900 -nest => \["MATCH (col1, col2) AGAINST (?)" => qw/apples/]
1901 );
1902
1903Finally, here is an example where a subquery is used
1904for expressing unary negation:
1905
1906 my ($sub_stmt, @sub_bind)
1907 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
1908 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
1909 my %where = (
1910 lname => {like => '%son%'},
1911 -nest => \["NOT ($sub_stmt)" => @sub_bind],
1912 );
1913
1914This yields
1915
1916 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
1917 @bind = ('%son%', 10, 20)
1918
1919
1920
1921=head2 Conclusion
1922
32eab2da 1923These pages could go on for a while, since the nesting of the data
1924structures this module can handle are pretty much unlimited (the
1925module implements the C<WHERE> expansion as a recursive function
1926internally). Your best bet is to "play around" with the module a
1927little to see how the data structures behave, and choose the best
1928format for your data based on that.
1929
1930And of course, all the values above will probably be replaced with
1931variables gotten from forms or the command line. After all, if you
1932knew everything ahead of time, you wouldn't have to worry about
1933dynamically-generating SQL and could just hardwire it into your
1934script.
1935
96449e8e 1936
1937
1938
86298391 1939=head1 ORDER BY CLAUSES
1940
1941Some functions take an order by clause. This can either be a scalar (just a
1942column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1cfa1db3 1943or an array of either of the two previous forms. Examples:
1944
1945 Given | Will Generate
1946 ----------------------------------------------------------
1947 \'colA DESC' | ORDER BY colA DESC
1948 'colA' | ORDER BY colA
1949 [qw/colA colB/] | ORDER BY colA, colB
1950 {-asc => 'colA'} | ORDER BY colA ASC
1951 {-desc => 'colB'} | ORDER BY colB DESC
1952 [ |
1953 {-asc => 'colA'}, | ORDER BY colA ASC, colB DESC
1954 {-desc => 'colB'} |
1955 ] |
1956 [colA => {-asc => 'colB'}] | ORDER BY colA, colB ASC
1957 ==========================================================
86298391 1958
96449e8e 1959
1960
1961=head1 SPECIAL OPERATORS
1962
e3f9dff4 1963 my $sqlmaker = SQL::Abstract->new(special_ops => [
1964 {regex => qr/.../,
1965 handler => sub {
1966 my ($self, $field, $op, $arg) = @_;
1967 ...
1968 },
1969 },
1970 ]);
1971
1972A "special operator" is a SQL syntactic clause that can be
1973applied to a field, instead of a usual binary operator.
1974For example :
1975
1976 WHERE field IN (?, ?, ?)
1977 WHERE field BETWEEN ? AND ?
1978 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 1979
e3f9dff4 1980Special operators IN and BETWEEN are fairly standard and therefore
1981are builtin within C<SQL::Abstract>. For other operators,
1982like the MATCH .. AGAINST example above which is
1983specific to MySQL, you can write your own operator handlers :
1984supply a C<special_ops> argument to the C<new> method.
1985That argument takes an arrayref of operator definitions;
1986each operator definition is a hashref with two entries
96449e8e 1987
e3f9dff4 1988=over
1989
1990=item regex
1991
1992the regular expression to match the operator
96449e8e 1993
e3f9dff4 1994=item handler
1995
1996coderef that will be called when meeting that operator
1997in the input tree. The coderef will be called with
1998arguments C<< ($self, $field, $op, $arg) >>, and
1999should return a C<< ($sql, @bind) >> structure.
2000
2001=back
2002
2003For example, here is an implementation
2004of the MATCH .. AGAINST syntax for MySQL
2005
2006 my $sqlmaker = SQL::Abstract->new(special_ops => [
2007
2008 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
2009 {regex => qr/^match$/i,
2010 handler => sub {
2011 my ($self, $field, $op, $arg) = @_;
2012 $arg = [$arg] if not ref $arg;
2013 my $label = $self->_quote($field);
2014 my ($placeholder) = $self->_convert('?');
2015 my $placeholders = join ", ", (($placeholder) x @$arg);
2016 my $sql = $self->_sqlcase('match') . " ($label) "
2017 . $self->_sqlcase('against') . " ($placeholders) ";
2018 my @bind = $self->_bindtype($field, @$arg);
2019 return ($sql, @bind);
2020 }
2021 },
2022
2023 ]);
96449e8e 2024
2025
32eab2da 2026=head1 PERFORMANCE
2027
2028Thanks to some benchmarking by Mark Stosberg, it turns out that
2029this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2030I must admit this wasn't an intentional design issue, but it's a
2031byproduct of the fact that you get to control your C<DBI> handles
2032yourself.
2033
2034To maximize performance, use a code snippet like the following:
2035
2036 # prepare a statement handle using the first row
2037 # and then reuse it for the rest of the rows
2038 my($sth, $stmt);
2039 for my $href (@array_of_hashrefs) {
2040 $stmt ||= $sql->insert('table', $href);
2041 $sth ||= $dbh->prepare($stmt);
2042 $sth->execute($sql->values($href));
2043 }
2044
2045The reason this works is because the keys in your C<$href> are sorted
2046internally by B<SQL::Abstract>. Thus, as long as your data retains
2047the same structure, you only have to generate the SQL the first time
2048around. On subsequent queries, simply use the C<values> function provided
2049by this module to return your values in the correct order.
2050
96449e8e 2051
32eab2da 2052=head1 FORMBUILDER
2053
2054If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2055really like this part (I do, at least). Building up a complex query
2056can be as simple as the following:
2057
2058 #!/usr/bin/perl
2059
2060 use CGI::FormBuilder;
2061 use SQL::Abstract;
2062
2063 my $form = CGI::FormBuilder->new(...);
2064 my $sql = SQL::Abstract->new;
2065
2066 if ($form->submitted) {
2067 my $field = $form->field;
2068 my $id = delete $field->{id};
2069 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2070 }
2071
2072Of course, you would still have to connect using C<DBI> to run the
2073query, but the point is that if you make your form look like your
2074table, the actual query script can be extremely simplistic.
2075
2076If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
2077a fast interface to returning and formatting data. I frequently
2078use these three modules together to write complex database query
2079apps in under 50 lines.
2080
32eab2da 2081
96449e8e 2082=head1 CHANGES
2083
2084Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
2085Great care has been taken to preserve the I<published> behavior
2086documented in previous versions in the 1.* family; however,
2087some features that were previously undocumented, or behaved
2088differently from the documentation, had to be changed in order
2089to clarify the semantics. Hence, client code that was relying
2090on some dark areas of C<SQL::Abstract> v1.*
2091B<might behave differently> in v1.50.
32eab2da 2092
d2a8fe1a 2093The main changes are :
2094
96449e8e 2095=over
32eab2da 2096
96449e8e 2097=item *
32eab2da 2098
96449e8e 2099support for literal SQL through the C<< \ [$sql, bind] >> syntax.
2100
2101=item *
2102
145fbfc8 2103support for the { operator => \"..." } construct (to embed literal SQL)
2104
2105=item *
2106
9c37b9c0 2107support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
2108
2109=item *
2110
96449e8e 2111added -nest1, -nest2 or -nest_1, -nest_2, ...
2112
2113=item *
2114
2115optional support for L<array datatypes|/"Inserting and Updating Arrays">
2116
2117=item *
2118
2119defensive programming : check arguments
2120
2121=item *
2122
2123fixed bug with global logic, which was previously implemented
2124through global variables yielding side-effects. Prior versons would
2125interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
2126as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
2127Now this is interpreted
2128as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
2129
2130=item *
2131
2132C<-and> / C<-or> operators are no longer accepted
2133in the middle of an arrayref : they are
2134only admitted if in first position.
2135
2136=item *
2137
2138changed logic for distributing an op over arrayrefs
2139
2140=item *
2141
2142fixed semantics of _bindtype on array args
2143
2144=item *
2145
2146dropped the C<_anoncopy> of the %where tree. No longer necessary,
2147we just avoid shifting arrays within that tree.
2148
2149=item *
2150
2151dropped the C<_modlogic> function
2152
2153=back
32eab2da 2154
32eab2da 2155
32eab2da 2156
2157=head1 ACKNOWLEDGEMENTS
2158
2159There are a number of individuals that have really helped out with
2160this module. Unfortunately, most of them submitted bugs via CPAN
2161so I have no idea who they are! But the people I do know are:
2162
86298391 2163 Ash Berlin (order_by hash term support)
b643abe1 2164 Matt Trout (DBIx::Class support)
32eab2da 2165 Mark Stosberg (benchmarking)
2166 Chas Owens (initial "IN" operator support)
2167 Philip Collins (per-field SQL functions)
2168 Eric Kolve (hashref "AND" support)
2169 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
2170 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 2171 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
96449e8e 2172 Laurent Dami (internal refactoring, multiple -nest, extensible list of special operators, literal SQL)
dbdf7648 2173 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
32eab2da 2174
2175Thanks!
2176
32eab2da 2177=head1 SEE ALSO
2178
86298391 2179L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 2180
32eab2da 2181=head1 AUTHOR
2182
b643abe1 2183Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
2184
2185This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 2186
abe72f94 2187For support, your best bet is to try the C<DBIx::Class> users mailing list.
2188While not an official support venue, C<DBIx::Class> makes heavy use of
2189C<SQL::Abstract>, and as such list members there are very familiar with
2190how to create queries.
2191
32eab2da 2192This module is free software; you may copy this under the terms of
2193the GNU General Public License, or the Artistic License, copies of
2194which should have accompanied your Perl kit.
2195
2196=cut
2197