1 package SQL::Abstract; # see doc at end of file
6 use Module::Runtime qw(use_module);
10 our $VERSION = '1.74';
11 # This would confuse some packagers
12 $VERSION = eval $VERSION if $VERSION =~ /_/; # numify for warning-free dev releases
15 my($func) = (caller(1))[3];
16 Carp::carp "[$func] Warning: ", @_;
20 my($func) = (caller(1))[3];
21 Carp::croak "[$func] Fatal: ", @_;
24 has converter => (is => 'lazy', clearer => 'clear_converter');
27 is => 'ro', coerce => sub { $_[0] eq 'lower' ? 'lower' : undef }
31 is => 'ro', coerce => sub { uc($_[0]) }, default => sub { 'OR' }
35 is => 'ro', default => sub { 'normal' }
38 has cmp => (is => 'ro', default => sub { '=' });
40 has sqltrue => (is => 'ro', default => sub { '1=1' });
41 has sqlfalse => (is => 'ro', default => sub { '0=1' });
43 has special_ops => (is => 'ro', default => sub { [] });
44 has unary_ops => (is => 'ro', default => sub { [] });
47 # need to guard against ()'s in column names too, but this will break tons of
48 # hacks... ideas anyone?
50 has injection_guard => (
61 has renderer => (is => 'lazy', clearer => 'clear_renderer');
64 is => 'rw', default => sub { '.' },
66 $_[0]->clear_renderer;
67 $_[0]->clear_converter;
74 $_[0]->clear_renderer;
75 $_[0]->clear_converter;
79 has collapse_aliases => (
85 is => 'rw', default => sub { 1 },
87 $_[0]->clear_renderer;
88 $_[0]->clear_converter;
92 has convert => (is => 'ro');
94 has array_datatypes => (is => 'ro');
96 has converter_class => (
97 is => 'rw', lazy => 1, builder => '_build_converter_class',
98 trigger => sub { shift->clear_converter },
101 sub _build_converter_class {
102 use_module('SQL::Abstract::Converter')
105 has renderer_class => (
106 is => 'rw', lazy => 1, clearer => 1, builder => 1,
107 trigger => sub { shift->clear_renderer },
110 after clear_renderer_class => sub { shift->clear_renderer };
112 sub _build_renderer_class {
114 my ($class, @roles) = (
115 $self->_build_base_renderer_class, $self->_build_renderer_roles
117 return $class unless @roles;
118 return use_module('Moo::Role')->create_class_with_roles($class, @roles);
121 sub _build_base_renderer_class {
122 use_module('Data::Query::Renderer::SQL::Naive')
125 sub _build_renderer_roles { () }
127 sub _converter_args {
129 Scalar::Util::weaken($self);
131 lower_case => $self->case,
132 default_logic => $self->logic,
133 bind_meta => not($self->bindtype eq 'normal'),
134 identifier_sep => $self->name_sep,
135 (map +($_ => $self->$_), qw(
136 cmp sqltrue sqlfalse injection_guard convert array_datatypes
140 my $sub = $_->{handler};
143 handler => sub { $self->$sub(@_) }
145 } @{$self->special_ops}
147 renderer_will_quote => (
148 defined($self->quote_char) and $self->always_quote
153 sub _build_converter {
155 $self->converter_class->new($self->_converter_args);
161 for ($self->quote_char) {
162 $chars = defined() ? (ref() ? $_ : [$_]) : ['',''];
165 quote_chars => $chars, always_quote => $self->always_quote,
166 identifier_sep => $self->name_sep,
167 collapse_aliases => $self->collapse_aliases,
168 ($self->case ? (lc_keywords => 1) : ()), # always 'lower' if it exists
172 sub _build_renderer {
174 $self->renderer_class->new($self->_renderer_args);
178 my ($self, $dq) = @_;
182 my ($sql, @bind) = @{$self->renderer->render($dq)};
184 ($self->{bindtype} eq 'normal'
185 ? ($sql, map $_->{value}, @bind)
186 : ($sql, map [ $_->{value_meta}, $_->{value} ], @bind)
192 my ($self, $type, @args) = @_;
193 $self->_render_dq($self->converter->${\"_${type}_to_dq"}(@args));
196 sub insert { shift->_render_sqla(insert => @_) }
198 sub update { shift->_render_sqla(update => @_) }
200 sub select { shift->_render_sqla(select => @_) }
202 sub delete { shift->_render_sqla(delete => @_) }
205 my ($self, $where, $order) = @_;
211 ($sql, @bind) = $self->_recurse_where($where) if defined($where);
212 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
216 $sql .= $self->_order_by($order);
219 return wantarray ? ($sql, @bind) : $sql;
222 sub _recurse_where { shift->_render_sqla(where => @_) }
225 my ($self, $arg) = @_;
226 if (my $dq = $self->converter->_order_by_to_dq($arg)) {
227 # SQLA generates ' ORDER BY foo'. The hilarity.
229 ? do { my @r = $self->_render_dq($dq); $r[0] = ' '.$r[0]; @r }
230 : ' '.$self->_render_dq($dq);
236 # highly optimized, as it's called way too often
238 # my ($self, $label) = @_;
240 return '' unless defined $_[1];
241 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
243 unless ($_[0]->{quote_char}) {
244 $_[0]->_assert_pass_injection_guard($_[1]);
248 my $qref = ref $_[0]->{quote_char};
251 ($l, $r) = ( $_[0]->{quote_char}, $_[0]->{quote_char} );
253 elsif ($qref eq 'ARRAY') {
254 ($l, $r) = @{$_[0]->{quote_char}};
257 puke "Unsupported quote_char format: $_[0]->{quote_char}";
260 # parts containing * are naturally unquoted
261 return join( $_[0]->{name_sep}||'', map
262 { $_ eq '*' ? $_ : $l . $_ . $r }
263 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
267 sub _assert_pass_injection_guard {
268 if ($_[1] =~ $_[0]->{injection_guard}) {
269 my $class = ref $_[0];
270 die "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the
272 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own
274 . "{injection_guard} attribute to ${class}->new()"
278 # Conversion, if applicable
280 #my ($self, $arg) = @_;
282 # LDNOTE : modified the previous implementation below because
283 # it was not consistent : the first "return" is always an array,
284 # the second "return" is context-dependent. Anyway, _convert
285 # seems always used with just a single argument, so make it a
287 # return @_ unless $self->{convert};
288 # my $conv = $self->_sqlcase($self->{convert});
289 # my @ret = map { $conv.'('.$_.')' } @_;
290 # return wantarray ? @ret : $ret[0];
291 if ($_[0]->{convert}) {
292 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
299 #my ($self, $col, @vals) = @_;
301 #LDNOTE : changed original implementation below because it did not make
302 # sense when bindtype eq 'columns' and @vals > 1.
303 # return $self->{bindtype} eq 'columns' ? [ $col, @vals ] : @vals;
305 # called often - tighten code
306 return $_[0]->{bindtype} eq 'columns'
307 ? map {[$_[1], $_]} @_[2 .. $#_]
312 # Dies if any element of @bind is not in [colname => value] format
313 # if bindtype is 'columns'.
314 sub _assert_bindval_matches_bindtype {
315 # my ($self, @bind) = @_;
317 if ($self->{bindtype} eq 'columns') {
319 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
320 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
326 # Fix SQL case, if so requested
328 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
329 # don't touch the argument ... crooked logic, but let's not change it!
330 return $_[0]->{case} ? $_[1] : uc($_[1]);
335 my $data = shift || return;
336 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
337 unless ref $data eq 'HASH';
340 foreach my $k ( sort keys %$data ) {
342 local our $Cur_Col_Meta = $k;
343 my ($sql, @bind) = $self->_render_sqla(
346 push @all_bind, @bind;
355 my(@sql, @sqlq, @sqlv);
359 if ($ref eq 'HASH') {
360 for my $k (sort keys %$_) {
363 my $label = $self->_quote($k);
365 # literal SQL with bind
366 my ($sql, @bind) = @$v;
367 $self->_assert_bindval_matches_bindtype(@bind);
368 push @sqlq, "$label = $sql";
370 } elsif ($r eq 'SCALAR') {
371 # literal SQL without bind
372 push @sqlq, "$label = $$v";
374 push @sqlq, "$label = ?";
375 push @sqlv, $self->_bindtype($k, $v);
378 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
379 } elsif ($ref eq 'ARRAY') {
380 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
383 if ($r eq 'ARRAY') { # literal SQL with bind
384 my ($sql, @bind) = @$v;
385 $self->_assert_bindval_matches_bindtype(@bind);
388 } elsif ($r eq 'SCALAR') { # literal SQL without bind
389 # embedded literal SQL
396 push @sql, '(' . join(', ', @sqlq) . ')';
397 } elsif ($ref eq 'SCALAR') {
401 # strings get case twiddled
402 push @sql, $self->_sqlcase($_);
406 my $sql = join ' ', @sql;
408 # this is pretty tricky
409 # if ask for an array, return ($stmt, @bind)
410 # otherwise, s/?/shift @sqlv/ to put it inline
412 return ($sql, @sqlv);
414 1 while $sql =~ s/\?/my $d = shift(@sqlv);
415 ref $d ? $d->[1] : $d/e;
427 SQL::Abstract - Generate SQL from Perl data structures
433 my $sql = SQL::Abstract->new;
435 my($stmt, @bind) = $sql->select($source, \@fields, \%where, \@order);
437 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
439 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
441 my($stmt, @bind) = $sql->delete($table, \%where);
443 # Then, use these in your DBI statements
444 my $sth = $dbh->prepare($stmt);
445 $sth->execute(@bind);
447 # Just generate the WHERE clause
448 my($stmt, @bind) = $sql->where(\%where, \@order);
450 # Return values in the same order, for hashed queries
451 # See PERFORMANCE section for more details
452 my @bind = $sql->values(\%fieldvals);
456 This module was inspired by the excellent L<DBIx::Abstract>.
457 However, in using that module I found that what I really wanted
458 to do was generate SQL, but still retain complete control over my
459 statement handles and use the DBI interface. So, I set out to
460 create an abstract SQL generation module.
462 While based on the concepts used by L<DBIx::Abstract>, there are
463 several important differences, especially when it comes to WHERE
464 clauses. I have modified the concepts used to make the SQL easier
465 to generate from Perl data structures and, IMO, more intuitive.
466 The underlying idea is for this module to do what you mean, based
467 on the data structures you provide it. The big advantage is that
468 you don't have to modify your code every time your data changes,
469 as this module figures it out.
471 To begin with, an SQL INSERT is as easy as just specifying a hash
472 of C<key=value> pairs:
475 name => 'Jimbo Bobson',
476 phone => '123-456-7890',
477 address => '42 Sister Lane',
479 state => 'Louisiana',
482 The SQL can then be generated with this:
484 my($stmt, @bind) = $sql->insert('people', \%data);
486 Which would give you something like this:
488 $stmt = "INSERT INTO people
489 (address, city, name, phone, state)
490 VALUES (?, ?, ?, ?, ?)";
491 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
492 '123-456-7890', 'Louisiana');
494 These are then used directly in your DBI code:
496 my $sth = $dbh->prepare($stmt);
497 $sth->execute(@bind);
499 =head2 Inserting and Updating Arrays
501 If your database has array types (like for example Postgres),
502 activate the special option C<< array_datatypes => 1 >>
503 when creating the C<SQL::Abstract> object.
504 Then you may use an arrayref to insert and update database array types:
506 my $sql = SQL::Abstract->new(array_datatypes => 1);
508 planets => [qw/Mercury Venus Earth Mars/]
511 my($stmt, @bind) = $sql->insert('solar_system', \%data);
515 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
517 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
520 =head2 Inserting and Updating SQL
522 In order to apply SQL functions to elements of your C<%data> you may
523 specify a reference to an arrayref for the given hash value. For example,
524 if you need to execute the Oracle C<to_date> function on a value, you can
525 say something like this:
529 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
532 The first value in the array is the actual SQL. Any other values are
533 optional and would be included in the bind values array. This gives
536 my($stmt, @bind) = $sql->insert('people', \%data);
538 $stmt = "INSERT INTO people (name, date_entered)
539 VALUES (?, to_date(?,'MM/DD/YYYY'))";
540 @bind = ('Bill', '03/02/2003');
542 An UPDATE is just as easy, all you change is the name of the function:
544 my($stmt, @bind) = $sql->update('people', \%data);
546 Notice that your C<%data> isn't touched; the module will generate
547 the appropriately quirky SQL for you automatically. Usually you'll
548 want to specify a WHERE clause for your UPDATE, though, which is
549 where handling C<%where> hashes comes in handy...
551 =head2 Complex where statements
553 This module can generate pretty complicated WHERE statements
554 easily. For example, simple C<key=value> pairs are taken to mean
555 equality, and if you want to see if a field is within a set
556 of values, you can use an arrayref. Let's say we wanted to
557 SELECT some data based on this criteria:
561 worker => ['nwiger', 'rcwe', 'sfz'],
562 status => { '!=', 'completed' }
565 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
567 The above would give you something like this:
569 $stmt = "SELECT * FROM tickets WHERE
570 ( requestor = ? ) AND ( status != ? )
571 AND ( worker = ? OR worker = ? OR worker = ? )";
572 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
574 Which you could then use in DBI code like so:
576 my $sth = $dbh->prepare($stmt);
577 $sth->execute(@bind);
583 The functions are simple. There's one for each major SQL operation,
584 and a constructor you use first. The arguments are specified in a
585 similar order to each function (table, then fields, then a where
586 clause) to try and simplify things.
591 =head2 new(option => 'value')
593 The C<new()> function takes a list of options and values, and returns
594 a new B<SQL::Abstract> object which can then be used to generate SQL
595 through the methods below. The options accepted are:
601 If set to 'lower', then SQL will be generated in all lowercase. By
602 default SQL is generated in "textbook" case meaning something like:
604 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
606 Any setting other than 'lower' is ignored.
610 This determines what the default comparison operator is. By default
611 it is C<=>, meaning that a hash like this:
613 %where = (name => 'nwiger', email => 'nate@wiger.org');
615 Will generate SQL like this:
617 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
619 However, you may want loose comparisons by default, so if you set
620 C<cmp> to C<like> you would get SQL such as:
622 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
624 You can also override the comparison on an individual basis - see
625 the huge section on L</"WHERE CLAUSES"> at the bottom.
627 =item sqltrue, sqlfalse
629 Expressions for inserting boolean values within SQL statements.
630 By default these are C<1=1> and C<1=0>. They are used
631 by the special operators C<-in> and C<-not_in> for generating
632 correct SQL even when the argument is an empty array (see below).
636 This determines the default logical operator for multiple WHERE
637 statements in arrays or hashes. If absent, the default logic is "or"
638 for arrays, and "and" for hashes. This means that a WHERE
642 event_date => {'>=', '2/13/99'},
643 event_date => {'<=', '4/24/03'},
646 will generate SQL like this:
648 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
650 This is probably not what you want given this query, though (look
651 at the dates). To change the "OR" to an "AND", simply specify:
653 my $sql = SQL::Abstract->new(logic => 'and');
655 Which will change the above C<WHERE> to:
657 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
659 The logic can also be changed locally by inserting
660 a modifier in front of an arrayref :
662 @where = (-and => [event_date => {'>=', '2/13/99'},
663 event_date => {'<=', '4/24/03'} ]);
665 See the L</"WHERE CLAUSES"> section for explanations.
669 This will automatically convert comparisons using the specified SQL
670 function for both column and value. This is mostly used with an argument
671 of C<upper> or C<lower>, so that the SQL will have the effect of
672 case-insensitive "searches". For example, this:
674 $sql = SQL::Abstract->new(convert => 'upper');
675 %where = (keywords => 'MaKe iT CAse inSeNSItive');
677 Will turn out the following SQL:
679 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
681 The conversion can be C<upper()>, C<lower()>, or any other SQL function
682 that can be applied symmetrically to fields (actually B<SQL::Abstract> does
683 not validate this option; it will just pass through what you specify verbatim).
687 This is a kludge because many databases suck. For example, you can't
688 just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
689 Instead, you have to use C<bind_param()>:
691 $sth->bind_param(1, 'reg data');
692 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
694 The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
695 which loses track of which field each slot refers to. Fear not.
697 If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
698 Currently, you can specify either C<normal> (default) or C<columns>. If you
699 specify C<columns>, you will get an array that looks like this:
701 my $sql = SQL::Abstract->new(bindtype => 'columns');
702 my($stmt, @bind) = $sql->insert(...);
705 [ 'column1', 'value1' ],
706 [ 'column2', 'value2' ],
707 [ 'column3', 'value3' ],
710 You can then iterate through this manually, using DBI's C<bind_param()>.
712 $sth->prepare($stmt);
715 my($col, $data) = @$_;
716 if ($col eq 'details' || $col eq 'comments') {
717 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
718 } elsif ($col eq 'image') {
719 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
721 $sth->bind_param($i, $data);
725 $sth->execute; # execute without @bind now
727 Now, why would you still use B<SQL::Abstract> if you have to do this crap?
728 Basically, the advantage is still that you don't have to care which fields
729 are or are not included. You could wrap that above C<for> loop in a simple
730 sub called C<bind_fields()> or something and reuse it repeatedly. You still
731 get a layer of abstraction over manual SQL specification.
733 Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
734 construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
735 will expect the bind values in this format.
739 This is the character that a table or column name will be quoted
740 with. By default this is an empty string, but you could set it to
741 the character C<`>, to generate SQL like this:
743 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
745 Alternatively, you can supply an array ref of two items, the first being the left
746 hand quote character, and the second the right hand quote character. For
747 example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
748 that generates SQL like this:
750 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
752 Quoting is useful if you have tables or columns names that are reserved
753 words in your database's SQL dialect.
757 This is the character that separates a table and column name. It is
758 necessary to specify this when the C<quote_char> option is selected,
759 so that tables and column names can be individually quoted like this:
761 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
763 =item injection_guard
765 A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
766 column name specified in a query structure. This is a safety mechanism to avoid
767 injection attacks when mishandling user input e.g.:
769 my %condition_as_column_value_pairs = get_values_from_user();
770 $sqla->select( ... , \%condition_as_column_value_pairs );
772 If the expression matches an exception is thrown. Note that literal SQL
773 supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
775 Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
777 =item array_datatypes
779 When this option is true, arrayrefs in INSERT or UPDATE are
780 interpreted as array datatypes and are passed directly
782 When this option is false, arrayrefs are interpreted
783 as literal SQL, just like refs to arrayrefs
784 (but this behavior is for backwards compatibility; when writing
785 new queries, use the "reference to arrayref" syntax
791 Takes a reference to a list of "special operators"
792 to extend the syntax understood by L<SQL::Abstract>.
793 See section L</"SPECIAL OPERATORS"> for details.
797 Takes a reference to a list of "unary operators"
798 to extend the syntax understood by L<SQL::Abstract>.
799 See section L</"UNARY OPERATORS"> for details.
805 =head2 insert($table, \@values || \%fieldvals, \%options)
807 This is the simplest function. You simply give it a table name
808 and either an arrayref of values or hashref of field/value pairs.
809 It returns an SQL INSERT statement and a list of bind values.
810 See the sections on L</"Inserting and Updating Arrays"> and
811 L</"Inserting and Updating SQL"> for information on how to insert
812 with those data types.
814 The optional C<\%options> hash reference may contain additional
815 options to generate the insert SQL. Currently supported options
822 Takes either a scalar of raw SQL fields, or an array reference of
823 field names, and adds on an SQL C<RETURNING> statement at the end.
824 This allows you to return data generated by the insert statement
825 (such as row IDs) without performing another C<SELECT> statement.
826 Note, however, this is not part of the SQL standard and may not
827 be supported by all database engines.
831 =head2 update($table, \%fieldvals, \%where)
833 This takes a table, hashref of field/value pairs, and an optional
834 hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
836 See the sections on L</"Inserting and Updating Arrays"> and
837 L</"Inserting and Updating SQL"> for information on how to insert
838 with those data types.
840 =head2 select($source, $fields, $where, $order)
842 This returns a SQL SELECT statement and associated list of bind values, as
843 specified by the arguments :
849 Specification of the 'FROM' part of the statement.
850 The argument can be either a plain scalar (interpreted as a table
851 name, will be quoted), or an arrayref (interpreted as a list
852 of table names, joined by commas, quoted), or a scalarref
853 (literal table name, not quoted), or a ref to an arrayref
854 (list of literal table names, joined by commas, not quoted).
858 Specification of the list of fields to retrieve from
860 The argument can be either an arrayref (interpreted as a list
861 of field names, will be joined by commas and quoted), or a
862 plain scalar (literal SQL, not quoted).
863 Please observe that this API is not as flexible as that of
864 the first argument C<$source>, for backwards compatibility reasons.
868 Optional argument to specify the WHERE part of the query.
869 The argument is most often a hashref, but can also be
870 an arrayref or plain scalar --
871 see section L<WHERE clause|/"WHERE CLAUSES"> for details.
875 Optional argument to specify the ORDER BY part of the query.
876 The argument can be a scalar, a hashref or an arrayref
877 -- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
883 =head2 delete($table, \%where)
885 This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
886 It returns an SQL DELETE statement and list of bind values.
888 =head2 where(\%where, \@order)
890 This is used to generate just the WHERE clause. For example,
891 if you have an arbitrary data structure and know what the
892 rest of your SQL is going to look like, but want an easy way
893 to produce a WHERE clause, use this. It returns an SQL WHERE
894 clause and list of bind values.
897 =head2 values(\%data)
899 This just returns the values from the hash C<%data>, in the same
900 order that would be returned from any of the other above queries.
901 Using this allows you to markedly speed up your queries if you
902 are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
904 =head2 generate($any, 'number', $of, \@data, $struct, \%types)
906 Warning: This is an experimental method and subject to change.
908 This returns arbitrarily generated SQL. It's a really basic shortcut.
909 It will return two different things, depending on return context:
911 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
912 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
914 These would return the following:
917 $stmt = "CREATE TABLE test (?, ?)";
918 @bind = (field1, field2);
920 # Second calling form
921 $stmt_and_val = "CREATE TABLE test (field1, field2)";
923 Depending on what you're trying to do, it's up to you to choose the correct
924 format. In this example, the second form is what you would want.
928 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
932 ALTER SESSION SET nls_date_format = 'MM/YY'
934 You get the idea. Strings get their case twiddled, but everything
935 else remains verbatim.
941 This module uses a variation on the idea from L<DBIx::Abstract>. It
942 is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
943 module is that things in arrays are OR'ed, and things in hashes
946 The easiest way to explain is to show lots of examples. After
947 each C<%where> hash shown, it is assumed you used:
949 my($stmt, @bind) = $sql->where(\%where);
951 However, note that the C<%where> hash can be used directly in any
952 of the other functions as well, as described above.
954 =head2 Key-value pairs
956 So, let's get started. To begin, a simple hash:
960 status => 'completed'
963 Is converted to SQL C<key = val> statements:
965 $stmt = "WHERE user = ? AND status = ?";
966 @bind = ('nwiger', 'completed');
968 One common thing I end up doing is having a list of values that
969 a field can be in. To do this, simply specify a list inside of
974 status => ['assigned', 'in-progress', 'pending'];
977 This simple code will create the following:
979 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
980 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
982 A field associated to an empty arrayref will be considered a
983 logical false and will generate 0=1.
985 =head2 Tests for NULL values
987 If the value part is C<undef> then this is converted to SQL <IS NULL>
996 $stmt = "WHERE user = ? AND status IS NULL";
999 To test if a column IS NOT NULL:
1003 status => { '!=', undef },
1006 =head2 Specific comparison operators
1008 If you want to specify a different type of operator for your comparison,
1009 you can use a hashref for a given column:
1013 status => { '!=', 'completed' }
1016 Which would generate:
1018 $stmt = "WHERE user = ? AND status != ?";
1019 @bind = ('nwiger', 'completed');
1021 To test against multiple values, just enclose the values in an arrayref:
1023 status => { '=', ['assigned', 'in-progress', 'pending'] };
1025 Which would give you:
1027 "WHERE status = ? OR status = ? OR status = ?"
1030 The hashref can also contain multiple pairs, in which case it is expanded
1031 into an C<AND> of its elements:
1035 status => { '!=', 'completed', -not_like => 'pending%' }
1038 # Or more dynamically, like from a form
1039 $where{user} = 'nwiger';
1040 $where{status}{'!='} = 'completed';
1041 $where{status}{'-not_like'} = 'pending%';
1043 # Both generate this
1044 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1045 @bind = ('nwiger', 'completed', 'pending%');
1048 To get an OR instead, you can combine it with the arrayref idea:
1052 priority => [ { '=', 2 }, { '>', 5 } ]
1055 Which would generate:
1057 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
1058 @bind = ('2', '5', 'nwiger');
1060 If you want to include literal SQL (with or without bind values), just use a
1061 scalar reference or array reference as the value:
1064 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1065 date_expires => { '<' => \"now()" }
1068 Which would generate:
1070 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1071 @bind = ('11/26/2008');
1074 =head2 Logic and nesting operators
1076 In the example above,
1077 there is a subtle trap if you want to say something like
1078 this (notice the C<AND>):
1080 WHERE priority != ? AND priority != ?
1082 Because, in Perl you I<can't> do this:
1084 priority => { '!=', 2, '!=', 1 }
1086 As the second C<!=> key will obliterate the first. The solution
1087 is to use the special C<-modifier> form inside an arrayref:
1089 priority => [ -and => {'!=', 2},
1093 Normally, these would be joined by C<OR>, but the modifier tells it
1094 to use C<AND> instead. (Hint: You can use this in conjunction with the
1095 C<logic> option to C<new()> in order to change the way your queries
1096 work by default.) B<Important:> Note that the C<-modifier> goes
1097 B<INSIDE> the arrayref, as an extra first element. This will
1098 B<NOT> do what you think it might:
1100 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1102 Here is a quick list of equivalencies, since there is some overlap:
1105 status => {'!=', 'completed', 'not like', 'pending%' }
1106 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1109 status => {'=', ['assigned', 'in-progress']}
1110 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1111 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1115 =head2 Special operators : IN, BETWEEN, etc.
1117 You can also use the hashref format to compare a list of fields using the
1118 C<IN> comparison operator, by specifying the list as an arrayref:
1121 status => 'completed',
1122 reportid => { -in => [567, 2335, 2] }
1125 Which would generate:
1127 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1128 @bind = ('completed', '567', '2335', '2');
1130 The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
1133 If the argument to C<-in> is an empty array, 'sqlfalse' is generated
1134 (by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
1135 'sqltrue' (by default : C<1=1>).
1137 In addition to the array you can supply a chunk of literal sql or
1138 literal sql with bind:
1141 customer => { -in => \[
1142 'SELECT cust_id FROM cust WHERE balance > ?',
1145 status => { -in => \'SELECT status_codes FROM states' },
1151 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
1152 AND status IN ( SELECT status_codes FROM states )
1156 Finally, if the argument to C<-in> is not a reference, it will be
1157 treated as a single-element array.
1159 Another pair of operators is C<-between> and C<-not_between>,
1160 used with an arrayref of two values:
1164 completion_date => {
1165 -not_between => ['2002-10-01', '2003-02-06']
1171 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1173 Just like with C<-in> all plausible combinations of literal SQL
1177 start0 => { -between => [ 1, 2 ] },
1178 start1 => { -between => \["? AND ?", 1, 2] },
1179 start2 => { -between => \"lower(x) AND upper(y)" },
1180 start3 => { -between => [
1182 \["upper(?)", 'stuff' ],
1189 ( start0 BETWEEN ? AND ? )
1190 AND ( start1 BETWEEN ? AND ? )
1191 AND ( start2 BETWEEN lower(x) AND upper(y) )
1192 AND ( start3 BETWEEN lower(x) AND upper(?) )
1194 @bind = (1, 2, 1, 2, 'stuff');
1197 These are the two builtin "special operators"; but the
1198 list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1200 =head2 Unary operators: bool
1202 If you wish to test against boolean columns or functions within your
1203 database you can use the C<-bool> and C<-not_bool> operators. For
1204 example to test the column C<is_user> being true and the column
1205 C<is_enabled> being false you would use:-
1209 -not_bool => 'is_enabled',
1214 WHERE is_user AND NOT is_enabled
1216 If a more complex combination is required, testing more conditions,
1217 then you should use the and/or operators:-
1224 -not_bool => 'four',
1230 WHERE one AND two AND three AND NOT four
1233 =head2 Nested conditions, -and/-or prefixes
1235 So far, we've seen how multiple conditions are joined with a top-level
1236 C<AND>. We can change this by putting the different conditions we want in
1237 hashes and then putting those hashes in an array. For example:
1242 status => { -like => ['pending%', 'dispatched'] },
1246 status => 'unassigned',
1250 This data structure would create the following:
1252 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1253 OR ( user = ? AND status = ? ) )";
1254 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1257 Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
1258 to change the logic inside :
1264 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1265 -or => { workhrs => {'<', 50}, geo => 'EURO' },
1272 WHERE ( user = ? AND (
1273 ( workhrs > ? AND geo = ? )
1274 OR ( workhrs < ? OR geo = ? )
1277 =head3 Algebraic inconsistency, for historical reasons
1279 C<Important note>: when connecting several conditions, the C<-and->|C<-or>
1280 operator goes C<outside> of the nested structure; whereas when connecting
1281 several constraints on one column, the C<-and> operator goes
1282 C<inside> the arrayref. Here is an example combining both features :
1285 -and => [a => 1, b => 2],
1286 -or => [c => 3, d => 4],
1287 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
1292 WHERE ( ( ( a = ? AND b = ? )
1293 OR ( c = ? OR d = ? )
1294 OR ( e LIKE ? AND e LIKE ? ) ) )
1296 This difference in syntax is unfortunate but must be preserved for
1297 historical reasons. So be careful : the two examples below would
1298 seem algebraically equivalent, but they are not
1300 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
1301 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
1303 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
1304 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
1307 =head2 Literal SQL and value type operators
1309 The basic premise of SQL::Abstract is that in WHERE specifications the "left
1310 side" is a column name and the "right side" is a value (normally rendered as
1311 a placeholder). This holds true for both hashrefs and arrayref pairs as you
1312 see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
1313 alter this behavior. There are several ways of doing so.
1317 This is a virtual operator that signals the string to its right side is an
1318 identifier (a column name) and not a value. For example to compare two
1319 columns you would write:
1322 priority => { '<', 2 },
1323 requestor => { -ident => 'submitter' },
1328 $stmt = "WHERE priority < ? AND requestor = submitter";
1331 If you are maintaining legacy code you may see a different construct as
1332 described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
1337 This is a virtual operator that signals that the construct to its right side
1338 is a value to be passed to DBI. This is for example necessary when you want
1339 to write a where clause against an array (for RDBMS that support such
1340 datatypes). For example:
1343 array => { -value => [1, 2, 3] }
1348 $stmt = 'WHERE array = ?';
1349 @bind = ([1, 2, 3]);
1351 Note that if you were to simply say:
1357 the result would probably not be what you wanted:
1359 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
1364 Finally, sometimes only literal SQL will do. To include a random snippet
1365 of SQL verbatim, you specify it as a scalar reference. Consider this only
1366 as a last resort. Usually there is a better way. For example:
1369 priority => { '<', 2 },
1370 requestor => { -in => \'(SELECT name FROM hitmen)' },
1375 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
1378 Note that in this example, you only get one bind parameter back, since
1379 the verbatim SQL is passed as part of the statement.
1383 Never use untrusted input as a literal SQL argument - this is a massive
1384 security risk (there is no way to check literal snippets for SQL
1385 injections and other nastyness). If you need to deal with untrusted input
1386 use literal SQL with placeholders as described next.
1388 =head3 Literal SQL with placeholders and bind values (subqueries)
1390 If the literal SQL to be inserted has placeholders and bind values,
1391 use a reference to an arrayref (yes this is a double reference --
1392 not so common, but perfectly legal Perl). For example, to find a date
1393 in Postgres you can use something like this:
1396 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1401 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
1404 Note that you must pass the bind values in the same format as they are returned
1405 by L</where>. That means that if you set L</bindtype> to C<columns>, you must
1406 provide the bind values in the C<< [ column_meta => value ] >> format, where
1407 C<column_meta> is an opaque scalar value; most commonly the column name, but
1408 you can use any scalar value (including references and blessed references),
1409 L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
1410 to C<columns> the above example will look like:
1413 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
1416 Literal SQL is especially useful for nesting parenthesized clauses in the
1417 main SQL query. Here is a first example :
1419 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1423 bar => \["IN ($sub_stmt)" => @sub_bind],
1428 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
1429 WHERE c2 < ? AND c3 LIKE ?))";
1430 @bind = (1234, 100, "foo%");
1432 Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
1433 are expressed in the same way. Of course the C<$sub_stmt> and
1434 its associated bind values can be generated through a former call
1437 my ($sub_stmt, @sub_bind)
1438 = $sql->select("t1", "c1", {c2 => {"<" => 100},
1439 c3 => {-like => "foo%"}});
1442 bar => \["> ALL ($sub_stmt)" => @sub_bind],
1445 In the examples above, the subquery was used as an operator on a column;
1446 but the same principle also applies for a clause within the main C<%where>
1447 hash, like an EXISTS subquery :
1449 my ($sub_stmt, @sub_bind)
1450 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
1451 my %where = ( -and => [
1453 \["EXISTS ($sub_stmt)" => @sub_bind],
1458 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
1459 WHERE c1 = ? AND c2 > t0.c0))";
1463 Observe that the condition on C<c2> in the subquery refers to
1464 column C<t0.c0> of the main query : this is I<not> a bind
1465 value, so we have to express it through a scalar ref.
1466 Writing C<< c2 => {">" => "t0.c0"} >> would have generated
1467 C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
1468 what we wanted here.
1470 Finally, here is an example where a subquery is used
1471 for expressing unary negation:
1473 my ($sub_stmt, @sub_bind)
1474 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
1475 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
1477 lname => {like => '%son%'},
1478 \["NOT ($sub_stmt)" => @sub_bind],
1483 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
1484 @bind = ('%son%', 10, 20)
1486 =head3 Deprecated usage of Literal SQL
1488 Below are some examples of archaic use of literal SQL. It is shown only as
1489 reference for those who deal with legacy code. Each example has a much
1490 better, cleaner and safer alternative that users should opt for in new code.
1496 my %where = ( requestor => \'IS NOT NULL' )
1498 $stmt = "WHERE requestor IS NOT NULL"
1500 This used to be the way of generating NULL comparisons, before the handling
1501 of C<undef> got formalized. For new code please use the superior syntax as
1502 described in L</Tests for NULL values>.
1506 my %where = ( requestor => \'= submitter' )
1508 $stmt = "WHERE requestor = submitter"
1510 This used to be the only way to compare columns. Use the superior L</-ident>
1511 method for all new code. For example an identifier declared in such a way
1512 will be properly quoted if L</quote_char> is properly set, while the legacy
1513 form will remain as supplied.
1517 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
1519 $stmt = "WHERE completed > ? AND is_ready"
1520 @bind = ('2012-12-21')
1522 Using an empty string literal used to be the only way to express a boolean.
1523 For all new code please use the much more readable
1524 L<-bool|/Unary operators: bool> operator.
1530 These pages could go on for a while, since the nesting of the data
1531 structures this module can handle are pretty much unlimited (the
1532 module implements the C<WHERE> expansion as a recursive function
1533 internally). Your best bet is to "play around" with the module a
1534 little to see how the data structures behave, and choose the best
1535 format for your data based on that.
1537 And of course, all the values above will probably be replaced with
1538 variables gotten from forms or the command line. After all, if you
1539 knew everything ahead of time, you wouldn't have to worry about
1540 dynamically-generating SQL and could just hardwire it into your
1543 =head1 ORDER BY CLAUSES
1545 Some functions take an order by clause. This can either be a scalar (just a
1546 column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1547 or an array of either of the two previous forms. Examples:
1549 Given | Will Generate
1550 ----------------------------------------------------------
1552 \'colA DESC' | ORDER BY colA DESC
1554 'colA' | ORDER BY colA
1556 [qw/colA colB/] | ORDER BY colA, colB
1558 {-asc => 'colA'} | ORDER BY colA ASC
1560 {-desc => 'colB'} | ORDER BY colB DESC
1562 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
1564 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
1567 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
1568 { -desc => [qw/colB/], | colC ASC, colD ASC
1569 { -asc => [qw/colC colD/],|
1571 ===========================================================
1575 =head1 SPECIAL OPERATORS
1577 my $sqlmaker = SQL::Abstract->new(special_ops => [
1581 my ($self, $field, $op, $arg) = @_;
1587 handler => 'method_name',
1591 A "special operator" is a SQL syntactic clause that can be
1592 applied to a field, instead of a usual binary operator.
1595 WHERE field IN (?, ?, ?)
1596 WHERE field BETWEEN ? AND ?
1597 WHERE MATCH(field) AGAINST (?, ?)
1599 Special operators IN and BETWEEN are fairly standard and therefore
1600 are builtin within C<SQL::Abstract> (as the overridable methods
1601 C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
1602 like the MATCH .. AGAINST example above which is specific to MySQL,
1603 you can write your own operator handlers - supply a C<special_ops>
1604 argument to the C<new> method. That argument takes an arrayref of
1605 operator definitions; each operator definition is a hashref with two
1612 the regular expression to match the operator
1616 Either a coderef or a plain scalar method name. In both cases
1617 the expected return is C<< ($sql, @bind) >>.
1619 When supplied with a method name, it is simply called on the
1620 L<SQL::Abstract/> object as:
1622 $self->$method_name ($field, $op, $arg)
1626 $op is the part that matched the handler regex
1627 $field is the LHS of the operator
1630 When supplied with a coderef, it is called as:
1632 $coderef->($self, $field, $op, $arg)
1637 For example, here is an implementation
1638 of the MATCH .. AGAINST syntax for MySQL
1640 my $sqlmaker = SQL::Abstract->new(special_ops => [
1642 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
1643 {regex => qr/^match$/i,
1645 my ($self, $field, $op, $arg) = @_;
1646 $arg = [$arg] if not ref $arg;
1647 my $label = $self->_quote($field);
1648 my ($placeholder) = $self->_convert('?');
1649 my $placeholders = join ", ", (($placeholder) x @$arg);
1650 my $sql = $self->_sqlcase('match') . " ($label) "
1651 . $self->_sqlcase('against') . " ($placeholders) ";
1652 my @bind = $self->_bindtype($field, @$arg);
1653 return ($sql, @bind);
1660 =head1 UNARY OPERATORS
1662 my $sqlmaker = SQL::Abstract->new(unary_ops => [
1666 my ($self, $op, $arg) = @_;
1672 handler => 'method_name',
1676 A "unary operator" is a SQL syntactic clause that can be
1677 applied to a field - the operator goes before the field
1679 You can write your own operator handlers - supply a C<unary_ops>
1680 argument to the C<new> method. That argument takes an arrayref of
1681 operator definitions; each operator definition is a hashref with two
1688 the regular expression to match the operator
1692 Either a coderef or a plain scalar method name. In both cases
1693 the expected return is C<< $sql >>.
1695 When supplied with a method name, it is simply called on the
1696 L<SQL::Abstract/> object as:
1698 $self->$method_name ($op, $arg)
1702 $op is the part that matched the handler regex
1703 $arg is the RHS or argument of the operator
1705 When supplied with a coderef, it is called as:
1707 $coderef->($self, $op, $arg)
1715 Thanks to some benchmarking by Mark Stosberg, it turns out that
1716 this module is many orders of magnitude faster than using C<DBIx::Abstract>.
1717 I must admit this wasn't an intentional design issue, but it's a
1718 byproduct of the fact that you get to control your C<DBI> handles
1721 To maximize performance, use a code snippet like the following:
1723 # prepare a statement handle using the first row
1724 # and then reuse it for the rest of the rows
1726 for my $href (@array_of_hashrefs) {
1727 $stmt ||= $sql->insert('table', $href);
1728 $sth ||= $dbh->prepare($stmt);
1729 $sth->execute($sql->values($href));
1732 The reason this works is because the keys in your C<$href> are sorted
1733 internally by B<SQL::Abstract>. Thus, as long as your data retains
1734 the same structure, you only have to generate the SQL the first time
1735 around. On subsequent queries, simply use the C<values> function provided
1736 by this module to return your values in the correct order.
1738 However this depends on the values having the same type - if, for
1739 example, the values of a where clause may either have values
1740 (resulting in sql of the form C<column = ?> with a single bind
1741 value), or alternatively the values might be C<undef> (resulting in
1742 sql of the form C<column IS NULL> with no bind value) then the
1743 caching technique suggested will not work.
1747 If you use my C<CGI::FormBuilder> module at all, you'll hopefully
1748 really like this part (I do, at least). Building up a complex query
1749 can be as simple as the following:
1753 use CGI::FormBuilder;
1756 my $form = CGI::FormBuilder->new(...);
1757 my $sql = SQL::Abstract->new;
1759 if ($form->submitted) {
1760 my $field = $form->field;
1761 my $id = delete $field->{id};
1762 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
1765 Of course, you would still have to connect using C<DBI> to run the
1766 query, but the point is that if you make your form look like your
1767 table, the actual query script can be extremely simplistic.
1769 If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
1770 a fast interface to returning and formatting data. I frequently
1771 use these three modules together to write complex database query
1772 apps in under 50 lines.
1778 =item * gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
1780 =item * git: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
1786 Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
1787 Great care has been taken to preserve the I<published> behavior
1788 documented in previous versions in the 1.* family; however,
1789 some features that were previously undocumented, or behaved
1790 differently from the documentation, had to be changed in order
1791 to clarify the semantics. Hence, client code that was relying
1792 on some dark areas of C<SQL::Abstract> v1.*
1793 B<might behave differently> in v1.50.
1795 The main changes are :
1801 support for literal SQL through the C<< \ [$sql, bind] >> syntax.
1805 support for the { operator => \"..." } construct (to embed literal SQL)
1809 support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
1813 optional support for L<array datatypes|/"Inserting and Updating Arrays">
1817 defensive programming : check arguments
1821 fixed bug with global logic, which was previously implemented
1822 through global variables yielding side-effects. Prior versions would
1823 interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
1824 as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
1825 Now this is interpreted
1826 as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
1831 fixed semantics of _bindtype on array args
1835 dropped the C<_anoncopy> of the %where tree. No longer necessary,
1836 we just avoid shifting arrays within that tree.
1840 dropped the C<_modlogic> function
1844 =head1 ACKNOWLEDGEMENTS
1846 There are a number of individuals that have really helped out with
1847 this module. Unfortunately, most of them submitted bugs via CPAN
1848 so I have no idea who they are! But the people I do know are:
1850 Ash Berlin (order_by hash term support)
1851 Matt Trout (DBIx::Class support)
1852 Mark Stosberg (benchmarking)
1853 Chas Owens (initial "IN" operator support)
1854 Philip Collins (per-field SQL functions)
1855 Eric Kolve (hashref "AND" support)
1856 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
1857 Dan Kubb (support for "quote_char" and "name_sep")
1858 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
1859 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
1860 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
1861 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
1862 Oliver Charles (support for "RETURNING" after "INSERT")
1868 L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
1872 Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
1874 This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
1876 For support, your best bet is to try the C<DBIx::Class> users mailing list.
1877 While not an official support venue, C<DBIx::Class> makes heavy use of
1878 C<SQL::Abstract>, and as such list members there are very familiar with
1879 how to create queries.
1883 This module is free software; you may copy this under the same
1884 terms as perl itself (either the GNU General Public License or
1885 the Artistic License)