Fix pesky taint xt test fail
[dbsrgits/SQL-Abstract.git] / lib / SQL / Abstract.pm
CommitLineData
96449e8e 1package SQL::Abstract; # see doc at end of file
2
39999edd 3use SQL::Abstract::_TempExtlib;
4
9d9d5bd6 5use Carp ();
312d830b 6use List::Util ();
7use Scalar::Util ();
a82e41dc 8use Module::Runtime qw(use_module);
3a9aca02 9use Moo;
8b9b83ae 10use namespace::clean;
96449e8e 11
4c120a34 12our $VERSION = '1.77';
7479e27e 13
22f1a437 14# This would confuse some packagers
c520207b 15$VERSION = eval $VERSION if $VERSION =~ /_/; # numify for warning-free dev releases
96449e8e 16
17sub belch (@) {
18 my($func) = (caller(1))[3];
9d9d5bd6 19 Carp::carp "[$func] Warning: ", @_;
96449e8e 20}
21
22sub puke (@) {
23 my($func) = (caller(1))[3];
9d9d5bd6 24 Carp::croak "[$func] Fatal: ", @_;
96449e8e 25}
26
a82e41dc 27has converter => (is => 'lazy', clearer => 'clear_converter');
96449e8e 28
3a9aca02 29has case => (
30 is => 'ro', coerce => sub { $_[0] eq 'lower' ? 'lower' : undef }
31);
96449e8e 32
3a9aca02 33has logic => (
34 is => 'ro', coerce => sub { uc($_[0]) }, default => sub { 'OR' }
35);
96449e8e 36
3a9aca02 37has bindtype => (
38 is => 'ro', default => sub { 'normal' }
39);
96449e8e 40
3a9aca02 41has cmp => (is => 'ro', default => sub { '=' });
96449e8e 42
3a9aca02 43has sqltrue => (is => 'ro', default => sub { '1=1' });
44has sqlfalse => (is => 'ro', default => sub { '0=1' });
45
46has special_ops => (is => 'ro', default => sub { [] });
47has unary_ops => (is => 'ro', default => sub { [] });
59f23b3d 48
a82e41dc 49# FIXME
50# need to guard against ()'s in column names too, but this will break tons of
51# hacks... ideas anyone?
8f57728a 52
3a9aca02 53has injection_guard => (
54 is => 'ro',
55 default => sub {
56 qr/
57 \;
58 |
59 ^ \s* go \s
60 /xmi;
61 }
62);
63
29a3e5dc 64has renderer => (is => 'lazy', clearer => 'clear_renderer');
3a9aca02 65
29a3e5dc 66has name_sep => (
67 is => 'rw', default => sub { '.' },
a82e41dc 68 trigger => sub {
69 $_[0]->clear_renderer;
70 $_[0]->clear_converter;
71 },
29a3e5dc 72);
3a9aca02 73
29a3e5dc 74has quote_char => (
75 is => 'rw',
a82e41dc 76 trigger => sub {
77 $_[0]->clear_renderer;
78 $_[0]->clear_converter;
79 },
29a3e5dc 80);
a9bb5c4c 81
62d17764 82has collapse_aliases => (
83 is => 'ro',
84 default => sub { 0 }
85);
86
a82e41dc 87has always_quote => (
88 is => 'rw', default => sub { 1 },
89 trigger => sub {
90 $_[0]->clear_renderer;
91 $_[0]->clear_converter;
92 },
93);
3a9aca02 94
95has convert => (is => 'ro');
96
97has array_datatypes => (is => 'ro');
98
a82e41dc 99has converter_class => (
dfaa9684 100 is => 'rw', lazy => 1, builder => '_build_converter_class',
101 trigger => sub { shift->clear_converter },
a82e41dc 102);
103
dfaa9684 104sub _build_converter_class {
105 use_module('SQL::Abstract::Converter')
106}
107
a82e41dc 108has renderer_class => (
1fa55ded 109 is => 'rw', lazy => 1, clearer => 1, builder => 1,
dfaa9684 110 trigger => sub { shift->clear_renderer },
a82e41dc 111);
112
1fa55ded 113after clear_renderer_class => sub { shift->clear_renderer };
114
dfaa9684 115sub _build_renderer_class {
a60d973a 116 my ($self) = @_;
117 my ($class, @roles) = (
118 $self->_build_base_renderer_class, $self->_build_renderer_roles
119 );
120 return $class unless @roles;
121 return use_module('Moo::Role')->create_class_with_roles($class, @roles);
122}
123
124sub _build_base_renderer_class {
dfaa9684 125 use_module('Data::Query::Renderer::SQL::Naive')
126}
127
a60d973a 128sub _build_renderer_roles { () }
129
a82e41dc 130sub _converter_args {
131 my ($self) = @_;
132 Scalar::Util::weaken($self);
133 +{
134 lower_case => $self->case,
135 default_logic => $self->logic,
136 bind_meta => not($self->bindtype eq 'normal'),
137 identifier_sep => $self->name_sep,
138 (map +($_ => $self->$_), qw(
139 cmp sqltrue sqlfalse injection_guard convert array_datatypes
140 )),
141 special_ops => [
142 map {
143 my $sub = $_->{handler};
144 +{
145 %$_,
146 handler => sub { $self->$sub(@_) }
147 }
148 } @{$self->special_ops}
149 ],
150 renderer_will_quote => (
151 defined($self->quote_char) and $self->always_quote
152 ),
153 }
154}
155
156sub _build_converter {
157 my ($self) = @_;
dfaa9684 158 $self->converter_class->new($self->_converter_args);
a82e41dc 159}
160
161sub _renderer_args {
3a9aca02 162 my ($self) = @_;
3a9aca02 163 my ($chars);
164 for ($self->quote_char) {
165 $chars = defined() ? (ref() ? $_ : [$_]) : ['',''];
166 }
a82e41dc 167 +{
3a9aca02 168 quote_chars => $chars, always_quote => $self->always_quote,
169 identifier_sep => $self->name_sep,
62d17764 170 collapse_aliases => $self->collapse_aliases,
3a9aca02 171 ($self->case ? (lc_keywords => 1) : ()), # always 'lower' if it exists
a82e41dc 172 };
173}
174
175sub _build_renderer {
176 my ($self) = @_;
dfaa9684 177 $self->renderer_class->new($self->_renderer_args);
b6251592 178}
96449e8e 179
8f57728a 180sub _render_dq {
181 my ($self, $dq) = @_;
9057306b 182 if (!$dq) {
183 return '';
184 }
3a9aca02 185 my ($sql, @bind) = @{$self->renderer->render($dq)};
b4951847 186 wantarray ?
187 ($self->{bindtype} eq 'normal'
188 ? ($sql, map $_->{value}, @bind)
a420b11f 189 : ($sql, map [ $_->{value_meta}, $_->{value} ], @bind)
b4951847 190 )
191 : $sql;
192}
193
a9bb5c4c 194sub _render_sqla {
195 my ($self, $type, @args) = @_;
a82e41dc 196 $self->_render_dq($self->converter->${\"_${type}_to_dq"}(@args));
170e6c33 197}
198
a9bb5c4c 199sub insert { shift->_render_sqla(insert => @_) }
fe3ae272 200
a9bb5c4c 201sub update { shift->_render_sqla(update => @_) }
9057306b 202
a9bb5c4c 203sub select { shift->_render_sqla(select => @_) }
9057306b 204
a9bb5c4c 205sub delete { shift->_render_sqla(delete => @_) }
96449e8e 206
96449e8e 207sub where {
208 my ($self, $where, $order) = @_;
209
1d6b8d4d 210 my $sql = '';
211 my @bind;
212
96449e8e 213 # where ?
1d6b8d4d 214 ($sql, @bind) = $self->_recurse_where($where) if defined($where);
96449e8e 215 $sql = $sql ? $self->_sqlcase(' where ') . "( $sql )" : '';
216
217 # order by?
218 if ($order) {
219 $sql .= $self->_order_by($order);
220 }
221
9d48860e 222 return wantarray ? ($sql, @bind) : $sql;
96449e8e 223}
224
a9bb5c4c 225sub _recurse_where { shift->_render_sqla(where => @_) }
d4e889af 226
96449e8e 227sub _order_by {
228 my ($self, $arg) = @_;
a82e41dc 229 if (my $dq = $self->converter->_order_by_to_dq($arg)) {
b4951847 230 # SQLA generates ' ORDER BY foo'. The hilarity.
231 wantarray
232 ? do { my @r = $self->_render_dq($dq); $r[0] = ' '.$r[0]; @r }
233 : ' '.$self->_render_dq($dq);
234 } else {
235 '';
f267b646 236 }
f267b646 237}
238
955e77ca 239# highly optimized, as it's called way too often
96449e8e 240sub _quote {
955e77ca 241 # my ($self, $label) = @_;
96449e8e 242
955e77ca 243 return '' unless defined $_[1];
955e77ca 244 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
96449e8e 245
b6251592 246 unless ($_[0]->{quote_char}) {
170e6c33 247 $_[0]->_assert_pass_injection_guard($_[1]);
b6251592 248 return $_[1];
249 }
96449e8e 250
07d7c35c 251 my $qref = ref $_[0]->{quote_char};
955e77ca 252 my ($l, $r);
07d7c35c 253 if (!$qref) {
254 ($l, $r) = ( $_[0]->{quote_char}, $_[0]->{quote_char} );
955e77ca 255 }
07d7c35c 256 elsif ($qref eq 'ARRAY') {
257 ($l, $r) = @{$_[0]->{quote_char}};
955e77ca 258 }
259 else {
260 puke "Unsupported quote_char format: $_[0]->{quote_char}";
261 }
96449e8e 262
07d7c35c 263 # parts containing * are naturally unquoted
264 return join( $_[0]->{name_sep}||'', map
955e77ca 265 { $_ eq '*' ? $_ : $l . $_ . $r }
266 ( $_[0]->{name_sep} ? split (/\Q$_[0]->{name_sep}\E/, $_[1] ) : $_[1] )
267 );
96449e8e 268}
269
a82e41dc 270sub _assert_pass_injection_guard {
271 if ($_[1] =~ $_[0]->{injection_guard}) {
272 my $class = ref $_[0];
f2a0d52b 273 die "Possible SQL injection attempt '$_[1]'. If this is indeed a part of "
274 . "the desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply "
275 . "your own {injection_guard} attribute to ${class}->new()"
a82e41dc 276 }
277}
96449e8e 278
279# Conversion, if applicable
280sub _convert ($) {
07d7c35c 281 #my ($self, $arg) = @_;
07d7c35c 282 if ($_[0]->{convert}) {
283 return $_[0]->_sqlcase($_[0]->{convert}) .'(' . $_[1] . ')';
96449e8e 284 }
07d7c35c 285 return $_[1];
96449e8e 286}
287
288# And bindtype
289sub _bindtype (@) {
07d7c35c 290 #my ($self, $col, @vals) = @_;
07d7c35c 291 # called often - tighten code
292 return $_[0]->{bindtype} eq 'columns'
293 ? map {[$_[1], $_]} @_[2 .. $#_]
294 : @_[2 .. $#_]
295 ;
96449e8e 296}
297
fe3ae272 298# Dies if any element of @bind is not in [colname => value] format
299# if bindtype is 'columns'.
300sub _assert_bindval_matches_bindtype {
c94a6c93 301# my ($self, @bind) = @_;
302 my $self = shift;
fe3ae272 303 if ($self->{bindtype} eq 'columns') {
c94a6c93 304 for (@_) {
305 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
3a06278c 306 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
fe3ae272 307 }
308 }
309 }
310}
311
96449e8e 312# Fix SQL case, if so requested
313sub _sqlcase {
96449e8e 314 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
315 # don't touch the argument ... crooked logic, but let's not change it!
07d7c35c 316 return $_[0]->{case} ? $_[1] : uc($_[1]);
96449e8e 317}
318
96449e8e 319sub values {
320 my $self = shift;
321 my $data = shift || return;
322 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
323 unless ref $data eq 'HASH';
bab725ce 324
325 my @all_bind;
326 foreach my $k ( sort keys %$data ) {
327 my $v = $data->{$k};
5cf3969e 328 local our $Cur_Col_Meta = $k;
a9bb5c4c 329 my ($sql, @bind) = $self->_render_sqla(
330 mutation_rhs => $v
5cf3969e 331 );
332 push @all_bind, @bind;
bab725ce 333 }
334
335 return @all_bind;
96449e8e 336}
337
338sub generate {
339 my $self = shift;
340
341 my(@sql, @sqlq, @sqlv);
342
343 for (@_) {
344 my $ref = ref $_;
345 if ($ref eq 'HASH') {
346 for my $k (sort keys %$_) {
347 my $v = $_->{$k};
348 my $r = ref $v;
349 my $label = $self->_quote($k);
350 if ($r eq 'ARRAY') {
fe3ae272 351 # literal SQL with bind
352 my ($sql, @bind) = @$v;
353 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 354 push @sqlq, "$label = $sql";
fe3ae272 355 push @sqlv, @bind;
96449e8e 356 } elsif ($r eq 'SCALAR') {
fe3ae272 357 # literal SQL without bind
96449e8e 358 push @sqlq, "$label = $$v";
9d48860e 359 } else {
96449e8e 360 push @sqlq, "$label = ?";
361 push @sqlv, $self->_bindtype($k, $v);
362 }
363 }
364 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
365 } elsif ($ref eq 'ARRAY') {
366 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
367 for my $v (@$_) {
368 my $r = ref $v;
fe3ae272 369 if ($r eq 'ARRAY') { # literal SQL with bind
370 my ($sql, @bind) = @$v;
371 $self->_assert_bindval_matches_bindtype(@bind);
372 push @sqlq, $sql;
373 push @sqlv, @bind;
374 } elsif ($r eq 'SCALAR') { # literal SQL without bind
96449e8e 375 # embedded literal SQL
376 push @sqlq, $$v;
9d48860e 377 } else {
96449e8e 378 push @sqlq, '?';
379 push @sqlv, $v;
380 }
381 }
382 push @sql, '(' . join(', ', @sqlq) . ')';
383 } elsif ($ref eq 'SCALAR') {
384 # literal SQL
385 push @sql, $$_;
386 } else {
387 # strings get case twiddled
388 push @sql, $self->_sqlcase($_);
389 }
390 }
391
392 my $sql = join ' ', @sql;
393
394 # this is pretty tricky
395 # if ask for an array, return ($stmt, @bind)
396 # otherwise, s/?/shift @sqlv/ to put it inline
397 if (wantarray) {
398 return ($sql, @sqlv);
399 } else {
400 1 while $sql =~ s/\?/my $d = shift(@sqlv);
401 ref $d ? $d->[1] : $d/e;
402 return $sql;
403 }
404}
405
96449e8e 4061;
407
408
96449e8e 409__END__
32eab2da 410
411=head1 NAME
412
413SQL::Abstract - Generate SQL from Perl data structures
414
415=head1 SYNOPSIS
416
417 use SQL::Abstract;
418
419 my $sql = SQL::Abstract->new;
420
521647e7 421 my($stmt, @bind) = $sql->select($source, \@fields, \%where, \@order);
32eab2da 422
423 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
424
425 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
426
427 my($stmt, @bind) = $sql->delete($table, \%where);
428
429 # Then, use these in your DBI statements
430 my $sth = $dbh->prepare($stmt);
431 $sth->execute(@bind);
432
433 # Just generate the WHERE clause
abe72f94 434 my($stmt, @bind) = $sql->where(\%where, \@order);
32eab2da 435
436 # Return values in the same order, for hashed queries
437 # See PERFORMANCE section for more details
438 my @bind = $sql->values(\%fieldvals);
439
440=head1 DESCRIPTION
441
442This module was inspired by the excellent L<DBIx::Abstract>.
443However, in using that module I found that what I really wanted
444to do was generate SQL, but still retain complete control over my
445statement handles and use the DBI interface. So, I set out to
446create an abstract SQL generation module.
447
448While based on the concepts used by L<DBIx::Abstract>, there are
449several important differences, especially when it comes to WHERE
450clauses. I have modified the concepts used to make the SQL easier
451to generate from Perl data structures and, IMO, more intuitive.
452The underlying idea is for this module to do what you mean, based
453on the data structures you provide it. The big advantage is that
454you don't have to modify your code every time your data changes,
455as this module figures it out.
456
457To begin with, an SQL INSERT is as easy as just specifying a hash
458of C<key=value> pairs:
459
460 my %data = (
461 name => 'Jimbo Bobson',
462 phone => '123-456-7890',
463 address => '42 Sister Lane',
464 city => 'St. Louis',
465 state => 'Louisiana',
466 );
467
468The SQL can then be generated with this:
469
470 my($stmt, @bind) = $sql->insert('people', \%data);
471
472Which would give you something like this:
473
474 $stmt = "INSERT INTO people
475 (address, city, name, phone, state)
476 VALUES (?, ?, ?, ?, ?)";
477 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
478 '123-456-7890', 'Louisiana');
479
480These are then used directly in your DBI code:
481
482 my $sth = $dbh->prepare($stmt);
483 $sth->execute(@bind);
484
96449e8e 485=head2 Inserting and Updating Arrays
486
487If your database has array types (like for example Postgres),
488activate the special option C<< array_datatypes => 1 >>
9d48860e 489when creating the C<SQL::Abstract> object.
96449e8e 490Then you may use an arrayref to insert and update database array types:
491
492 my $sql = SQL::Abstract->new(array_datatypes => 1);
493 my %data = (
494 planets => [qw/Mercury Venus Earth Mars/]
495 );
9d48860e 496
96449e8e 497 my($stmt, @bind) = $sql->insert('solar_system', \%data);
498
499This results in:
500
501 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
502
503 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
504
505
506=head2 Inserting and Updating SQL
507
508In order to apply SQL functions to elements of your C<%data> you may
509specify a reference to an arrayref for the given hash value. For example,
510if you need to execute the Oracle C<to_date> function on a value, you can
511say something like this:
32eab2da 512
513 my %data = (
514 name => 'Bill',
96449e8e 515 date_entered => \["to_date(?,'MM/DD/YYYY')", "03/02/2003"],
9d48860e 516 );
32eab2da 517
518The first value in the array is the actual SQL. Any other values are
519optional and would be included in the bind values array. This gives
520you:
521
522 my($stmt, @bind) = $sql->insert('people', \%data);
523
9d48860e 524 $stmt = "INSERT INTO people (name, date_entered)
32eab2da 525 VALUES (?, to_date(?,'MM/DD/YYYY'))";
526 @bind = ('Bill', '03/02/2003');
527
528An UPDATE is just as easy, all you change is the name of the function:
529
530 my($stmt, @bind) = $sql->update('people', \%data);
531
532Notice that your C<%data> isn't touched; the module will generate
533the appropriately quirky SQL for you automatically. Usually you'll
534want to specify a WHERE clause for your UPDATE, though, which is
535where handling C<%where> hashes comes in handy...
536
96449e8e 537=head2 Complex where statements
538
32eab2da 539This module can generate pretty complicated WHERE statements
540easily. For example, simple C<key=value> pairs are taken to mean
541equality, and if you want to see if a field is within a set
542of values, you can use an arrayref. Let's say we wanted to
543SELECT some data based on this criteria:
544
545 my %where = (
546 requestor => 'inna',
547 worker => ['nwiger', 'rcwe', 'sfz'],
548 status => { '!=', 'completed' }
549 );
550
551 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
552
553The above would give you something like this:
554
555 $stmt = "SELECT * FROM tickets WHERE
556 ( requestor = ? ) AND ( status != ? )
557 AND ( worker = ? OR worker = ? OR worker = ? )";
558 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
559
560Which you could then use in DBI code like so:
561
562 my $sth = $dbh->prepare($stmt);
563 $sth->execute(@bind);
564
565Easy, eh?
566
567=head1 FUNCTIONS
568
569The functions are simple. There's one for each major SQL operation,
570and a constructor you use first. The arguments are specified in a
9d48860e 571similar order to each function (table, then fields, then a where
32eab2da 572clause) to try and simplify things.
573
83cab70b 574
83cab70b 575
32eab2da 576
577=head2 new(option => 'value')
578
579The C<new()> function takes a list of options and values, and returns
580a new B<SQL::Abstract> object which can then be used to generate SQL
581through the methods below. The options accepted are:
582
583=over
584
585=item case
586
587If set to 'lower', then SQL will be generated in all lowercase. By
588default SQL is generated in "textbook" case meaning something like:
589
590 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
591
96449e8e 592Any setting other than 'lower' is ignored.
593
32eab2da 594=item cmp
595
596This determines what the default comparison operator is. By default
597it is C<=>, meaning that a hash like this:
598
599 %where = (name => 'nwiger', email => 'nate@wiger.org');
600
601Will generate SQL like this:
602
603 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
604
605However, you may want loose comparisons by default, so if you set
606C<cmp> to C<like> you would get SQL such as:
607
608 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
609
3af02ccb 610You can also override the comparison on an individual basis - see
32eab2da 611the huge section on L</"WHERE CLAUSES"> at the bottom.
612
96449e8e 613=item sqltrue, sqlfalse
614
615Expressions for inserting boolean values within SQL statements.
6e0c6552 616By default these are C<1=1> and C<1=0>. They are used
617by the special operators C<-in> and C<-not_in> for generating
618correct SQL even when the argument is an empty array (see below).
96449e8e 619
32eab2da 620=item logic
621
622This determines the default logical operator for multiple WHERE
7cac25e6 623statements in arrays or hashes. If absent, the default logic is "or"
624for arrays, and "and" for hashes. This means that a WHERE
32eab2da 625array of the form:
626
627 @where = (
9d48860e 628 event_date => {'>=', '2/13/99'},
629 event_date => {'<=', '4/24/03'},
32eab2da 630 );
631
7cac25e6 632will generate SQL like this:
32eab2da 633
634 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
635
636This is probably not what you want given this query, though (look
637at the dates). To change the "OR" to an "AND", simply specify:
638
639 my $sql = SQL::Abstract->new(logic => 'and');
640
641Which will change the above C<WHERE> to:
642
643 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
644
96449e8e 645The logic can also be changed locally by inserting
7cac25e6 646a modifier in front of an arrayref :
96449e8e 647
9d48860e 648 @where = (-and => [event_date => {'>=', '2/13/99'},
7cac25e6 649 event_date => {'<=', '4/24/03'} ]);
96449e8e 650
651See the L</"WHERE CLAUSES"> section for explanations.
652
32eab2da 653=item convert
654
655This will automatically convert comparisons using the specified SQL
656function for both column and value. This is mostly used with an argument
657of C<upper> or C<lower>, so that the SQL will have the effect of
658case-insensitive "searches". For example, this:
659
660 $sql = SQL::Abstract->new(convert => 'upper');
661 %where = (keywords => 'MaKe iT CAse inSeNSItive');
662
663Will turn out the following SQL:
664
665 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
666
667The conversion can be C<upper()>, C<lower()>, or any other SQL function
668that can be applied symmetrically to fields (actually B<SQL::Abstract> does
669not validate this option; it will just pass through what you specify verbatim).
670
671=item bindtype
672
673This is a kludge because many databases suck. For example, you can't
674just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
675Instead, you have to use C<bind_param()>:
676
677 $sth->bind_param(1, 'reg data');
678 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
679
680The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
681which loses track of which field each slot refers to. Fear not.
682
683If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
684Currently, you can specify either C<normal> (default) or C<columns>. If you
685specify C<columns>, you will get an array that looks like this:
686
687 my $sql = SQL::Abstract->new(bindtype => 'columns');
688 my($stmt, @bind) = $sql->insert(...);
689
690 @bind = (
691 [ 'column1', 'value1' ],
692 [ 'column2', 'value2' ],
693 [ 'column3', 'value3' ],
694 );
695
696You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 697
32eab2da 698 $sth->prepare($stmt);
699 my $i = 1;
700 for (@bind) {
701 my($col, $data) = @$_;
702 if ($col eq 'details' || $col eq 'comments') {
703 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
704 } elsif ($col eq 'image') {
705 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
706 } else {
707 $sth->bind_param($i, $data);
708 }
709 $i++;
710 }
711 $sth->execute; # execute without @bind now
712
713Now, why would you still use B<SQL::Abstract> if you have to do this crap?
714Basically, the advantage is still that you don't have to care which fields
715are or are not included. You could wrap that above C<for> loop in a simple
716sub called C<bind_fields()> or something and reuse it repeatedly. You still
717get a layer of abstraction over manual SQL specification.
718
deb148a2 719Note that if you set L</bindtype> to C<columns>, the C<\[$sql, @bind]>
720construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
721will expect the bind values in this format.
722
32eab2da 723=item quote_char
724
725This is the character that a table or column name will be quoted
9d48860e 726with. By default this is an empty string, but you could set it to
32eab2da 727the character C<`>, to generate SQL like this:
728
729 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
730
96449e8e 731Alternatively, you can supply an array ref of two items, the first being the left
732hand quote character, and the second the right hand quote character. For
733example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
734that generates SQL like this:
735
736 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
737
9d48860e 738Quoting is useful if you have tables or columns names that are reserved
96449e8e 739words in your database's SQL dialect.
32eab2da 740
741=item name_sep
742
743This is the character that separates a table and column name. It is
744necessary to specify this when the C<quote_char> option is selected,
745so that tables and column names can be individually quoted like this:
746
747 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
748
b6251592 749=item injection_guard
750
751A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
752column name specified in a query structure. This is a safety mechanism to avoid
753injection attacks when mishandling user input e.g.:
754
755 my %condition_as_column_value_pairs = get_values_from_user();
756 $sqla->select( ... , \%condition_as_column_value_pairs );
757
758If the expression matches an exception is thrown. Note that literal SQL
759supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
760
761Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
762
96449e8e 763=item array_datatypes
32eab2da 764
9d48860e 765When this option is true, arrayrefs in INSERT or UPDATE are
766interpreted as array datatypes and are passed directly
96449e8e 767to the DBI layer.
768When this option is false, arrayrefs are interpreted
769as literal SQL, just like refs to arrayrefs
770(but this behavior is for backwards compatibility; when writing
771new queries, use the "reference to arrayref" syntax
772for literal SQL).
32eab2da 773
32eab2da 774
96449e8e 775=item special_ops
32eab2da 776
9d48860e 777Takes a reference to a list of "special operators"
96449e8e 778to extend the syntax understood by L<SQL::Abstract>.
779See section L</"SPECIAL OPERATORS"> for details.
32eab2da 780
59f23b3d 781=item unary_ops
782
9d48860e 783Takes a reference to a list of "unary operators"
59f23b3d 784to extend the syntax understood by L<SQL::Abstract>.
785See section L</"UNARY OPERATORS"> for details.
786
32eab2da 787
32eab2da 788
96449e8e 789=back
32eab2da 790
02288357 791=head2 insert($table, \@values || \%fieldvals, \%options)
32eab2da 792
793This is the simplest function. You simply give it a table name
794and either an arrayref of values or hashref of field/value pairs.
795It returns an SQL INSERT statement and a list of bind values.
96449e8e 796See the sections on L</"Inserting and Updating Arrays"> and
797L</"Inserting and Updating SQL"> for information on how to insert
798with those data types.
32eab2da 799
02288357 800The optional C<\%options> hash reference may contain additional
801options to generate the insert SQL. Currently supported options
802are:
803
804=over 4
805
806=item returning
807
808Takes either a scalar of raw SQL fields, or an array reference of
809field names, and adds on an SQL C<RETURNING> statement at the end.
810This allows you to return data generated by the insert statement
811(such as row IDs) without performing another C<SELECT> statement.
812Note, however, this is not part of the SQL standard and may not
813be supported by all database engines.
814
815=back
816
32eab2da 817=head2 update($table, \%fieldvals, \%where)
818
819This takes a table, hashref of field/value pairs, and an optional
86298391 820hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 821of bind values.
96449e8e 822See the sections on L</"Inserting and Updating Arrays"> and
823L</"Inserting and Updating SQL"> for information on how to insert
824with those data types.
32eab2da 825
96449e8e 826=head2 select($source, $fields, $where, $order)
32eab2da 827
9d48860e 828This returns a SQL SELECT statement and associated list of bind values, as
96449e8e 829specified by the arguments :
32eab2da 830
96449e8e 831=over
32eab2da 832
96449e8e 833=item $source
32eab2da 834
9d48860e 835Specification of the 'FROM' part of the statement.
96449e8e 836The argument can be either a plain scalar (interpreted as a table
837name, will be quoted), or an arrayref (interpreted as a list
838of table names, joined by commas, quoted), or a scalarref
839(literal table name, not quoted), or a ref to an arrayref
840(list of literal table names, joined by commas, not quoted).
32eab2da 841
96449e8e 842=item $fields
32eab2da 843
9d48860e 844Specification of the list of fields to retrieve from
96449e8e 845the source.
846The argument can be either an arrayref (interpreted as a list
9d48860e 847of field names, will be joined by commas and quoted), or a
96449e8e 848plain scalar (literal SQL, not quoted).
521647e7 849Please observe that this API is not as flexible as that of
850the first argument C<$source>, for backwards compatibility reasons.
32eab2da 851
96449e8e 852=item $where
32eab2da 853
96449e8e 854Optional argument to specify the WHERE part of the query.
855The argument is most often a hashref, but can also be
9d48860e 856an arrayref or plain scalar --
96449e8e 857see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 858
96449e8e 859=item $order
32eab2da 860
96449e8e 861Optional argument to specify the ORDER BY part of the query.
9d48860e 862The argument can be a scalar, a hashref or an arrayref
96449e8e 863-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
864for details.
32eab2da 865
96449e8e 866=back
32eab2da 867
32eab2da 868
869=head2 delete($table, \%where)
870
86298391 871This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 872It returns an SQL DELETE statement and list of bind values.
873
32eab2da 874=head2 where(\%where, \@order)
875
876This is used to generate just the WHERE clause. For example,
877if you have an arbitrary data structure and know what the
878rest of your SQL is going to look like, but want an easy way
879to produce a WHERE clause, use this. It returns an SQL WHERE
880clause and list of bind values.
881
32eab2da 882
883=head2 values(\%data)
884
885This just returns the values from the hash C<%data>, in the same
886order that would be returned from any of the other above queries.
887Using this allows you to markedly speed up your queries if you
888are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
889
32eab2da 890=head2 generate($any, 'number', $of, \@data, $struct, \%types)
891
892Warning: This is an experimental method and subject to change.
893
894This returns arbitrarily generated SQL. It's a really basic shortcut.
895It will return two different things, depending on return context:
896
897 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
898 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
899
900These would return the following:
901
902 # First calling form
903 $stmt = "CREATE TABLE test (?, ?)";
904 @bind = (field1, field2);
905
906 # Second calling form
907 $stmt_and_val = "CREATE TABLE test (field1, field2)";
908
909Depending on what you're trying to do, it's up to you to choose the correct
910format. In this example, the second form is what you would want.
911
912By the same token:
913
914 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
915
916Might give you:
917
918 ALTER SESSION SET nls_date_format = 'MM/YY'
919
920You get the idea. Strings get their case twiddled, but everything
921else remains verbatim.
922
32eab2da 923=head1 WHERE CLAUSES
924
96449e8e 925=head2 Introduction
926
32eab2da 927This module uses a variation on the idea from L<DBIx::Abstract>. It
928is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
929module is that things in arrays are OR'ed, and things in hashes
930are AND'ed.>
931
932The easiest way to explain is to show lots of examples. After
933each C<%where> hash shown, it is assumed you used:
934
935 my($stmt, @bind) = $sql->where(\%where);
936
937However, note that the C<%where> hash can be used directly in any
938of the other functions as well, as described above.
939
96449e8e 940=head2 Key-value pairs
941
32eab2da 942So, let's get started. To begin, a simple hash:
943
944 my %where = (
945 user => 'nwiger',
946 status => 'completed'
947 );
948
949Is converted to SQL C<key = val> statements:
950
951 $stmt = "WHERE user = ? AND status = ?";
952 @bind = ('nwiger', 'completed');
953
954One common thing I end up doing is having a list of values that
955a field can be in. To do this, simply specify a list inside of
956an arrayref:
957
958 my %where = (
959 user => 'nwiger',
960 status => ['assigned', 'in-progress', 'pending'];
961 );
962
963This simple code will create the following:
9d48860e 964
32eab2da 965 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
966 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
967
9d48860e 968A field associated to an empty arrayref will be considered a
7cac25e6 969logical false and will generate 0=1.
8a68b5be 970
b864ba9b 971=head2 Tests for NULL values
972
973If the value part is C<undef> then this is converted to SQL <IS NULL>
974
975 my %where = (
976 user => 'nwiger',
977 status => undef,
978 );
979
980becomes:
981
982 $stmt = "WHERE user = ? AND status IS NULL";
983 @bind = ('nwiger');
984
e9614080 985To test if a column IS NOT NULL:
986
987 my %where = (
988 user => 'nwiger',
989 status => { '!=', undef },
990 );
cc422895 991
6e0c6552 992=head2 Specific comparison operators
96449e8e 993
32eab2da 994If you want to specify a different type of operator for your comparison,
995you can use a hashref for a given column:
996
997 my %where = (
998 user => 'nwiger',
999 status => { '!=', 'completed' }
1000 );
1001
1002Which would generate:
1003
1004 $stmt = "WHERE user = ? AND status != ?";
1005 @bind = ('nwiger', 'completed');
1006
1007To test against multiple values, just enclose the values in an arrayref:
1008
96449e8e 1009 status => { '=', ['assigned', 'in-progress', 'pending'] };
1010
f2d5020d 1011Which would give you:
96449e8e 1012
1013 "WHERE status = ? OR status = ? OR status = ?"
1014
1015
1016The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 1017into an C<AND> of its elements:
1018
1019 my %where = (
1020 user => 'nwiger',
1021 status => { '!=', 'completed', -not_like => 'pending%' }
1022 );
1023
1024 # Or more dynamically, like from a form
1025 $where{user} = 'nwiger';
1026 $where{status}{'!='} = 'completed';
1027 $where{status}{'-not_like'} = 'pending%';
1028
1029 # Both generate this
1030 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
1031 @bind = ('nwiger', 'completed', 'pending%');
1032
96449e8e 1033
32eab2da 1034To get an OR instead, you can combine it with the arrayref idea:
1035
1036 my %where => (
1037 user => 'nwiger',
1a6f2a03 1038 priority => [ { '=', 2 }, { '>', 5 } ]
32eab2da 1039 );
1040
1041Which would generate:
1042
1a6f2a03 1043 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
1044 @bind = ('2', '5', 'nwiger');
32eab2da 1045
44b9e502 1046If you want to include literal SQL (with or without bind values), just use a
1047scalar reference or array reference as the value:
1048
1049 my %where = (
1050 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
1051 date_expires => { '<' => \"now()" }
1052 );
1053
1054Which would generate:
1055
1056 $stmt = "WHERE date_entered > "to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
1057 @bind = ('11/26/2008');
1058
96449e8e 1059
1060=head2 Logic and nesting operators
1061
1062In the example above,
1063there is a subtle trap if you want to say something like
32eab2da 1064this (notice the C<AND>):
1065
1066 WHERE priority != ? AND priority != ?
1067
1068Because, in Perl you I<can't> do this:
1069
1070 priority => { '!=', 2, '!=', 1 }
1071
1072As the second C<!=> key will obliterate the first. The solution
1073is to use the special C<-modifier> form inside an arrayref:
1074
9d48860e 1075 priority => [ -and => {'!=', 2},
96449e8e 1076 {'!=', 1} ]
1077
32eab2da 1078
1079Normally, these would be joined by C<OR>, but the modifier tells it
1080to use C<AND> instead. (Hint: You can use this in conjunction with the
1081C<logic> option to C<new()> in order to change the way your queries
1082work by default.) B<Important:> Note that the C<-modifier> goes
1083B<INSIDE> the arrayref, as an extra first element. This will
1084B<NOT> do what you think it might:
1085
1086 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
1087
1088Here is a quick list of equivalencies, since there is some overlap:
1089
1090 # Same
1091 status => {'!=', 'completed', 'not like', 'pending%' }
1092 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
1093
1094 # Same
1095 status => {'=', ['assigned', 'in-progress']}
1096 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
1097 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
1098
e3f9dff4 1099
1100
96449e8e 1101=head2 Special operators : IN, BETWEEN, etc.
1102
32eab2da 1103You can also use the hashref format to compare a list of fields using the
1104C<IN> comparison operator, by specifying the list as an arrayref:
1105
1106 my %where = (
1107 status => 'completed',
1108 reportid => { -in => [567, 2335, 2] }
1109 );
1110
1111Which would generate:
1112
1113 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
1114 @bind = ('completed', '567', '2335', '2');
1115
9d48860e 1116The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
96449e8e 1117the same way.
1118
6e0c6552 1119If the argument to C<-in> is an empty array, 'sqlfalse' is generated
1120(by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
1121'sqltrue' (by default : C<1=1>).
1122
e41c3bdd 1123In addition to the array you can supply a chunk of literal sql or
1124literal sql with bind:
6e0c6552 1125
e41c3bdd 1126 my %where = {
1127 customer => { -in => \[
1128 'SELECT cust_id FROM cust WHERE balance > ?',
1129 2000,
1130 ],
1131 status => { -in => \'SELECT status_codes FROM states' },
1132 };
6e0c6552 1133
e41c3bdd 1134would generate:
1135
1136 $stmt = "WHERE (
1137 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
1138 AND status IN ( SELECT status_codes FROM states )
1139 )";
1140 @bind = ('2000');
1141
0dfd2442 1142Finally, if the argument to C<-in> is not a reference, it will be
1143treated as a single-element array.
e41c3bdd 1144
1145Another pair of operators is C<-between> and C<-not_between>,
96449e8e 1146used with an arrayref of two values:
32eab2da 1147
1148 my %where = (
1149 user => 'nwiger',
1150 completion_date => {
1151 -not_between => ['2002-10-01', '2003-02-06']
1152 }
1153 );
1154
1155Would give you:
1156
1157 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
1158
e41c3bdd 1159Just like with C<-in> all plausible combinations of literal SQL
1160are possible:
1161
1162 my %where = {
1163 start0 => { -between => [ 1, 2 ] },
1164 start1 => { -between => \["? AND ?", 1, 2] },
1165 start2 => { -between => \"lower(x) AND upper(y)" },
9d48860e 1166 start3 => { -between => [
e41c3bdd 1167 \"lower(x)",
1168 \["upper(?)", 'stuff' ],
1169 ] },
1170 };
1171
1172Would give you:
1173
1174 $stmt = "WHERE (
1175 ( start0 BETWEEN ? AND ? )
1176 AND ( start1 BETWEEN ? AND ? )
1177 AND ( start2 BETWEEN lower(x) AND upper(y) )
1178 AND ( start3 BETWEEN lower(x) AND upper(?) )
1179 )";
1180 @bind = (1, 2, 1, 2, 'stuff');
1181
1182
9d48860e 1183These are the two builtin "special operators"; but the
96449e8e 1184list can be expanded : see section L</"SPECIAL OPERATORS"> below.
1185
59f23b3d 1186=head2 Unary operators: bool
97a920ef 1187
1188If you wish to test against boolean columns or functions within your
1189database you can use the C<-bool> and C<-not_bool> operators. For
1190example to test the column C<is_user> being true and the column
827bb0eb 1191C<is_enabled> being false you would use:-
97a920ef 1192
1193 my %where = (
1194 -bool => 'is_user',
1195 -not_bool => 'is_enabled',
1196 );
1197
1198Would give you:
1199
277b5d3f 1200 WHERE is_user AND NOT is_enabled
97a920ef 1201
0b604e9d 1202If a more complex combination is required, testing more conditions,
1203then you should use the and/or operators:-
1204
1205 my %where = (
1206 -and => [
1207 -bool => 'one',
23401b81 1208 -not_bool => { two=> { -rlike => 'bar' } },
1209 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
0b604e9d 1210 ],
1211 );
1212
1213Would give you:
1214
23401b81 1215 WHERE
1216 one
1217 AND
1218 (NOT two RLIKE ?)
1219 AND
1220 (NOT ( three = ? OR three > ? ))
97a920ef 1221
1222
107b72f1 1223=head2 Nested conditions, -and/-or prefixes
96449e8e 1224
32eab2da 1225So far, we've seen how multiple conditions are joined with a top-level
1226C<AND>. We can change this by putting the different conditions we want in
1227hashes and then putting those hashes in an array. For example:
1228
1229 my @where = (
1230 {
1231 user => 'nwiger',
1232 status => { -like => ['pending%', 'dispatched'] },
1233 },
1234 {
1235 user => 'robot',
1236 status => 'unassigned',
1237 }
1238 );
1239
1240This data structure would create the following:
1241
1242 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
1243 OR ( user = ? AND status = ? ) )";
1244 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
1245
107b72f1 1246
48d9f5f8 1247Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
1248to change the logic inside :
32eab2da 1249
1250 my @where = (
1251 -and => [
1252 user => 'nwiger',
48d9f5f8 1253 [
1254 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
1255 -or => { workhrs => {'<', 50}, geo => 'EURO' },
32eab2da 1256 ],
1257 ],
1258 );
1259
1260That would yield:
1261
48d9f5f8 1262 WHERE ( user = ? AND (
1263 ( workhrs > ? AND geo = ? )
1264 OR ( workhrs < ? OR geo = ? )
1265 ) )
107b72f1 1266
cc422895 1267=head3 Algebraic inconsistency, for historical reasons
107b72f1 1268
7cac25e6 1269C<Important note>: when connecting several conditions, the C<-and->|C<-or>
1270operator goes C<outside> of the nested structure; whereas when connecting
1271several constraints on one column, the C<-and> operator goes
1272C<inside> the arrayref. Here is an example combining both features :
1273
1274 my @where = (
1275 -and => [a => 1, b => 2],
1276 -or => [c => 3, d => 4],
1277 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
1278 )
1279
1280yielding
1281
9d48860e 1282 WHERE ( ( ( a = ? AND b = ? )
1283 OR ( c = ? OR d = ? )
7cac25e6 1284 OR ( e LIKE ? AND e LIKE ? ) ) )
1285
107b72f1 1286This difference in syntax is unfortunate but must be preserved for
1287historical reasons. So be careful : the two examples below would
1288seem algebraically equivalent, but they are not
1289
9d48860e 1290 {col => [-and => {-like => 'foo%'}, {-like => '%bar'}]}
107b72f1 1291 # yields : WHERE ( ( col LIKE ? AND col LIKE ? ) )
1292
9d48860e 1293 [-and => {col => {-like => 'foo%'}, {col => {-like => '%bar'}}]]
107b72f1 1294 # yields : WHERE ( ( col LIKE ? OR col LIKE ? ) )
1295
7cac25e6 1296
cc422895 1297=head2 Literal SQL and value type operators
96449e8e 1298
cc422895 1299The basic premise of SQL::Abstract is that in WHERE specifications the "left
1300side" is a column name and the "right side" is a value (normally rendered as
1301a placeholder). This holds true for both hashrefs and arrayref pairs as you
1302see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
1303alter this behavior. There are several ways of doing so.
e9614080 1304
cc422895 1305=head3 -ident
1306
1307This is a virtual operator that signals the string to its right side is an
1308identifier (a column name) and not a value. For example to compare two
1309columns you would write:
32eab2da 1310
e9614080 1311 my %where = (
1312 priority => { '<', 2 },
cc422895 1313 requestor => { -ident => 'submitter' },
e9614080 1314 );
1315
1316which creates:
1317
1318 $stmt = "WHERE priority < ? AND requestor = submitter";
1319 @bind = ('2');
1320
cc422895 1321If you are maintaining legacy code you may see a different construct as
1322described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
1323code.
1324
1325=head3 -value
e9614080 1326
cc422895 1327This is a virtual operator that signals that the construct to its right side
1328is a value to be passed to DBI. This is for example necessary when you want
1329to write a where clause against an array (for RDBMS that support such
1330datatypes). For example:
e9614080 1331
32eab2da 1332 my %where = (
cc422895 1333 array => { -value => [1, 2, 3] }
32eab2da 1334 );
1335
cc422895 1336will result in:
32eab2da 1337
cc422895 1338 $stmt = 'WHERE array = ?';
1339 @bind = ([1, 2, 3]);
32eab2da 1340
cc422895 1341Note that if you were to simply say:
32eab2da 1342
1343 my %where = (
cc422895 1344 array => [1, 2, 3]
32eab2da 1345 );
1346
3af02ccb 1347the result would probably not be what you wanted:
cc422895 1348
1349 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
1350 @bind = (1, 2, 3);
1351
1352=head3 Literal SQL
96449e8e 1353
cc422895 1354Finally, sometimes only literal SQL will do. To include a random snippet
1355of SQL verbatim, you specify it as a scalar reference. Consider this only
1356as a last resort. Usually there is a better way. For example:
96449e8e 1357
1358 my %where = (
cc422895 1359 priority => { '<', 2 },
1360 requestor => { -in => \'(SELECT name FROM hitmen)' },
96449e8e 1361 );
1362
cc422895 1363Would create:
96449e8e 1364
cc422895 1365 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
1366 @bind = (2);
1367
1368Note that in this example, you only get one bind parameter back, since
1369the verbatim SQL is passed as part of the statement.
1370
1371=head4 CAVEAT
1372
1373 Never use untrusted input as a literal SQL argument - this is a massive
1374 security risk (there is no way to check literal snippets for SQL
1375 injections and other nastyness). If you need to deal with untrusted input
1376 use literal SQL with placeholders as described next.
96449e8e 1377
cc422895 1378=head3 Literal SQL with placeholders and bind values (subqueries)
96449e8e 1379
1380If the literal SQL to be inserted has placeholders and bind values,
1381use a reference to an arrayref (yes this is a double reference --
1382not so common, but perfectly legal Perl). For example, to find a date
1383in Postgres you can use something like this:
1384
1385 my %where = (
1386 date_column => \[q/= date '2008-09-30' - ?::integer/, 10/]
1387 )
1388
1389This would create:
1390
d2a8fe1a 1391 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 1392 @bind = ('10');
1393
deb148a2 1394Note that you must pass the bind values in the same format as they are returned
62552e7d 1395by L</where>. That means that if you set L</bindtype> to C<columns>, you must
26f2dca5 1396provide the bind values in the C<< [ column_meta => value ] >> format, where
1397C<column_meta> is an opaque scalar value; most commonly the column name, but
62552e7d 1398you can use any scalar value (including references and blessed references),
1399L<SQL::Abstract> will simply pass it through intact. So if C<bindtype> is set
1400to C<columns> the above example will look like:
deb148a2 1401
1402 my %where = (
1403 date_column => \[q/= date '2008-09-30' - ?::integer/, [ dummy => 10 ]/]
1404 )
96449e8e 1405
1406Literal SQL is especially useful for nesting parenthesized clauses in the
1407main SQL query. Here is a first example :
1408
1409 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
1410 100, "foo%");
1411 my %where = (
1412 foo => 1234,
1413 bar => \["IN ($sub_stmt)" => @sub_bind],
1414 );
1415
1416This yields :
1417
9d48860e 1418 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
96449e8e 1419 WHERE c2 < ? AND c3 LIKE ?))";
1420 @bind = (1234, 100, "foo%");
1421
9d48860e 1422Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
96449e8e 1423are expressed in the same way. Of course the C<$sub_stmt> and
9d48860e 1424its associated bind values can be generated through a former call
96449e8e 1425to C<select()> :
1426
1427 my ($sub_stmt, @sub_bind)
9d48860e 1428 = $sql->select("t1", "c1", {c2 => {"<" => 100},
96449e8e 1429 c3 => {-like => "foo%"}});
1430 my %where = (
1431 foo => 1234,
1432 bar => \["> ALL ($sub_stmt)" => @sub_bind],
1433 );
1434
1435In the examples above, the subquery was used as an operator on a column;
9d48860e 1436but the same principle also applies for a clause within the main C<%where>
96449e8e 1437hash, like an EXISTS subquery :
1438
9d48860e 1439 my ($sub_stmt, @sub_bind)
96449e8e 1440 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
48d9f5f8 1441 my %where = ( -and => [
96449e8e 1442 foo => 1234,
48d9f5f8 1443 \["EXISTS ($sub_stmt)" => @sub_bind],
1444 ]);
96449e8e 1445
1446which yields
1447
9d48860e 1448 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
96449e8e 1449 WHERE c1 = ? AND c2 > t0.c0))";
1450 @bind = (1234, 1);
1451
1452
9d48860e 1453Observe that the condition on C<c2> in the subquery refers to
1454column C<t0.c0> of the main query : this is I<not> a bind
1455value, so we have to express it through a scalar ref.
96449e8e 1456Writing C<< c2 => {">" => "t0.c0"} >> would have generated
1457C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
1458what we wanted here.
1459
96449e8e 1460Finally, here is an example where a subquery is used
1461for expressing unary negation:
1462
9d48860e 1463 my ($sub_stmt, @sub_bind)
96449e8e 1464 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
1465 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
1466 my %where = (
1467 lname => {like => '%son%'},
48d9f5f8 1468 \["NOT ($sub_stmt)" => @sub_bind],
96449e8e 1469 );
1470
1471This yields
1472
1473 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
1474 @bind = ('%son%', 10, 20)
1475
cc422895 1476=head3 Deprecated usage of Literal SQL
1477
1478Below are some examples of archaic use of literal SQL. It is shown only as
1479reference for those who deal with legacy code. Each example has a much
1480better, cleaner and safer alternative that users should opt for in new code.
1481
1482=over
1483
1484=item *
1485
1486 my %where = ( requestor => \'IS NOT NULL' )
1487
1488 $stmt = "WHERE requestor IS NOT NULL"
1489
1490This used to be the way of generating NULL comparisons, before the handling
1491of C<undef> got formalized. For new code please use the superior syntax as
1492described in L</Tests for NULL values>.
96449e8e 1493
cc422895 1494=item *
1495
1496 my %where = ( requestor => \'= submitter' )
1497
1498 $stmt = "WHERE requestor = submitter"
1499
1500This used to be the only way to compare columns. Use the superior L</-ident>
1501method for all new code. For example an identifier declared in such a way
1502will be properly quoted if L</quote_char> is properly set, while the legacy
1503form will remain as supplied.
1504
1505=item *
1506
1507 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
1508
1509 $stmt = "WHERE completed > ? AND is_ready"
1510 @bind = ('2012-12-21')
1511
1512Using an empty string literal used to be the only way to express a boolean.
1513For all new code please use the much more readable
1514L<-bool|/Unary operators: bool> operator.
1515
1516=back
96449e8e 1517
1518=head2 Conclusion
1519
32eab2da 1520These pages could go on for a while, since the nesting of the data
1521structures this module can handle are pretty much unlimited (the
1522module implements the C<WHERE> expansion as a recursive function
1523internally). Your best bet is to "play around" with the module a
1524little to see how the data structures behave, and choose the best
1525format for your data based on that.
1526
1527And of course, all the values above will probably be replaced with
1528variables gotten from forms or the command line. After all, if you
1529knew everything ahead of time, you wouldn't have to worry about
1530dynamically-generating SQL and could just hardwire it into your
1531script.
1532
86298391 1533=head1 ORDER BY CLAUSES
1534
9d48860e 1535Some functions take an order by clause. This can either be a scalar (just a
86298391 1536column name,) a hash of C<< { -desc => 'col' } >> or C<< { -asc => 'col' } >>,
1cfa1db3 1537or an array of either of the two previous forms. Examples:
1538
952f9e2d 1539 Given | Will Generate
1cfa1db3 1540 ----------------------------------------------------------
952f9e2d 1541 |
1542 \'colA DESC' | ORDER BY colA DESC
1543 |
1544 'colA' | ORDER BY colA
1545 |
1546 [qw/colA colB/] | ORDER BY colA, colB
1547 |
1548 {-asc => 'colA'} | ORDER BY colA ASC
1549 |
1550 {-desc => 'colB'} | ORDER BY colB DESC
1551 |
1552 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
1553 |
855e6047 1554 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
952f9e2d 1555 |
1556 [ |
1557 { -asc => 'colA' }, | ORDER BY colA ASC, colB DESC,
1558 { -desc => [qw/colB/], | colC ASC, colD ASC
1559 { -asc => [qw/colC colD/],|
1560 ] |
1561 ===========================================================
86298391 1562
96449e8e 1563
1564
1565=head1 SPECIAL OPERATORS
1566
e3f9dff4 1567 my $sqlmaker = SQL::Abstract->new(special_ops => [
3a2e1a5e 1568 {
1569 regex => qr/.../,
e3f9dff4 1570 handler => sub {
1571 my ($self, $field, $op, $arg) = @_;
1572 ...
3a2e1a5e 1573 },
1574 },
1575 {
1576 regex => qr/.../,
1577 handler => 'method_name',
e3f9dff4 1578 },
1579 ]);
1580
9d48860e 1581A "special operator" is a SQL syntactic clause that can be
e3f9dff4 1582applied to a field, instead of a usual binary operator.
9d48860e 1583For example :
e3f9dff4 1584
1585 WHERE field IN (?, ?, ?)
1586 WHERE field BETWEEN ? AND ?
1587 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 1588
e3f9dff4 1589Special operators IN and BETWEEN are fairly standard and therefore
3a2e1a5e 1590are builtin within C<SQL::Abstract> (as the overridable methods
1591C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
1592like the MATCH .. AGAINST example above which is specific to MySQL,
1593you can write your own operator handlers - supply a C<special_ops>
1594argument to the C<new> method. That argument takes an arrayref of
1595operator definitions; each operator definition is a hashref with two
1596entries:
96449e8e 1597
e3f9dff4 1598=over
1599
1600=item regex
1601
1602the regular expression to match the operator
96449e8e 1603
e3f9dff4 1604=item handler
1605
3a2e1a5e 1606Either a coderef or a plain scalar method name. In both cases
1607the expected return is C<< ($sql, @bind) >>.
1608
1609When supplied with a method name, it is simply called on the
1610L<SQL::Abstract/> object as:
1611
1612 $self->$method_name ($field, $op, $arg)
1613
1614 Where:
1615
1616 $op is the part that matched the handler regex
1617 $field is the LHS of the operator
1618 $arg is the RHS
1619
1620When supplied with a coderef, it is called as:
1621
1622 $coderef->($self, $field, $op, $arg)
1623
e3f9dff4 1624
1625=back
1626
9d48860e 1627For example, here is an implementation
e3f9dff4 1628of the MATCH .. AGAINST syntax for MySQL
1629
1630 my $sqlmaker = SQL::Abstract->new(special_ops => [
9d48860e 1631
e3f9dff4 1632 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
9d48860e 1633 {regex => qr/^match$/i,
e3f9dff4 1634 handler => sub {
1635 my ($self, $field, $op, $arg) = @_;
1636 $arg = [$arg] if not ref $arg;
1637 my $label = $self->_quote($field);
1638 my ($placeholder) = $self->_convert('?');
1639 my $placeholders = join ", ", (($placeholder) x @$arg);
1640 my $sql = $self->_sqlcase('match') . " ($label) "
1641 . $self->_sqlcase('against') . " ($placeholders) ";
1642 my @bind = $self->_bindtype($field, @$arg);
1643 return ($sql, @bind);
1644 }
1645 },
9d48860e 1646
e3f9dff4 1647 ]);
96449e8e 1648
1649
59f23b3d 1650=head1 UNARY OPERATORS
1651
112b5232 1652 my $sqlmaker = SQL::Abstract->new(unary_ops => [
59f23b3d 1653 {
1654 regex => qr/.../,
1655 handler => sub {
1656 my ($self, $op, $arg) = @_;
1657 ...
1658 },
1659 },
1660 {
1661 regex => qr/.../,
1662 handler => 'method_name',
1663 },
1664 ]);
1665
9d48860e 1666A "unary operator" is a SQL syntactic clause that can be
59f23b3d 1667applied to a field - the operator goes before the field
1668
1669You can write your own operator handlers - supply a C<unary_ops>
1670argument to the C<new> method. That argument takes an arrayref of
1671operator definitions; each operator definition is a hashref with two
1672entries:
1673
1674=over
1675
1676=item regex
1677
1678the regular expression to match the operator
1679
1680=item handler
1681
1682Either a coderef or a plain scalar method name. In both cases
1683the expected return is C<< $sql >>.
1684
1685When supplied with a method name, it is simply called on the
1686L<SQL::Abstract/> object as:
1687
1688 $self->$method_name ($op, $arg)
1689
1690 Where:
1691
1692 $op is the part that matched the handler regex
1693 $arg is the RHS or argument of the operator
1694
1695When supplied with a coderef, it is called as:
1696
1697 $coderef->($self, $op, $arg)
1698
1699
1700=back
1701
1702
32eab2da 1703=head1 PERFORMANCE
1704
1705Thanks to some benchmarking by Mark Stosberg, it turns out that
1706this module is many orders of magnitude faster than using C<DBIx::Abstract>.
1707I must admit this wasn't an intentional design issue, but it's a
1708byproduct of the fact that you get to control your C<DBI> handles
1709yourself.
1710
1711To maximize performance, use a code snippet like the following:
1712
1713 # prepare a statement handle using the first row
1714 # and then reuse it for the rest of the rows
1715 my($sth, $stmt);
1716 for my $href (@array_of_hashrefs) {
1717 $stmt ||= $sql->insert('table', $href);
1718 $sth ||= $dbh->prepare($stmt);
1719 $sth->execute($sql->values($href));
1720 }
1721
1722The reason this works is because the keys in your C<$href> are sorted
1723internally by B<SQL::Abstract>. Thus, as long as your data retains
1724the same structure, you only have to generate the SQL the first time
1725around. On subsequent queries, simply use the C<values> function provided
1726by this module to return your values in the correct order.
1727
b864ba9b 1728However this depends on the values having the same type - if, for
1729example, the values of a where clause may either have values
1730(resulting in sql of the form C<column = ?> with a single bind
1731value), or alternatively the values might be C<undef> (resulting in
1732sql of the form C<column IS NULL> with no bind value) then the
1733caching technique suggested will not work.
96449e8e 1734
32eab2da 1735=head1 FORMBUILDER
1736
1737If you use my C<CGI::FormBuilder> module at all, you'll hopefully
1738really like this part (I do, at least). Building up a complex query
1739can be as simple as the following:
1740
1741 #!/usr/bin/perl
1742
46dc2f3e 1743 use warnings;
1744 use strict;
1745
32eab2da 1746 use CGI::FormBuilder;
1747 use SQL::Abstract;
1748
1749 my $form = CGI::FormBuilder->new(...);
1750 my $sql = SQL::Abstract->new;
1751
1752 if ($form->submitted) {
1753 my $field = $form->field;
1754 my $id = delete $field->{id};
1755 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
1756 }
1757
1758Of course, you would still have to connect using C<DBI> to run the
1759query, but the point is that if you make your form look like your
1760table, the actual query script can be extremely simplistic.
1761
1762If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
9d48860e 1763a fast interface to returning and formatting data. I frequently
32eab2da 1764use these three modules together to write complex database query
1765apps in under 50 lines.
1766
d8cc1792 1767=head1 REPO
1768
1769=over
1770
6d19fbf9 1771=item * gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
d8cc1792 1772
6d19fbf9 1773=item * git: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
d8cc1792 1774
1775=back
32eab2da 1776
96449e8e 1777=head1 CHANGES
1778
1779Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
1780Great care has been taken to preserve the I<published> behavior
1781documented in previous versions in the 1.* family; however,
9d48860e 1782some features that were previously undocumented, or behaved
96449e8e 1783differently from the documentation, had to be changed in order
1784to clarify the semantics. Hence, client code that was relying
9d48860e 1785on some dark areas of C<SQL::Abstract> v1.*
96449e8e 1786B<might behave differently> in v1.50.
32eab2da 1787
d2a8fe1a 1788The main changes are :
1789
96449e8e 1790=over
32eab2da 1791
9d48860e 1792=item *
32eab2da 1793
96449e8e 1794support for literal SQL through the C<< \ [$sql, bind] >> syntax.
1795
1796=item *
1797
145fbfc8 1798support for the { operator => \"..." } construct (to embed literal SQL)
1799
1800=item *
1801
9c37b9c0 1802support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
1803
1804=item *
1805
96449e8e 1806optional support for L<array datatypes|/"Inserting and Updating Arrays">
1807
9d48860e 1808=item *
96449e8e 1809
1810defensive programming : check arguments
1811
1812=item *
1813
1814fixed bug with global logic, which was previously implemented
7cac25e6 1815through global variables yielding side-effects. Prior versions would
96449e8e 1816interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
1817as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
1818Now this is interpreted
1819as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
1820
96449e8e 1821
1822=item *
1823
1824fixed semantics of _bindtype on array args
1825
9d48860e 1826=item *
96449e8e 1827
1828dropped the C<_anoncopy> of the %where tree. No longer necessary,
1829we just avoid shifting arrays within that tree.
1830
1831=item *
1832
1833dropped the C<_modlogic> function
1834
1835=back
32eab2da 1836
32eab2da 1837=head1 ACKNOWLEDGEMENTS
1838
1839There are a number of individuals that have really helped out with
1840this module. Unfortunately, most of them submitted bugs via CPAN
1841so I have no idea who they are! But the people I do know are:
1842
9d48860e 1843 Ash Berlin (order_by hash term support)
b643abe1 1844 Matt Trout (DBIx::Class support)
32eab2da 1845 Mark Stosberg (benchmarking)
1846 Chas Owens (initial "IN" operator support)
1847 Philip Collins (per-field SQL functions)
1848 Eric Kolve (hashref "AND" support)
1849 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
1850 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 1851 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
48d9f5f8 1852 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
dbdf7648 1853 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
e96c510a 1854 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
02288357 1855 Oliver Charles (support for "RETURNING" after "INSERT")
32eab2da 1856
1857Thanks!
1858
32eab2da 1859=head1 SEE ALSO
1860
86298391 1861L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 1862
32eab2da 1863=head1 AUTHOR
1864
b643abe1 1865Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
1866
1867This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 1868
abe72f94 1869For support, your best bet is to try the C<DBIx::Class> users mailing list.
1870While not an official support venue, C<DBIx::Class> makes heavy use of
1871C<SQL::Abstract>, and as such list members there are very familiar with
1872how to create queries.
1873
0d067ded 1874=head1 LICENSE
1875
d988ab87 1876This module is free software; you may copy this under the same
1877terms as perl itself (either the GNU General Public License or
1878the Artistic License)
32eab2da 1879
1880=cut
1881