abstract from code imported from DBIC::SQL::Abstract plus tests
[dbsrgits/SQL-Abstract.git] / lib / SQL / Abstract.pm
CommitLineData
32eab2da 1
2package SQL::Abstract;
3
4=head1 NAME
5
6SQL::Abstract - Generate SQL from Perl data structures
7
8=head1 SYNOPSIS
9
10 use SQL::Abstract;
11
12 my $sql = SQL::Abstract->new;
13
14 my($stmt, @bind) = $sql->select($table, \@fields, \%where, \@order);
15
16 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
17
18 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
19
20 my($stmt, @bind) = $sql->delete($table, \%where);
21
22 # Then, use these in your DBI statements
23 my $sth = $dbh->prepare($stmt);
24 $sth->execute(@bind);
25
26 # Just generate the WHERE clause
abe72f94 27 my($stmt, @bind) = $sql->where(\%where, \@order);
32eab2da 28
29 # Return values in the same order, for hashed queries
30 # See PERFORMANCE section for more details
31 my @bind = $sql->values(\%fieldvals);
32
33=head1 DESCRIPTION
34
35This module was inspired by the excellent L<DBIx::Abstract>.
36However, in using that module I found that what I really wanted
37to do was generate SQL, but still retain complete control over my
38statement handles and use the DBI interface. So, I set out to
39create an abstract SQL generation module.
40
41While based on the concepts used by L<DBIx::Abstract>, there are
42several important differences, especially when it comes to WHERE
43clauses. I have modified the concepts used to make the SQL easier
44to generate from Perl data structures and, IMO, more intuitive.
45The underlying idea is for this module to do what you mean, based
46on the data structures you provide it. The big advantage is that
47you don't have to modify your code every time your data changes,
48as this module figures it out.
49
50To begin with, an SQL INSERT is as easy as just specifying a hash
51of C<key=value> pairs:
52
53 my %data = (
54 name => 'Jimbo Bobson',
55 phone => '123-456-7890',
56 address => '42 Sister Lane',
57 city => 'St. Louis',
58 state => 'Louisiana',
59 );
60
61The SQL can then be generated with this:
62
63 my($stmt, @bind) = $sql->insert('people', \%data);
64
65Which would give you something like this:
66
67 $stmt = "INSERT INTO people
68 (address, city, name, phone, state)
69 VALUES (?, ?, ?, ?, ?)";
70 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
71 '123-456-7890', 'Louisiana');
72
73These are then used directly in your DBI code:
74
75 my $sth = $dbh->prepare($stmt);
76 $sth->execute(@bind);
77
78In addition, you can apply SQL functions to elements of your C<%data>
79by specifying an arrayref for the given hash value. For example, if
80you need to execute the Oracle C<to_date> function on a value, you
81can say something like this:
82
83 my %data = (
84 name => 'Bill',
85 date_entered => ["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
86 );
87
88The first value in the array is the actual SQL. Any other values are
89optional and would be included in the bind values array. This gives
90you:
91
92 my($stmt, @bind) = $sql->insert('people', \%data);
93
94 $stmt = "INSERT INTO people (name, date_entered)
95 VALUES (?, to_date(?,'MM/DD/YYYY'))";
96 @bind = ('Bill', '03/02/2003');
97
98An UPDATE is just as easy, all you change is the name of the function:
99
100 my($stmt, @bind) = $sql->update('people', \%data);
101
102Notice that your C<%data> isn't touched; the module will generate
103the appropriately quirky SQL for you automatically. Usually you'll
104want to specify a WHERE clause for your UPDATE, though, which is
105where handling C<%where> hashes comes in handy...
106
107This module can generate pretty complicated WHERE statements
108easily. For example, simple C<key=value> pairs are taken to mean
109equality, and if you want to see if a field is within a set
110of values, you can use an arrayref. Let's say we wanted to
111SELECT some data based on this criteria:
112
113 my %where = (
114 requestor => 'inna',
115 worker => ['nwiger', 'rcwe', 'sfz'],
116 status => { '!=', 'completed' }
117 );
118
119 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
120
121The above would give you something like this:
122
123 $stmt = "SELECT * FROM tickets WHERE
124 ( requestor = ? ) AND ( status != ? )
125 AND ( worker = ? OR worker = ? OR worker = ? )";
126 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
127
128Which you could then use in DBI code like so:
129
130 my $sth = $dbh->prepare($stmt);
131 $sth->execute(@bind);
132
133Easy, eh?
134
135=head1 FUNCTIONS
136
137The functions are simple. There's one for each major SQL operation,
138and a constructor you use first. The arguments are specified in a
139similar order to each function (table, then fields, then a where
140clause) to try and simplify things.
141
142=cut
143
144use Carp;
145use strict;
146
69f2a249 147our $VERSION = '1.22';
148our $REVISION = '$Id$';
32eab2da 149our $AUTOLOAD;
150
151# Fix SQL case, if so requested
152sub _sqlcase {
153 my $self = shift;
154 return $self->{case} ? $_[0] : uc($_[0]);
155}
156
157# Anon copies of arrays/hashes
158# Based on deep_copy example by merlyn
159# http://www.stonehenge.com/merlyn/UnixReview/col30.html
160sub _anoncopy {
161 my $orig = shift;
162 return (ref $orig eq 'HASH') ? +{map { $_ => _anoncopy($orig->{$_}) } keys %$orig}
163 : (ref $orig eq 'ARRAY') ? [map _anoncopy($_), @$orig]
164 : $orig;
165}
166
167# Debug
168sub _debug {
169 return unless $_[0]->{debug}; shift; # a little faster
170 my $func = (caller(1))[3];
171 warn "[$func] ", @_, "\n";
172}
173
174sub belch (@) {
175 my($func) = (caller(1))[3];
176 carp "[$func] Warning: ", @_;
177}
178
179sub puke (@) {
180 my($func) = (caller(1))[3];
181 croak "[$func] Fatal: ", @_;
182}
183
184# Utility functions
185sub _table {
186 my $self = shift;
83cab70b 187 my $from = shift;
188 if (ref $from eq 'ARRAY') {
189 return $self->_recurse_from(@$from);
190 } elsif (ref $from eq 'HASH') {
191 return $self->_make_as($from);
32eab2da 192 } else {
83cab70b 193 return $self->_quote($from);
32eab2da 194 }
195}
196
83cab70b 197sub _recurse_from {
198 my ($self, $from, @join) = @_;
199 my @sqlf;
200 push(@sqlf, $self->_make_as($from));
201 foreach my $j (@join) {
202 push @sqlf, ', ' . $self->_quote($j) and next unless ref $j;
203 push @sqlf, ', ' . $$j and next if ref $j eq 'SCALAR';
204 my ($to, $on) = @$j;
205
206 # check whether a join type exists
207 my $join_clause = '';
208 my $to_jt = ref($to) eq 'ARRAY' ? $to->[0] : $to;
209 if (ref($to_jt) eq 'HASH' and exists($to_jt->{-join_type})) {
210 $join_clause = $self->_sqlcase(' '.($to_jt->{-join_type}).' JOIN ');
211 } else {
212 $join_clause = $self->_sqlcase(' JOIN ');
213 }
214 push(@sqlf, $join_clause);
215
216 if (ref $to eq 'ARRAY') {
217 push(@sqlf, '(', $self->_recurse_from(@$to), ')');
218 } else {
219 push(@sqlf, $self->_make_as($to));
220 }
221 push(@sqlf, $self->_sqlcase(' ON '), $self->_join_condition($on));
222 }
223 return join('', @sqlf);
224}
225
226sub _make_as {
227 my ($self, $from) = @_;
228 return $self->_quote($from) unless ref $from;
229 return $$from if ref $from eq 'SCALAR';
230 return join(' ', map { (ref $_ eq 'SCALAR' ? $$_ : $self->_quote($_)) }
231 reverse each %{$self->_skip_options($from)});
232}
233
234sub _skip_options {
235 my ($self, $hash) = @_;
236 my $clean_hash = {};
237 $clean_hash->{$_} = $hash->{$_}
238 for grep {!/^-/} keys %$hash;
239 return $clean_hash;
240}
241
242sub _join_condition {
243 my ($self, $cond) = @_;
244 if (ref $cond eq 'HASH') {
245 my %j;
246 for (keys %$cond) {
247 my $x = '= '.$self->_quote($cond->{$_}); $j{$_} = \$x;
248 };
249 return $self->_recurse_where(\%j);
250 } elsif (ref $cond eq 'ARRAY') {
251 return join(' OR ', map { $self->_join_condition($_) } @$cond);
252 } else {
253 die "Can't handle this yet!";
254 }
255}
256
257
32eab2da 258sub _quote {
259 my $self = shift;
260 my $label = shift;
261
83cab70b 262 return '' unless defined $label;
263
32eab2da 264 return $label
265 if $label eq '*';
266
83cab70b 267 return $label unless $self->{quote_char};
268
269 if (ref $self->{quote_char} eq "ARRAY") {
270
271 return $self->{quote_char}->[0] . $label . $self->{quote_char}->[1]
272 if !defined $self->{name_sep};
273
274 my $sep = $self->{name_sep};
275 return join($self->{name_sep},
276 map { $self->{quote_char}->[0] . $_ . $self->{quote_char}->[1] }
277 split( /\Q$sep\E/, $label ) );
278 }
279
280
32eab2da 281 return $self->{quote_char} . $label . $self->{quote_char}
282 if !defined $self->{name_sep};
283
284 return join $self->{name_sep},
285 map { $self->{quote_char} . $_ . $self->{quote_char} }
286 split /\Q$self->{name_sep}\E/, $label;
287}
288
289# Conversion, if applicable
290sub _convert ($) {
291 my $self = shift;
292 return @_ unless $self->{convert};
293 my $conv = $self->_sqlcase($self->{convert});
294 my @ret = map { $conv.'('.$_.')' } @_;
295 return wantarray ? @ret : $ret[0];
296}
297
298# And bindtype
299sub _bindtype (@) {
300 my $self = shift;
301 my($col,@val) = @_;
302 return $self->{bindtype} eq 'columns' ? [ @_ ] : @val;
303}
304
305# Modified -logic or -nest
306sub _modlogic ($) {
307 my $self = shift;
308 my $sym = @_ ? lc(shift) : $self->{logic};
309 $sym =~ tr/_/ /;
310 $sym = $self->{logic} if $sym eq 'nest';
311 return $self->_sqlcase($sym); # override join
312}
313
314=head2 new(option => 'value')
315
316The C<new()> function takes a list of options and values, and returns
317a new B<SQL::Abstract> object which can then be used to generate SQL
318through the methods below. The options accepted are:
319
320=over
321
322=item case
323
324If set to 'lower', then SQL will be generated in all lowercase. By
325default SQL is generated in "textbook" case meaning something like:
326
327 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
328
329=item cmp
330
331This determines what the default comparison operator is. By default
332it is C<=>, meaning that a hash like this:
333
334 %where = (name => 'nwiger', email => 'nate@wiger.org');
335
336Will generate SQL like this:
337
338 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
339
340However, you may want loose comparisons by default, so if you set
341C<cmp> to C<like> you would get SQL such as:
342
343 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
344
345You can also override the comparsion on an individual basis - see
346the huge section on L</"WHERE CLAUSES"> at the bottom.
347
348=item logic
349
350This determines the default logical operator for multiple WHERE
351statements in arrays. By default it is "or", meaning that a WHERE
352array of the form:
353
354 @where = (
355 event_date => {'>=', '2/13/99'},
356 event_date => {'<=', '4/24/03'},
357 );
358
359Will generate SQL like this:
360
361 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
362
363This is probably not what you want given this query, though (look
364at the dates). To change the "OR" to an "AND", simply specify:
365
366 my $sql = SQL::Abstract->new(logic => 'and');
367
368Which will change the above C<WHERE> to:
369
370 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
371
372=item convert
373
374This will automatically convert comparisons using the specified SQL
375function for both column and value. This is mostly used with an argument
376of C<upper> or C<lower>, so that the SQL will have the effect of
377case-insensitive "searches". For example, this:
378
379 $sql = SQL::Abstract->new(convert => 'upper');
380 %where = (keywords => 'MaKe iT CAse inSeNSItive');
381
382Will turn out the following SQL:
383
384 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
385
386The conversion can be C<upper()>, C<lower()>, or any other SQL function
387that can be applied symmetrically to fields (actually B<SQL::Abstract> does
388not validate this option; it will just pass through what you specify verbatim).
389
390=item bindtype
391
392This is a kludge because many databases suck. For example, you can't
393just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
394Instead, you have to use C<bind_param()>:
395
396 $sth->bind_param(1, 'reg data');
397 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
398
399The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
400which loses track of which field each slot refers to. Fear not.
401
402If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
403Currently, you can specify either C<normal> (default) or C<columns>. If you
404specify C<columns>, you will get an array that looks like this:
405
406 my $sql = SQL::Abstract->new(bindtype => 'columns');
407 my($stmt, @bind) = $sql->insert(...);
408
409 @bind = (
410 [ 'column1', 'value1' ],
411 [ 'column2', 'value2' ],
412 [ 'column3', 'value3' ],
413 );
414
415You can then iterate through this manually, using DBI's C<bind_param()>.
416
417 $sth->prepare($stmt);
418 my $i = 1;
419 for (@bind) {
420 my($col, $data) = @$_;
421 if ($col eq 'details' || $col eq 'comments') {
422 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
423 } elsif ($col eq 'image') {
424 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
425 } else {
426 $sth->bind_param($i, $data);
427 }
428 $i++;
429 }
430 $sth->execute; # execute without @bind now
431
432Now, why would you still use B<SQL::Abstract> if you have to do this crap?
433Basically, the advantage is still that you don't have to care which fields
434are or are not included. You could wrap that above C<for> loop in a simple
435sub called C<bind_fields()> or something and reuse it repeatedly. You still
436get a layer of abstraction over manual SQL specification.
437
438=item quote_char
439
440This is the character that a table or column name will be quoted
441with. By default this is an empty string, but you could set it to
442the character C<`>, to generate SQL like this:
443
444 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
445
446This is useful if you have tables or columns that are reserved words
447in your database's SQL dialect.
448
449=item name_sep
450
451This is the character that separates a table and column name. It is
452necessary to specify this when the C<quote_char> option is selected,
453so that tables and column names can be individually quoted like this:
454
455 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
456
457=back
458
459=cut
460
461sub new {
462 my $self = shift;
463 my $class = ref($self) || $self;
464 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
465
466 # choose our case by keeping an option around
467 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
468
469 # override logical operator
470 $opt{logic} = uc $opt{logic} if $opt{logic};
471
472 # how to return bind vars
473 $opt{bindtype} ||= delete($opt{bind_type}) || 'normal';
474
475 # default comparison is "=", but can be overridden
476 $opt{cmp} ||= '=';
477
478 # default quotation character around tables/columns
479 $opt{quote_char} ||= '';
480
481 return bless \%opt, $class;
482}
483
484=head2 insert($table, \@values || \%fieldvals)
485
486This is the simplest function. You simply give it a table name
487and either an arrayref of values or hashref of field/value pairs.
488It returns an SQL INSERT statement and a list of bind values.
489
490=cut
491
492sub insert {
493 my $self = shift;
494 my $table = $self->_table(shift);
495 my $data = shift || return;
496
497 my $sql = $self->_sqlcase('insert into') . " $table ";
498 my(@sqlf, @sqlv, @sqlq) = ();
499
500 my $ref = ref $data;
501 if ($ref eq 'HASH') {
502 for my $k (sort keys %$data) {
503 my $v = $data->{$k};
504 my $r = ref $v;
505 # named fields, so must save names in order
506 push @sqlf, $self->_quote($k);
507 if ($r eq 'ARRAY') {
508 # SQL included for values
509 my @val = @$v;
510 push @sqlq, shift @val;
511 push @sqlv, $self->_bindtype($k, @val);
512 } elsif ($r eq 'SCALAR') {
513 # embedded literal SQL
514 push @sqlq, $$v;
515 } else {
516 push @sqlq, '?';
517 push @sqlv, $self->_bindtype($k, $v);
518 }
519 }
520 $sql .= '(' . join(', ', @sqlf) .') '. $self->_sqlcase('values') . ' ('. join(', ', @sqlq) .')';
521 } elsif ($ref eq 'ARRAY') {
522 # just generate values(?,?) part
523 # no names (arrayref) so can't generate bindtype
524 carp "Warning: ",__PACKAGE__,"->insert called with arrayref when bindtype set"
525 if $self->{bindtype} ne 'normal';
526 for my $v (@$data) {
527 my $r = ref $v;
528 if ($r eq 'ARRAY') {
529 my @val = @$v;
530 push @sqlq, shift @val;
531 push @sqlv, @val;
532 } elsif ($r eq 'SCALAR') {
533 # embedded literal SQL
534 push @sqlq, $$v;
535 } else {
536 push @sqlq, '?';
537 push @sqlv, $v;
538 }
539 }
540 $sql .= $self->_sqlcase('values') . ' ('. join(', ', @sqlq) .')';
541 } elsif ($ref eq 'SCALAR') {
542 # literal SQL
543 $sql .= $$data;
544 } else {
545 puke "Unsupported data type specified to \$sql->insert";
546 }
547
548 return wantarray ? ($sql, @sqlv) : $sql;
549}
550
551=head2 update($table, \%fieldvals, \%where)
552
553This takes a table, hashref of field/value pairs, and an optional
554hashref WHERE clause. It returns an SQL UPDATE function and a list
555of bind values.
556
557=cut
558
559sub update {
560 my $self = shift;
561 my $table = $self->_table(shift);
562 my $data = shift || return;
563 my $where = shift;
564
565 my $sql = $self->_sqlcase('update') . " $table " . $self->_sqlcase('set ');
566 my(@sqlf, @sqlv) = ();
567
568 puke "Unsupported data type specified to \$sql->update"
569 unless ref $data eq 'HASH';
570
571 for my $k (sort keys %$data) {
572 my $v = $data->{$k};
573 my $r = ref $v;
574 my $label = $self->_quote($k);
575 if ($r eq 'ARRAY') {
576 # SQL included for values
577 my @bind = @$v;
578 my $sql = shift @bind;
579 push @sqlf, "$label = $sql";
580 push @sqlv, $self->_bindtype($k, @bind);
581 } elsif ($r eq 'SCALAR') {
582 # embedded literal SQL
583 push @sqlf, "$label = $$v";
584 } else {
585 push @sqlf, "$label = ?";
586 push @sqlv, $self->_bindtype($k, $v);
587 }
588 }
589
590 $sql .= join ', ', @sqlf;
591
592 if ($where) {
593 my($wsql, @wval) = $self->where($where);
594 $sql .= $wsql;
595 push @sqlv, @wval;
596 }
597
598 return wantarray ? ($sql, @sqlv) : $sql;
599}
600
601=head2 select($table, \@fields, \%where, \@order)
602
603This takes a table, arrayref of fields (or '*'), optional hashref
604WHERE clause, and optional arrayref order by, and returns the
605corresponding SQL SELECT statement and list of bind values.
606
607=cut
608
609sub select {
610 my $self = shift;
611 my $table = $self->_table(shift);
612 my $fields = shift || '*';
613 my $where = shift;
614 my $order = shift;
615
616 my $f = (ref $fields eq 'ARRAY') ? join ', ', map { $self->_quote($_) } @$fields : $fields;
617 my $sql = join ' ', $self->_sqlcase('select'), $f, $self->_sqlcase('from'), $table;
618
619 my(@sqlf, @sqlv) = ();
620 my($wsql, @wval) = $self->where($where, $order);
621 $sql .= $wsql;
622 push @sqlv, @wval;
623
624 return wantarray ? ($sql, @sqlv) : $sql;
625}
626
627=head2 delete($table, \%where)
628
629This takes a table name and optional hashref WHERE clause.
630It returns an SQL DELETE statement and list of bind values.
631
632=cut
633
634sub delete {
635 my $self = shift;
636 my $table = $self->_table(shift);
637 my $where = shift;
638
639 my $sql = $self->_sqlcase('delete from') . " $table";
640 my(@sqlf, @sqlv) = ();
641
642 if ($where) {
643 my($wsql, @wval) = $self->where($where);
644 $sql .= $wsql;
645 push @sqlv, @wval;
646 }
647
648 return wantarray ? ($sql, @sqlv) : $sql;
649}
650
651=head2 where(\%where, \@order)
652
653This is used to generate just the WHERE clause. For example,
654if you have an arbitrary data structure and know what the
655rest of your SQL is going to look like, but want an easy way
656to produce a WHERE clause, use this. It returns an SQL WHERE
657clause and list of bind values.
658
659=cut
660
661# Finally, a separate routine just to handle WHERE clauses
662sub where {
663 my $self = shift;
664 my $where = shift;
665 my $order = shift;
666
667 # Need a separate routine to properly wrap w/ "where"
668 my $sql = '';
669 my @ret = $self->_recurse_where($where);
670 if (@ret) {
671 my $wh = shift @ret;
672 $sql .= $self->_sqlcase(' where ') . $wh if $wh;
673 }
674
675 # order by?
676 if ($order) {
677 $sql .= $self->_order_by($order);
678 }
679
680 return wantarray ? ($sql, @ret) : $sql;
681}
682
683
684sub _recurse_where {
685 local $^W = 0; # really, you've gotta be fucking kidding me
686 my $self = shift;
687 my $where = _anoncopy(shift); # prevent destroying original
688 my $ref = ref $where || '';
689 my $join = shift || $self->{logic} ||
690 ($ref eq 'ARRAY' ? $self->_sqlcase('or') : $self->_sqlcase('and'));
691
692 # For assembling SQL fields and values
693 my(@sqlf, @sqlv) = ();
694
695 # If an arrayref, then we join each element
696 if ($ref eq 'ARRAY') {
697 # need to use while() so can shift() for arrays
698 my $subjoin;
699 while (my $el = shift @$where) {
700
701 # skip empty elements, otherwise get invalid trailing AND stuff
702 if (my $ref2 = ref $el) {
703 if ($ref2 eq 'ARRAY') {
704 next unless @$el;
705 } elsif ($ref2 eq 'HASH') {
706 next unless %$el;
707 $subjoin ||= $self->_sqlcase('and');
708 } elsif ($ref2 eq 'SCALAR') {
709 # literal SQL
710 push @sqlf, $$el;
711 next;
712 }
713 $self->_debug("$ref2(*top) means join with $subjoin");
714 } else {
715 # top-level arrayref with scalars, recurse in pairs
716 $self->_debug("NOREF(*top) means join with $subjoin");
717 $el = {$el => shift(@$where)};
718 }
719 my @ret = $self->_recurse_where($el, $subjoin);
720 push @sqlf, shift @ret;
721 push @sqlv, @ret;
722 }
723 }
724 elsif ($ref eq 'HASH') {
725 # Note: during recursion, the last element will always be a hashref,
726 # since it needs to point a column => value. So this be the end.
727 for my $k (sort keys %$where) {
728 my $v = $where->{$k};
729 my $label = $self->_quote($k);
61fdf29c 730
32eab2da 731 if ($k =~ /^-(\D+)/) {
732 # special nesting, like -and, -or, -nest, so shift over
733 my $subjoin = $self->_modlogic($1);
734 $self->_debug("OP(-$1) means special logic ($subjoin), recursing...");
735 my @ret = $self->_recurse_where($v, $subjoin);
736 push @sqlf, shift @ret;
737 push @sqlv, @ret;
738 } elsif (! defined($v)) {
739 # undef = null
740 $self->_debug("UNDEF($k) means IS NULL");
741 push @sqlf, $label . $self->_sqlcase(' is null');
742 } elsif (ref $v eq 'ARRAY') {
743 my @v = @$v;
744
745 # multiple elements: multiple options
746 $self->_debug("ARRAY($k) means multiple elements: [ @v ]");
747
748 # special nesting, like -and, -or, -nest, so shift over
749 my $subjoin = $self->_sqlcase('or');
750 if ($v[0] =~ /^-(\D+)/) {
751 $subjoin = $self->_modlogic($1); # override subjoin
752 $self->_debug("OP(-$1) means special logic ($subjoin), shifting...");
753 shift @v;
754 }
755
756 # map into an array of hashrefs and recurse
757 my @ret = $self->_recurse_where([map { {$k => $_} } @v], $subjoin);
758
759 # push results into our structure
760 push @sqlf, shift @ret;
761 push @sqlv, @ret;
762 } elsif (ref $v eq 'HASH') {
763 # modified operator { '!=', 'completed' }
764 for my $f (sort keys %$v) {
765 my $x = $v->{$f};
61fdf29c 766
767 # do the right thing for single -in values
768 $x = [$x] if ($f =~ /^-?\s*(not[\s_]+)?in\s*$/i && ref $x ne 'ARRAY');
769
32eab2da 770 $self->_debug("HASH($k) means modified operator: { $f }");
771
772 # check for the operator being "IN" or "BETWEEN" or whatever
773 if (ref $x eq 'ARRAY') {
774 if ($f =~ /^-?\s*(not[\s_]+)?(in|between)\s*$/i) {
775 my $u = $self->_modlogic($1 . $2);
776 $self->_debug("HASH($f => $x) uses special operator: [ $u ]");
777 if ($u =~ /between/i) {
778 # SQL sucks
61fdf29c 779 # Throw an exception if you try to use between with
780 # anything other than 2 values
781 $self->puke("You need two values to use between") unless @$x == 2;
32eab2da 782 push @sqlf, join ' ', $self->_convert($label), $u, $self->_convert('?'),
783 $self->_sqlcase('and'), $self->_convert('?');
61fdf29c 784 } elsif (@$x) {
785 # DWIM for empty arrayrefs
32eab2da 786 push @sqlf, join ' ', $self->_convert($label), $u, '(',
787 join(', ', map { $self->_convert('?') } @$x),
788 ')';
61fdf29c 789 } elsif(@$x == 0){
790 # Empty IN defaults to 0=1 and empty NOT IN to 1=1
791 push(@sqlf, ($u =~ /not/i ? "1=1" : "0=1"));
32eab2da 792 }
793 push @sqlv, $self->_bindtype($k, @$x);
794 } else {
795 # multiple elements: multiple options
796 $self->_debug("ARRAY($x) means multiple elements: [ @$x ]");
797
798 # map into an array of hashrefs and recurse
799 my @ret = $self->_recurse_where([map { {$k => {$f, $_}} } @$x]);
800
801 # push results into our structure
802 push @sqlf, shift @ret;
803 push @sqlv, @ret;
804 }
805 } elsif (! defined($x)) {
806 # undef = NOT null
807 my $not = ($f eq '!=' || $f eq 'not like') ? ' not' : '';
808 push @sqlf, $label . $self->_sqlcase(" is$not null");
809 } else {
810 # regular ol' value
811 $f =~ s/^-//; # strip leading -like =>
812 $f =~ s/_/ /; # _ => " "
813 push @sqlf, join ' ', $self->_convert($label), $self->_sqlcase($f), $self->_convert('?');
814 push @sqlv, $self->_bindtype($k, $x);
815 }
816 }
817 } elsif (ref $v eq 'SCALAR') {
818 # literal SQL
819 $self->_debug("SCALAR($k) means literal SQL: $$v");
820 push @sqlf, "$label $$v";
821 } else {
822 # standard key => val
823 $self->_debug("NOREF($k) means simple key=val: $k $self->{cmp} $v");
824 push @sqlf, join ' ', $self->_convert($label), $self->_sqlcase($self->{cmp}), $self->_convert('?');
825 push @sqlv, $self->_bindtype($k, $v);
826 }
827 }
828 }
829 elsif ($ref eq 'SCALAR') {
830 # literal sql
831 $self->_debug("SCALAR(*top) means literal SQL: $$where");
832 push @sqlf, $$where;
833 }
834 elsif (defined $where) {
835 # literal sql
836 $self->_debug("NOREF(*top) means literal SQL: $where");
837 push @sqlf, $where;
838 }
839
840 # assemble and return sql
841 my $wsql = @sqlf ? '( ' . join(" $join ", @sqlf) . ' )' : '';
842 return wantarray ? ($wsql, @sqlv) : $wsql;
843}
844
845sub _order_by {
846 my $self = shift;
847 my $ref = ref $_[0];
848
849 my @vals = $ref eq 'ARRAY' ? @{$_[0]} :
850 $ref eq 'SCALAR' ? ${$_[0]} :
851 $ref eq '' ? $_[0] :
852 puke "Unsupported data struct $ref for ORDER BY";
853
854 my $val = join ', ', map { $self->_quote($_) } @vals;
855 return $val ? $self->_sqlcase(' order by')." $val" : '';
856}
857
858=head2 values(\%data)
859
860This just returns the values from the hash C<%data>, in the same
861order that would be returned from any of the other above queries.
862Using this allows you to markedly speed up your queries if you
863are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
864
865=cut
866
867sub values {
868 my $self = shift;
869 my $data = shift || return;
870 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
871 unless ref $data eq 'HASH';
872 return map { $self->_bindtype($_, $data->{$_}) } sort keys %$data;
873}
874
875=head2 generate($any, 'number', $of, \@data, $struct, \%types)
876
877Warning: This is an experimental method and subject to change.
878
879This returns arbitrarily generated SQL. It's a really basic shortcut.
880It will return two different things, depending on return context:
881
882 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
883 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
884
885These would return the following:
886
887 # First calling form
888 $stmt = "CREATE TABLE test (?, ?)";
889 @bind = (field1, field2);
890
891 # Second calling form
892 $stmt_and_val = "CREATE TABLE test (field1, field2)";
893
894Depending on what you're trying to do, it's up to you to choose the correct
895format. In this example, the second form is what you would want.
896
897By the same token:
898
899 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
900
901Might give you:
902
903 ALTER SESSION SET nls_date_format = 'MM/YY'
904
905You get the idea. Strings get their case twiddled, but everything
906else remains verbatim.
907
908=cut
909
910sub generate {
911 my $self = shift;
912
913 my(@sql, @sqlq, @sqlv);
914
915 for (@_) {
916 my $ref = ref $_;
917 if ($ref eq 'HASH') {
918 for my $k (sort keys %$_) {
919 my $v = $_->{$k};
920 my $r = ref $v;
921 my $label = $self->_quote($k);
922 if ($r eq 'ARRAY') {
923 # SQL included for values
924 my @bind = @$v;
925 my $sql = shift @bind;
926 push @sqlq, "$label = $sql";
927 push @sqlv, $self->_bindtype($k, @bind);
928 } elsif ($r eq 'SCALAR') {
929 # embedded literal SQL
930 push @sqlq, "$label = $$v";
931 } else {
932 push @sqlq, "$label = ?";
933 push @sqlv, $self->_bindtype($k, $v);
934 }
935 }
936 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
937 } elsif ($ref eq 'ARRAY') {
938 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
939 for my $v (@$_) {
940 my $r = ref $v;
941 if ($r eq 'ARRAY') {
942 my @val = @$v;
943 push @sqlq, shift @val;
944 push @sqlv, @val;
945 } elsif ($r eq 'SCALAR') {
946 # embedded literal SQL
947 push @sqlq, $$v;
948 } else {
949 push @sqlq, '?';
950 push @sqlv, $v;
951 }
952 }
953 push @sql, '(' . join(', ', @sqlq) . ')';
954 } elsif ($ref eq 'SCALAR') {
955 # literal SQL
956 push @sql, $$_;
957 } else {
958 # strings get case twiddled
959 push @sql, $self->_sqlcase($_);
960 }
961 }
962
963 my $sql = join ' ', @sql;
964
965 # this is pretty tricky
966 # if ask for an array, return ($stmt, @bind)
967 # otherwise, s/?/shift @sqlv/ to put it inline
968 if (wantarray) {
969 return ($sql, @sqlv);
970 } else {
971 1 while $sql =~ s/\?/my $d = shift(@sqlv);
972 ref $d ? $d->[1] : $d/e;
973 return $sql;
974 }
975}
976
977sub DESTROY { 1 }
978sub AUTOLOAD {
979 # This allows us to check for a local, then _form, attr
980 my $self = shift;
981 my($name) = $AUTOLOAD =~ /.*::(.+)/;
982 return $self->generate($name, @_);
983}
984
9851;
986
987__END__
988
989=head1 WHERE CLAUSES
990
991This module uses a variation on the idea from L<DBIx::Abstract>. It
992is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
993module is that things in arrays are OR'ed, and things in hashes
994are AND'ed.>
995
996The easiest way to explain is to show lots of examples. After
997each C<%where> hash shown, it is assumed you used:
998
999 my($stmt, @bind) = $sql->where(\%where);
1000
1001However, note that the C<%where> hash can be used directly in any
1002of the other functions as well, as described above.
1003
1004So, let's get started. To begin, a simple hash:
1005
1006 my %where = (
1007 user => 'nwiger',
1008 status => 'completed'
1009 );
1010
1011Is converted to SQL C<key = val> statements:
1012
1013 $stmt = "WHERE user = ? AND status = ?";
1014 @bind = ('nwiger', 'completed');
1015
1016One common thing I end up doing is having a list of values that
1017a field can be in. To do this, simply specify a list inside of
1018an arrayref:
1019
1020 my %where = (
1021 user => 'nwiger',
1022 status => ['assigned', 'in-progress', 'pending'];
1023 );
1024
1025This simple code will create the following:
1026
1027 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
1028 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
1029
1030If you want to specify a different type of operator for your comparison,
1031you can use a hashref for a given column:
1032
1033 my %where = (
1034 user => 'nwiger',
1035 status => { '!=', 'completed' }
1036 );
1037
1038Which would generate:
1039
1040 $stmt = "WHERE user = ? AND status != ?";
1041 @bind = ('nwiger', 'completed');
1042
1043To test against multiple values, just enclose the values in an arrayref:
1044
1045 status => { '!=', ['assigned', 'in-progress', 'pending'] };
1046
1047Which would give you:
1048
1049 "WHERE status != ? OR status != ? OR status != ?"
1050
1051But, this is probably not what you want in this case (look at it). So
1052the hashref can also contain multiple pairs, in which case it is expanded
1053into an C<AND> of its elements:
1054
1055 my %where = (
1056 user => 'nwiger',
1057 status => { '!=', 'completed', -not_like => 'pending%' }
1058 );
1059
1060 # Or more dynamically, like from a form
1061 $where{user} = 'nwiger';
1062 $where{status}{'!='} = 'completed';
1063 $where{status}{'-not_like'} = 'pending%';
1064
1065 # Both generate this
1066 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1067 @bind = ('nwiger', 'completed', 'pending%');
1068
1069To get an OR instead, you can combine it with the arrayref idea:
1070
1071 my %where => (
1072 user => 'nwiger',
1073 priority => [ {'=', 2}, {'!=', 1} ]
1074 );
1075
1076Which would generate:
1077
1078 $stmt = "WHERE user = ? AND priority = ? OR priority != ?";
1079 @bind = ('nwiger', '2', '1');
1080
1081However, there is a subtle trap if you want to say something like
1082this (notice the C<AND>):
1083
1084 WHERE priority != ? AND priority != ?
1085
1086Because, in Perl you I<can't> do this:
1087
1088 priority => { '!=', 2, '!=', 1 }
1089
1090As the second C<!=> key will obliterate the first. The solution
1091is to use the special C<-modifier> form inside an arrayref:
1092
1093 priority => [ -and => {'!=', 2}, {'!=', 1} ]
1094
1095Normally, these would be joined by C<OR>, but the modifier tells it
1096to use C<AND> instead. (Hint: You can use this in conjunction with the
1097C<logic> option to C<new()> in order to change the way your queries
1098work by default.) B<Important:> Note that the C<-modifier> goes
1099B<INSIDE> the arrayref, as an extra first element. This will
1100B<NOT> do what you think it might:
1101
1102 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1103
1104Here is a quick list of equivalencies, since there is some overlap:
1105
1106 # Same
1107 status => {'!=', 'completed', 'not like', 'pending%' }
1108 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1109
1110 # Same
1111 status => {'=', ['assigned', 'in-progress']}
1112 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1113 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1114
1115In addition to C<-and> and C<-or>, there is also a special C<-nest>
1116operator which adds an additional set of parens, to create a subquery.
1117For example, to get something like this:
1118
1119 $stmt = WHERE user = ? AND ( workhrs > ? OR geo = ? )
1120 @bind = ('nwiger', '20', 'ASIA');
1121
1122You would do:
1123
1124 my %where = (
1125 user => 'nwiger',
1126 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1127 );
1128
1129You can also use the hashref format to compare a list of fields using the
1130C<IN> comparison operator, by specifying the list as an arrayref:
1131
1132 my %where = (
1133 status => 'completed',
1134 reportid => { -in => [567, 2335, 2] }
1135 );
1136
1137Which would generate:
1138
1139 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1140 @bind = ('completed', '567', '2335', '2');
1141
1142You can use this same format to use other grouping functions, such
1143as C<BETWEEN>, C<SOME>, and so forth. For example:
1144
1145 my %where = (
1146 user => 'nwiger',
1147 completion_date => {
1148 -not_between => ['2002-10-01', '2003-02-06']
1149 }
1150 );
1151
1152Would give you:
1153
1154 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1155
1156So far, we've seen how multiple conditions are joined with a top-level
1157C<AND>. We can change this by putting the different conditions we want in
1158hashes and then putting those hashes in an array. For example:
1159
1160 my @where = (
1161 {
1162 user => 'nwiger',
1163 status => { -like => ['pending%', 'dispatched'] },
1164 },
1165 {
1166 user => 'robot',
1167 status => 'unassigned',
1168 }
1169 );
1170
1171This data structure would create the following:
1172
1173 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1174 OR ( user = ? AND status = ? ) )";
1175 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1176
1177This can be combined with the C<-nest> operator to properly group
1178SQL statements:
1179
1180 my @where = (
1181 -and => [
1182 user => 'nwiger',
1183 -nest => [
1184 -and => [workhrs => {'>', 20}, geo => 'ASIA' ],
1185 -and => [workhrs => {'<', 50}, geo => 'EURO' ]
1186 ],
1187 ],
1188 );
1189
1190That would yield:
1191
1192 WHERE ( user = ? AND
1193 ( ( workhrs > ? AND geo = ? )
1194 OR ( workhrs < ? AND geo = ? ) ) )
1195
1196Finally, sometimes only literal SQL will do. If you want to include
1197literal SQL verbatim, you can specify it as a scalar reference, namely:
1198
1199 my $inn = 'is Not Null';
1200 my %where = (
1201 priority => { '<', 2 },
1202 requestor => \$inn
1203 );
1204
1205This would create:
1206
1207 $stmt = "WHERE priority < ? AND requestor is Not Null";
1208 @bind = ('2');
1209
1210Note that in this example, you only get one bind parameter back, since
1211the verbatim SQL is passed as part of the statement.
1212
1213Of course, just to prove a point, the above can also be accomplished
1214with this:
1215
1216 my %where = (
1217 priority => { '<', 2 },
1218 requestor => { '!=', undef },
1219 );
1220
1221TMTOWTDI.
1222
1223These pages could go on for a while, since the nesting of the data
1224structures this module can handle are pretty much unlimited (the
1225module implements the C<WHERE> expansion as a recursive function
1226internally). Your best bet is to "play around" with the module a
1227little to see how the data structures behave, and choose the best
1228format for your data based on that.
1229
1230And of course, all the values above will probably be replaced with
1231variables gotten from forms or the command line. After all, if you
1232knew everything ahead of time, you wouldn't have to worry about
1233dynamically-generating SQL and could just hardwire it into your
1234script.
1235
1236=head1 PERFORMANCE
1237
1238Thanks to some benchmarking by Mark Stosberg, it turns out that
1239this module is many orders of magnitude faster than using C<DBIx::Abstract>.
1240I must admit this wasn't an intentional design issue, but it's a
1241byproduct of the fact that you get to control your C<DBI> handles
1242yourself.
1243
1244To maximize performance, use a code snippet like the following:
1245
1246 # prepare a statement handle using the first row
1247 # and then reuse it for the rest of the rows
1248 my($sth, $stmt);
1249 for my $href (@array_of_hashrefs) {
1250 $stmt ||= $sql->insert('table', $href);
1251 $sth ||= $dbh->prepare($stmt);
1252 $sth->execute($sql->values($href));
1253 }
1254
1255The reason this works is because the keys in your C<$href> are sorted
1256internally by B<SQL::Abstract>. Thus, as long as your data retains
1257the same structure, you only have to generate the SQL the first time
1258around. On subsequent queries, simply use the C<values> function provided
1259by this module to return your values in the correct order.
1260
1261=head1 FORMBUILDER
1262
1263If you use my C<CGI::FormBuilder> module at all, you'll hopefully
1264really like this part (I do, at least). Building up a complex query
1265can be as simple as the following:
1266
1267 #!/usr/bin/perl
1268
1269 use CGI::FormBuilder;
1270 use SQL::Abstract;
1271
1272 my $form = CGI::FormBuilder->new(...);
1273 my $sql = SQL::Abstract->new;
1274
1275 if ($form->submitted) {
1276 my $field = $form->field;
1277 my $id = delete $field->{id};
1278 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
1279 }
1280
1281Of course, you would still have to connect using C<DBI> to run the
1282query, but the point is that if you make your form look like your
1283table, the actual query script can be extremely simplistic.
1284
1285If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
1286a fast interface to returning and formatting data. I frequently
1287use these three modules together to write complex database query
1288apps in under 50 lines.
1289
1290=head1 NOTES
1291
1292There is not (yet) any explicit support for SQL compound logic
1293statements like "AND NOT". Instead, just do the de Morgan's
1294law transformations yourself. For example, this:
1295
1296 "lname LIKE '%son%' AND NOT ( age < 10 OR age > 20 )"
1297
1298Becomes:
1299
1300 "lname LIKE '%son%' AND ( age >= 10 AND age <= 20 )"
1301
1302With the corresponding C<%where> hash:
1303
1304 %where = (
1305 lname => {like => '%son%'},
1306 age => [-and => {'>=', 10}, {'<=', 20}],
1307 );
1308
1309Again, remember that the C<-and> goes I<inside> the arrayref.
1310
1311=head1 ACKNOWLEDGEMENTS
1312
1313There are a number of individuals that have really helped out with
1314this module. Unfortunately, most of them submitted bugs via CPAN
1315so I have no idea who they are! But the people I do know are:
1316
1317 Mark Stosberg (benchmarking)
1318 Chas Owens (initial "IN" operator support)
1319 Philip Collins (per-field SQL functions)
1320 Eric Kolve (hashref "AND" support)
1321 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
1322 Dan Kubb (support for "quote_char" and "name_sep")
abe72f94 1323 Matt Trout (DBIx::Class support)
32eab2da 1324
1325Thanks!
1326
1327=head1 BUGS
1328
1329If found, please DO NOT submit anything via C<rt.cpan.org> - that
1330just causes me a ton of work. Email me a patch (or script demonstrating
abe72f94 1331the problem) to the below address, and include the VERSION you're using.
32eab2da 1332
1333=head1 SEE ALSO
1334
1335L<DBIx::Abstract>, L<DBI|DBI>, L<CGI::FormBuilder>, L<HTML::QuickTable>
1336
32eab2da 1337=head1 AUTHOR
1338
6be9cea3 1339Copyright (c) 2001-2006 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
32eab2da 1340
abe72f94 1341For support, your best bet is to try the C<DBIx::Class> users mailing list.
1342While not an official support venue, C<DBIx::Class> makes heavy use of
1343C<SQL::Abstract>, and as such list members there are very familiar with
1344how to create queries.
1345
32eab2da 1346This module is free software; you may copy this under the terms of
1347the GNU General Public License, or the Artistic License, copies of
1348which should have accompanied your Perl kit.
1349
1350=cut
1351