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