no longer required, op is normalised earlier
[scpubgit/Q-Branch.git] / lib / SQL / Abstract.pm
CommitLineData
96449e8e 1package SQL::Abstract; # see doc at end of file
2
96449e8e 3use strict;
4use warnings;
9d9d5bd6 5use Carp ();
312d830b 6use List::Util ();
7use Scalar::Util ();
96449e8e 8
0da0fe34 9use Exporter 'import';
10our @EXPORT_OK = qw(is_plain_value is_literal_value);
11
12BEGIN {
13 if ($] < 5.009_005) {
14 require MRO::Compat;
15 }
16 else {
17 require mro;
18 }
843a94b5 19
20 *SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION = $ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}
21 ? sub () { 0 }
22 : sub () { 1 }
23 ;
0da0fe34 24}
25
96449e8e 26#======================================================================
27# GLOBALS
28#======================================================================
29
dc6afcf8 30our $VERSION = '1.86';
7479e27e 31
22f1a437 32# This would confuse some packagers
c520207b 33$VERSION = eval $VERSION if $VERSION =~ /_/; # numify for warning-free dev releases
96449e8e 34
35our $AUTOLOAD;
36
37# special operators (-in, -between). May be extended/overridden by user.
38# See section WHERE: BUILTIN SPECIAL OPERATORS below for implementation
39my @BUILTIN_SPECIAL_OPS = (
f663e672 40 {regex => qr/^ (?: not \s )? between $/ix, handler => sub { die "NOPE" }},
41 {regex => qr/^ (?: not \s )? in $/ix, handler => sub { die "NOPE" }},
87c8e45b 42 {regex => qr/^ is (?: \s+ not )? $/ix, handler => sub { die "NOPE" }},
96449e8e 43);
44
45#======================================================================
46# DEBUGGING AND ERROR REPORTING
47#======================================================================
48
49sub _debug {
50 return unless $_[0]->{debug}; shift; # a little faster
51 my $func = (caller(1))[3];
52 warn "[$func] ", @_, "\n";
53}
54
55sub belch (@) {
56 my($func) = (caller(1))[3];
9d9d5bd6 57 Carp::carp "[$func] Warning: ", @_;
96449e8e 58}
59
60sub puke (@) {
61 my($func) = (caller(1))[3];
9d9d5bd6 62 Carp::croak "[$func] Fatal: ", @_;
96449e8e 63}
64
0da0fe34 65sub is_literal_value ($) {
66 ref $_[0] eq 'SCALAR' ? [ ${$_[0]} ]
67 : ( ref $_[0] eq 'REF' and ref ${$_[0]} eq 'ARRAY' ) ? [ @${ $_[0] } ]
0da0fe34 68 : undef;
69}
70
71# FIXME XSify - this can be done so much more efficiently
72sub is_plain_value ($) {
73 no strict 'refs';
966200cc 74 ! length ref $_[0] ? \($_[0])
0da0fe34 75 : (
76 ref $_[0] eq 'HASH' and keys %{$_[0]} == 1
77 and
78 exists $_[0]->{-value}
966200cc 79 ) ? \($_[0]->{-value})
0da0fe34 80 : (
a1c9e0ff 81 # reuse @_ for even moar speedz
82 defined ( $_[1] = Scalar::Util::blessed $_[0] )
0da0fe34 83 and
84 # deliberately not using Devel::OverloadInfo - the checks we are
85 # intersted in are much more limited than the fullblown thing, and
86 # this is a very hot piece of code
87 (
e8d729d4 88 # simply using ->can('(""') can leave behind stub methods that
89 # break actually using the overload later (see L<perldiag/Stub
90 # found while resolving method "%s" overloading "%s" in package
91 # "%s"> and the source of overload::mycan())
44e54b41 92 #
0da0fe34 93 # either has stringification which DBI SHOULD prefer out of the box
a1c9e0ff 94 grep { *{ (qq[${_}::(""]) }{CODE} } @{ $_[2] = mro::get_linear_isa( $_[1] ) }
0da0fe34 95 or
20e178a8 96 # has nummification or boolification, AND fallback is *not* disabled
0da0fe34 97 (
843a94b5 98 SQL::Abstract::_ENV_::DETECT_AUTOGENERATED_STRINGIFICATION
99 and
20e178a8 100 (
101 grep { *{"${_}::(0+"}{CODE} } @{$_[2]}
102 or
103 grep { *{"${_}::(bool"}{CODE} } @{$_[2]}
104 )
0da0fe34 105 and
106 (
107 # no fallback specified at all
a1c9e0ff 108 ! ( ($_[3]) = grep { *{"${_}::()"}{CODE} } @{$_[2]} )
0da0fe34 109 or
110 # fallback explicitly undef
a1c9e0ff 111 ! defined ${"$_[3]::()"}
0da0fe34 112 or
113 # explicitly true
a1c9e0ff 114 !! ${"$_[3]::()"}
0da0fe34 115 )
116 )
117 )
966200cc 118 ) ? \($_[0])
0da0fe34 119 : undef;
120}
121
122
96449e8e 123
124#======================================================================
125# NEW
126#======================================================================
127
128sub new {
129 my $self = shift;
130 my $class = ref($self) || $self;
131 my %opt = (ref $_[0] eq 'HASH') ? %{$_[0]} : @_;
132
133 # choose our case by keeping an option around
134 delete $opt{case} if $opt{case} && $opt{case} ne 'lower';
135
136 # default logic for interpreting arrayrefs
ef559da3 137 $opt{logic} = $opt{logic} ? uc $opt{logic} : 'OR';
96449e8e 138
139 # how to return bind vars
96449e8e 140 $opt{bindtype} ||= 'normal';
141
142 # default comparison is "=", but can be overridden
143 $opt{cmp} ||= '=';
144
3af02ccb 145 # try to recognize which are the 'equality' and 'inequality' ops
3cdadcbe 146 # (temporary quickfix (in 2007), should go through a more seasoned API)
147 $opt{equality_op} = qr/^( \Q$opt{cmp}\E | \= )$/ix;
148 $opt{inequality_op} = qr/^( != | <> )$/ix;
149
150 $opt{like_op} = qr/^ (is\s+)? r?like $/xi;
151 $opt{not_like_op} = qr/^ (is\s+)? not \s+ r?like $/xi;
96449e8e 152
153 # SQL booleans
154 $opt{sqltrue} ||= '1=1';
155 $opt{sqlfalse} ||= '0=1';
156
9d48860e 157 # special operators
30af97c5 158 $opt{special_ops} ||= [];
159
b6251592 160 # regexes are applied in order, thus push after user-defines
96449e8e 161 push @{$opt{special_ops}}, @BUILTIN_SPECIAL_OPS;
162
cf06e9dc 163 if ($class->isa('DBIx::Class::SQLMaker')) {
dd1d0dbf 164 push @{$opt{special_ops}}, our $DBIC_Compat_Op ||= {
165 regex => qr/^(?:ident|value)$/i, handler => sub { die "NOPE" }
166 };
cf06e9dc 167 $opt{is_dbic_sqlmaker} = 1;
dd1d0dbf 168 }
169
9d48860e 170 # unary operators
59f23b3d 171 $opt{unary_ops} ||= [];
59f23b3d 172
3af02ccb 173 # rudimentary sanity-check for user supplied bits treated as functions/operators
b6251592 174 # If a purported function matches this regular expression, an exception is thrown.
175 # Literal SQL is *NOT* subject to this check, only functions (and column names
176 # when quoting is not in effect)
96449e8e 177
b6251592 178 # FIXME
179 # need to guard against ()'s in column names too, but this will break tons of
180 # hacks... ideas anyone?
181 $opt{injection_guard} ||= qr/
182 \;
183 |
184 ^ \s* go \s
185 /xmi;
96449e8e 186
21225d32 187 $opt{render} = {
188 (map +("-$_", "_render_$_"), qw(op func bind ident literal list)),
189 %{$opt{render}||{}}
b07681b1 190 };
191
ec19b759 192 $opt{expand_unary} = {};
193
767b62e4 194 $opt{expand} = {
d1aabfe4 195 -ident => '_expand_ident',
71f1364b 196 -value => '_expand_value',
2a238661 197 -not => '_expand_not',
05d37f9c 198 -bool => '_expand_bool',
70f98e4b 199 -and => '_expand_andor',
200 -or => '_expand_andor',
767b62e4 201 };
202
b6251592 203 return bless \%opt, $class;
204}
96449e8e 205
e175845b 206sub sqltrue { +{ -literal => [ $_[0]->{sqltrue} ] } }
207sub sqlfalse { +{ -literal => [ $_[0]->{sqlfalse} ] } }
170e6c33 208
209sub _assert_pass_injection_guard {
210 if ($_[1] =~ $_[0]->{injection_guard}) {
211 my $class = ref $_[0];
212 puke "Possible SQL injection attempt '$_[1]'. If this is indeed a part of the "
213 . "desired SQL use literal SQL ( \'...' or \[ '...' ] ) or supply your own "
214 . "{injection_guard} attribute to ${class}->new()"
215 }
216}
217
218
96449e8e 219#======================================================================
220# INSERT methods
221#======================================================================
222
223sub insert {
02288357 224 my $self = shift;
225 my $table = $self->_table(shift);
226 my $data = shift || return;
227 my $options = shift;
96449e8e 228
229 my $method = $self->_METHOD_FOR_refkind("_insert", $data);
02288357 230 my ($sql, @bind) = $self->$method($data);
96449e8e 231 $sql = join " ", $self->_sqlcase('insert into'), $table, $sql;
02288357 232
e82e648a 233 if ($options->{returning}) {
ca4f826a 234 my ($s, @b) = $self->_insert_returning($options);
e82e648a 235 $sql .= $s;
236 push @bind, @b;
02288357 237 }
238
96449e8e 239 return wantarray ? ($sql, @bind) : $sql;
240}
241
60f3fd3f 242# So that subclasses can override INSERT ... RETURNING separately from
243# UPDATE and DELETE (e.g. DBIx::Class::SQLMaker::Oracle does this)
b17a3ece 244sub _insert_returning { shift->_returning(@_) }
245
95904db5 246sub _returning {
e82e648a 247 my ($self, $options) = @_;
6b1fe79d 248
e82e648a 249 my $f = $options->{returning};
250
79d310f2 251 my ($sql, @bind) = $self->render_aqt(
ff96fdd4 252 $self->_expand_maybe_list_expr($f, undef, -ident)
253 );
254 return wantarray
255 ? $self->_sqlcase(' returning ') . $sql
256 : ($self->_sqlcase(' returning ').$sql, @bind);
6b1fe79d 257}
258
96449e8e 259sub _insert_HASHREF { # explicit list of fields and then values
260 my ($self, $data) = @_;
261
262 my @fields = sort keys %$data;
263
fe3ae272 264 my ($sql, @bind) = $self->_insert_values($data);
96449e8e 265
266 # assemble SQL
267 $_ = $self->_quote($_) foreach @fields;
268 $sql = "( ".join(", ", @fields).") ".$sql;
269
270 return ($sql, @bind);
271}
272
273sub _insert_ARRAYREF { # just generate values(?,?) part (no list of fields)
274 my ($self, $data) = @_;
275
276 # no names (arrayref) so can't generate bindtype
277 $self->{bindtype} ne 'columns'
278 or belch "can't do 'columns' bindtype when called with arrayref";
279
19b6ccce 280 my (@values, @all_bind);
281 foreach my $value (@$data) {
282 my ($values, @bind) = $self->_insert_value(undef, $value);
283 push @values, $values;
284 push @all_bind, @bind;
285 }
286 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
287 return ($sql, @all_bind);
fe3ae272 288}
289
290sub _insert_ARRAYREFREF { # literal SQL with bind
291 my ($self, $data) = @_;
292
293 my ($sql, @bind) = @${$data};
294 $self->_assert_bindval_matches_bindtype(@bind);
295
296 return ($sql, @bind);
297}
298
299
300sub _insert_SCALARREF { # literal SQL without bind
301 my ($self, $data) = @_;
302
303 return ($$data);
304}
305
306sub _insert_values {
307 my ($self, $data) = @_;
308
96449e8e 309 my (@values, @all_bind);
fe3ae272 310 foreach my $column (sort keys %$data) {
19b6ccce 311 my ($values, @bind) = $self->_insert_value($column, $data->{$column});
312 push @values, $values;
313 push @all_bind, @bind;
314 }
315 my $sql = $self->_sqlcase('values')." ( ".join(", ", @values)." )";
316 return ($sql, @all_bind);
317}
96449e8e 318
19b6ccce 319sub _insert_value {
320 my ($self, $column, $v) = @_;
96449e8e 321
79d310f2 322 return $self->render_aqt(
720ca4f7 323 $self->_expand_insert_value($column, $v)
324 );
325}
96449e8e 326
720ca4f7 327sub _expand_insert_value {
328 my ($self, $column, $v) = @_;
96449e8e 329
720ca4f7 330 if (ref($v) eq 'ARRAY') {
331 if ($self->{array_datatypes}) {
332 return +{ -bind => [ $column, $v ] };
333 }
334 my ($sql, @bind) = @$v;
335 $self->_assert_bindval_matches_bindtype(@bind);
336 return +{ -literal => $v };
337 }
338 if (ref($v) eq 'HASH') {
339 if (grep !/^-/, keys %$v) {
340 belch "HASH ref as bind value in insert is not supported";
341 return +{ -bind => [ $column, $v ] };
342 }
343 }
344 if (!defined($v)) {
345 return +{ -bind => [ $column, undef ] };
346 }
347 local our $Cur_Col_Meta = $column;
79d310f2 348 return $self->expand_expr($v);
96449e8e 349}
350
351
96449e8e 352
353#======================================================================
354# UPDATE methods
355#======================================================================
356
357
358sub update {
95904db5 359 my $self = shift;
360 my $table = $self->_table(shift);
361 my $data = shift || return;
362 my $where = shift;
363 my $options = shift;
96449e8e 364
365 # first build the 'SET' part of the sql statement
96449e8e 366 puke "Unsupported data type specified to \$sql->update"
367 unless ref $data eq 'HASH';
368
9ade906e 369 my ($sql, @all_bind) = $self->_update_set_values($data);
a9e94508 370 $sql = $self->_sqlcase('update ') . $table . $self->_sqlcase(' set ')
9ade906e 371 . $sql;
372
373 if ($where) {
374 my($where_sql, @where_bind) = $self->where($where);
375 $sql .= $where_sql;
376 push @all_bind, @where_bind;
377 }
378
379 if ($options->{returning}) {
380 my ($returning_sql, @returning_bind) = $self->_update_returning($options);
381 $sql .= $returning_sql;
382 push @all_bind, @returning_bind;
383 }
384
385 return wantarray ? ($sql, @all_bind) : $sql;
386}
387
388sub _update_set_values {
389 my ($self, $data) = @_;
390
79d310f2 391 return $self->render_aqt(
89690da2 392 $self->_expand_update_set_values($data),
393 );
394}
96449e8e 395
89690da2 396sub _expand_update_set_values {
397 my ($self, $data) = @_;
398 $self->_expand_maybe_list_expr( [
399 map {
400 my ($k, $set) = @$_;
c4ed66f4 401 $set = { -bind => $_ } unless defined $set;
9103bd14 402 +{ -op => [ '=', $self->_expand_ident(-ident => $k), $set ] };
89690da2 403 }
404 map {
405 my $k = $_;
406 my $v = $data->{$k};
407 (ref($v) eq 'ARRAY'
408 ? ($self->{array_datatypes}
409 ? [ $k, +{ -bind => [ $k, $v ] } ]
410 : [ $k, +{ -literal => $v } ])
411 : do {
412 local our $Cur_Col_Meta = $k;
413 [ $k, $self->_expand_expr($v) ]
414 }
415 );
416 } sort keys %$data
417 ] );
96449e8e 418}
419
60f3fd3f 420# So that subclasses can override UPDATE ... RETURNING separately from
421# INSERT and DELETE
20bb2ad5 422sub _update_returning { shift->_returning(@_) }
96449e8e 423
424
425
426#======================================================================
427# SELECT
428#======================================================================
429
430
431sub select {
432 my $self = shift;
433 my $table = $self->_table(shift);
434 my $fields = shift || '*';
435 my $where = shift;
436 my $order = shift;
437
daa4ccdd 438 my ($fields_sql, @bind) = $self->_select_fields($fields);
96449e8e 439
daa4ccdd 440 my ($where_sql, @where_bind) = $self->where($where, $order);
441 push @bind, @where_bind;
442
443 my $sql = join(' ', $self->_sqlcase('select'), $fields_sql,
96449e8e 444 $self->_sqlcase('from'), $table)
445 . $where_sql;
446
9d48860e 447 return wantarray ? ($sql, @bind) : $sql;
96449e8e 448}
449
daa4ccdd 450sub _select_fields {
451 my ($self, $fields) = @_;
de63ce57 452 return $fields unless ref($fields);
79d310f2 453 return $self->render_aqt(
27592e2b 454 $self->_expand_maybe_list_expr($fields, undef, '-ident')
455 );
daa4ccdd 456}
457
96449e8e 458#======================================================================
459# DELETE
460#======================================================================
461
462
463sub delete {
85327cd5 464 my $self = shift;
465 my $table = $self->_table(shift);
466 my $where = shift;
467 my $options = shift;
96449e8e 468
469 my($where_sql, @bind) = $self->where($where);
a9e94508 470 my $sql = $self->_sqlcase('delete from ') . $table . $where_sql;
96449e8e 471
85327cd5 472 if ($options->{returning}) {
ca4f826a 473 my ($returning_sql, @returning_bind) = $self->_delete_returning($options);
85327cd5 474 $sql .= $returning_sql;
475 push @bind, @returning_bind;
476 }
477
9d48860e 478 return wantarray ? ($sql, @bind) : $sql;
96449e8e 479}
480
60f3fd3f 481# So that subclasses can override DELETE ... RETURNING separately from
482# INSERT and UPDATE
85327cd5 483sub _delete_returning { shift->_returning(@_) }
484
485
96449e8e 486
487#======================================================================
488# WHERE: entry point
489#======================================================================
490
491
492
493# Finally, a separate routine just to handle WHERE clauses
494sub where {
495 my ($self, $where, $order) = @_;
496
7ad12721 497 local $self->{convert_where} = $self->{convert};
498
96449e8e 499 # where ?
e175845b 500 my ($sql, @bind) = defined($where)
501 ? $self->_recurse_where($where)
502 : (undef);
417dd15e 503 $sql = (defined $sql and length $sql) ? $self->_sqlcase(' where ') . "( $sql )" : '';
96449e8e 504
505 # order by?
506 if ($order) {
26fe4d30 507 my ($order_sql, @order_bind) = $self->_order_by($order);
508 $sql .= $order_sql;
509 push @bind, @order_bind;
96449e8e 510 }
511
9d48860e 512 return wantarray ? ($sql, @bind) : $sql;
96449e8e 513}
514
79d310f2 515sub expand_expr {
54d3140f 516 my ($self, $expr, $default_scalar_to) = @_;
517 local our $Default_Scalar_To = $default_scalar_to if $default_scalar_to;
7d93797d 518 $self->_expand_expr($expr);
79d310f2 519}
520
521sub render_aqt {
522 my ($self, $aqt) = @_;
523 my ($k, $v, @rest) = %$aqt;
524 die "No" if @rest;
21225d32 525 if (my $meth = $self->{render}{$k}) {
79d310f2 526 return $self->$meth($v);
527 }
528 die "notreached: $k";
529}
530
6082a464 531sub render_expr {
532 my ($self, $expr) = @_;
533 $self->render_aqt($self->expand_expr($expr));
534}
535
a2cd381d 536sub _expand_expr {
c7aeb9f5 537 my ($self, $expr, $logic) = @_;
3ae10d16 538 our $Expand_Depth ||= 0; local $Expand_Depth = $Expand_Depth + 1;
252518da 539 return undef unless defined($expr);
59588695 540 if (ref($expr) eq 'HASH') {
767b62e4 541 return undef unless my $kc = keys %$expr;
542 if ($kc > 1) {
59588695 543 $logic ||= 'and';
70f98e4b 544 return $self->_expand_andor("-${logic}", $expr);
59588695 545 }
767b62e4 546 my ($key, $value) = %$expr;
70f98e4b 547 if ($key =~ /^-/ and $key =~ s/ [_\s]? \d+ $//x ) {
548 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
549 . "You probably wanted ...-and => [ $key => COND1, $key => COND2 ... ]";
550 }
767b62e4 551 if (my $exp = $self->{expand}{$key}) {
d1aabfe4 552 return $self->$exp($key, $value);
767b62e4 553 }
554 return $self->_expand_expr_hashpair($key, $value, $logic);
a2cd381d 555 }
08264f40 556 if (ref($expr) eq 'ARRAY') {
99a65fa8 557 my $logic = lc($logic || $self->{logic});
70f98e4b 558 return $self->_expand_andor("-${logic}", $expr);
08264f40 559 }
ca3da680 560 if (my $literal = is_literal_value($expr)) {
561 return +{ -literal => $literal };
562 }
99a65fa8 563 if (!ref($expr) or Scalar::Util::blessed($expr)) {
c7aeb9f5 564 if (my $d = our $Default_Scalar_To) {
a332e2cb 565 return $self->_expand_expr({ $d => $expr });
2558b622 566 }
24c9f930 567 return $self->_expand_value(-value => $expr);
252518da 568 }
252518da 569 die "notreached";
a2cd381d 570}
96449e8e 571
59588695 572sub _expand_expr_hashpair {
573 my ($self, $k, $v, $logic) = @_;
d13725da 574 unless (defined($k) and length($k)) {
2d64004f 575 if (defined($k) and my $literal = is_literal_value($v)) {
d13725da 576 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
2d64004f 577 return { -literal => $literal };
d13725da 578 }
579 puke "Supplying an empty left hand side argument is not supported";
580 }
ef071fad 581 if ($k =~ /^-/) {
99a65fa8 582 $self->_assert_pass_injection_guard($k =~ /^-(.*)$/s);
ef071fad 583 if ($k eq '-nest') {
0fc68377 584 # DBIx::Class requires a nest warning to be emitted once but the private
585 # method it overrode to do so no longer exists
cf06e9dc 586 if ($self->{is_dbic_sqlmaker}) {
587 unless (our $Nest_Warned) {
0fc68377 588 belch(
589 "-nest in search conditions is deprecated, you most probably wanted:\n"
590 .q|{..., -and => [ \%cond0, \@cond1, \'cond2', \[ 'cond3', [ col => bind ] ], etc. ], ... }|
591 );
592 $Nest_Warned = 1;
593 }
594 }
ef071fad 595 return $self->_expand_expr($v);
596 }
ce3bc4b0 597 if (my ($rest) = $k =~/^-not[_ ](.*)$/) {
0c7e3af0 598 return +{ -op => [
599 'not',
767b62e4 600 $self->_expand_expr({ "-${rest}", $v }, $logic)
0c7e3af0 601 ] };
ce3bc4b0 602 }
99a65fa8 603 {
604 my $op = $k;
605 $op =~ s/^-// if length($op) > 1;
ddc44894 606
99a65fa8 607 # top level special ops are illegal in general
3ae10d16 608 # note that, arguably, if it makes no sense at top level, it also
609 # makes no sense on the other side of an = sign or similar but DBIC
610 # gets disappointingly upset if I disallow it
611 if (
612 (our $Expand_Depth) == 1
613 and List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}
614 ) {
615 puke "Illegal use of top-level '-$op'"
616 }
96a8d74a 617 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
618 return { -op => [ $op, $v ] };
619 }
99a65fa8 620 }
21225d32 621 if ($self->{render}{$k}) {
99a65fa8 622 return { $k => $v };
d13725da 623 }
711892b1 624 if (
625 ref($v) eq 'HASH'
626 and keys %$v == 1
627 and (keys %$v)[0] =~ /^-/
628 ) {
629 my ($func) = $k =~ /^-(.*)$/;
3ae10d16 630 if (List::Util::first { $func =~ $_->{regex} } @{$self->{special_ops}}) {
631 return +{ -op => [ $func, $self->_expand_expr($v) ] };
632 }
711892b1 633 return +{ -func => [ $func, $self->_expand_expr($v) ] };
634 }
635 if (!ref($v) or is_literal_value($v)) {
99a65fa8 636 return +{ -op => [ $k =~ /^-(.*)$/, $self->_expand_expr($v) ] };
59588695 637 }
99a65fa8 638 }
639 if (
640 !defined($v)
641 or (
642 ref($v) eq 'HASH'
643 and exists $v->{-value}
644 and not defined $v->{-value}
645 )
646 ) {
213209dd 647 return $self->_expand_expr({ $k => { $self->{cmp} => undef } });
99a65fa8 648 }
649 if (!ref($v) or Scalar::Util::blessed($v)) {
ec19b759 650 my $d = our $Default_Scalar_To;
99a65fa8 651 return +{
652 -op => [
653 $self->{cmp},
944f2c7b 654 $self->_expand_ident(-ident => $k),
7d93797d 655 ($d
656 ? $self->_expand_expr($d => $v)
657 : { -bind => [ $k, $v ] }
658 )
99a65fa8 659 ]
660 };
661 }
662 if (ref($v) eq 'HASH') {
663 if (keys %$v > 1) {
e175845b 664 return { -op => [
665 'and',
5e75aa04 666 map $self->_expand_expr({ $k => { $_ => $v->{$_} } }),
99a65fa8 667 sort keys %$v
668 ] };
669 }
b18a95e4 670 return undef unless keys %$v;
99a65fa8 671 my ($vk, $vv) = %$v;
d455dcf1 672 my $op = join ' ', split '_', (map lc, $vk =~ /^-?(.*)$/)[0];
673 $self->_assert_pass_injection_guard($op);
674 if ($op =~ s/ [_\s]? \d+ $//x ) {
99a65fa8 675 belch 'Use of [and|or|nest]_N modifiers is deprecated and will be removed in SQLA v2.0. '
d455dcf1 676 . "You probably wanted ...-and => [ -$op => COND1, -$op => COND2 ... ]";
99a65fa8 677 }
d455dcf1 678 if ($op =~ /^(?:not )?between$/) {
99a65fa8 679 local our $Cur_Col_Meta = $k;
680 my @rhs = map $self->_expand_expr($_),
681 ref($vv) eq 'ARRAY' ? @$vv : $vv;
682 unless (
683 (@rhs == 1 and ref($rhs[0]) eq 'HASH' and $rhs[0]->{-literal})
684 or
685 (@rhs == 2 and defined($rhs[0]) and defined($rhs[1]))
686 ) {
d455dcf1 687 puke "Operator '${\uc($op)}' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref";
b5b18861 688 }
99a65fa8 689 return +{ -op => [
d455dcf1 690 $op,
944f2c7b 691 $self->_expand_ident(-ident => $k),
99a65fa8 692 @rhs
693 ] }
694 }
d455dcf1 695 if ($op =~ /^(?:not )?in$/) {
99a65fa8 696 if (my $literal = is_literal_value($vv)) {
697 my ($sql, @bind) = @$literal;
698 my $opened_sql = $self->_open_outer_paren($sql);
10d07c4e 699 return +{ -op => [
d455dcf1 700 $op, $self->_expand_ident(-ident => $k),
99a65fa8 701 [ { -literal => [ $opened_sql, @bind ] } ]
10d07c4e 702 ] };
703 }
99a65fa8 704 my $undef_err =
705 'SQL::Abstract before v1.75 used to generate incorrect SQL when the '
d455dcf1 706 . "-${\uc($op)} operator was given an undef-containing list: !!!AUDIT YOUR CODE "
99a65fa8 707 . 'AND DATA!!! (the upcoming Data::Query-based version of SQL::Abstract '
708 . 'will emit the logically correct SQL instead of raising this exception)'
709 ;
d455dcf1 710 puke("Argument passed to the '${\uc($op)}' operator can not be undefined")
99a65fa8 711 if !defined($vv);
712 my @rhs = map $self->_expand_expr($_),
713 map { ref($_) ? $_ : { -bind => [ $k, $_ ] } }
714 map { defined($_) ? $_: puke($undef_err) }
715 (ref($vv) eq 'ARRAY' ? @$vv : $vv);
d455dcf1 716 return $self->${\($op =~ /^not/ ? 'sqltrue' : 'sqlfalse')} unless @rhs;
99a65fa8 717
718 return +{ -op => [
d455dcf1 719 $op,
944f2c7b 720 $self->_expand_ident(-ident => $k),
99a65fa8 721 \@rhs
722 ] };
723 }
d455dcf1 724 if ($op eq 'ident') {
02b8fe35 725 if (! defined $vv or (ref($vv) and ref($vv) eq 'ARRAY')) {
d455dcf1 726 puke "-$op requires a single plain scalar argument (a quotable identifier) or an arrayref of identifier parts";
f7778474 727 }
99a65fa8 728 return +{ -op => [
729 $self->{cmp},
de8d04fb 730 $self->_expand_ident(-ident => $k),
731 $self->_expand_ident(-ident => $vv),
99a65fa8 732 ] };
733 }
d455dcf1 734 if ($op eq 'value') {
7b3a5558 735 return $self->_expand_expr({ $k, undef }) unless defined($vv);
99a65fa8 736 return +{ -op => [
737 $self->{cmp},
de8d04fb 738 $self->_expand_ident(-ident => $k),
99a65fa8 739 { -bind => [ $k, $vv ] }
740 ] };
741 }
d455dcf1 742 if ($op =~ /^is(?: not)?$/) {
743 puke "$op can only take undef as argument"
99a65fa8 744 if defined($vv)
745 and not (
746 ref($vv) eq 'HASH'
747 and exists($vv->{-value})
748 and !defined($vv->{-value})
749 );
d455dcf1 750 return +{ -op => [ $op.' null', $self->_expand_ident(-ident => $k) ] };
99a65fa8 751 }
d455dcf1 752 if ($op =~ /^(and|or)$/) {
99a65fa8 753 if (ref($vv) eq 'HASH') {
e62fe58a 754 return +{ -op => [
d455dcf1 755 $op,
ff1b554a 756 map $self->_expand_expr({ $k, { $_ => $vv->{$_} } }),
99a65fa8 757 sort keys %$vv
7d7868d1 758 ] };
759 }
e28d9b13 760 }
d455dcf1 761 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}}) {
762 return { -op => [ $op, $self->_expand_ident(-ident => $k), $vv ] };
7dbe1183 763 }
d455dcf1 764 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
96a8d74a 765 return { -op => [
766 $self->{cmp},
de8d04fb 767 $self->_expand_ident(-ident => $k),
d455dcf1 768 { -op => [ $op, $vv ] }
96a8d74a 769 ] };
770 }
99a65fa8 771 if (ref($vv) eq 'ARRAY') {
772 my ($logic, @values) = (
773 (defined($vv->[0]) and $vv->[0] =~ /^-(and|or)$/i)
774 ? @$vv
775 : (-or => @$vv)
776 );
777 if (
d455dcf1 778 $op =~ $self->{inequality_op}
779 or $op =~ $self->{not_like_op}
99a65fa8 780 ) {
781 if (lc($logic) eq '-or' and @values > 1) {
d455dcf1 782 belch "A multi-element arrayref as an argument to the inequality op '${\uc($op)}' "
99a65fa8 783 . 'is technically equivalent to an always-true 1=1 (you probably wanted '
784 . "to say ...{ \$inequality_op => [ -and => \@values ] }... instead)"
785 ;
786 }
ef071fad 787 }
b3cb13e8 788 unless (@values) {
789 # try to DWIM on equality operators
b3cb13e8 790 return
e175845b 791 $op =~ $self->{equality_op} ? $self->sqlfalse
792 : $op =~ $self->{like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqlfalse
793 : $op =~ $self->{inequality_op} ? $self->sqltrue
794 : $op =~ $self->{not_like_op} ? belch("Supplying an empty arrayref to '@{[ uc $op]}' is deprecated") && $self->sqltrue
b3cb13e8 795 : puke "operator '$op' applied on an empty array (field '$k')";
796 }
63c97a0b 797 return +{ -op => [
798 $logic =~ /^-(.*)$/,
85acf9c4 799 map $self->_expand_expr({ $k => { $vk => $_ } }),
99a65fa8 800 @values
801 ] };
802 }
803 if (
804 !defined($vv)
805 or (
806 ref($vv) eq 'HASH'
807 and exists $vv->{-value}
808 and not defined $vv->{-value}
809 )
810 ) {
99a65fa8 811 my $is =
812 $op =~ /^not$/i ? 'is not' # legacy
813 : $op =~ $self->{equality_op} ? 'is'
814 : $op =~ $self->{like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is'
815 : $op =~ $self->{inequality_op} ? 'is not'
816 : $op =~ $self->{not_like_op} ? belch("Supplying an undefined argument to '@{[ uc $op]}' is deprecated") && 'is not'
817 : puke "unexpected operator '$op' with undef operand";
de8d04fb 818 return +{ -op => [ $is.' null', $self->_expand_ident(-ident => $k) ] };
99a65fa8 819 }
820 local our $Cur_Col_Meta = $k;
821 return +{ -op => [
d455dcf1 822 $op,
823 $self->_expand_ident(-ident => $k),
824 $self->_expand_expr($vv)
99a65fa8 825 ] };
826 }
827 if (ref($v) eq 'ARRAY') {
e175845b 828 return $self->sqlfalse unless @$v;
99a65fa8 829 $self->_debug("ARRAY($k) means distribute over elements");
70f98e4b 830 my $this_logic = lc(
831 $v->[0] =~ /^-(and|or)$/i
832 ? shift(@{$v = [ @$v ]})
833 : '-'.($self->{logic} || 'or')
99a65fa8 834 );
70f98e4b 835 return $self->_expand_expr({
836 $this_logic => [ map +{ $k => $_ }, @$v ]
837 });
99a65fa8 838 }
839 if (my $literal = is_literal_value($v)) {
840 unless (length $k) {
841 belch 'Hash-pairs consisting of an empty string with a literal are deprecated, and will be removed in 2.0: use -and => [ $literal ] instead';
842 return \$literal;
843 }
844 my ($sql, @bind) = @$literal;
845 if ($self->{bindtype} eq 'columns') {
846 for (@bind) {
6fb2bd90 847 $self->_assert_bindval_matches_bindtype($_);
aa8d7bdb 848 }
331e2209 849 }
99a65fa8 850 return +{ -literal => [ $self->_quote($k).' '.$sql, @bind ] };
331e2209 851 }
99a65fa8 852 die "notreached";
59588695 853}
854
9103bd14 855sub _expand_ident {
856 my ($self, undef, $body) = @_;
857 my @parts = map split(/\Q${\($self->{name_sep}||'.')}\E/, $_),
858 ref($body) ? @$body : $body;
944f2c7b 859 return { -ident => $parts[-1] } if $self->{_dequalify_idents};
860 unless ($self->{quote_char}) {
861 $self->_assert_pass_injection_guard($_) for @parts;
862 }
9103bd14 863 return +{ -ident => \@parts };
864}
865
71f1364b 866sub _expand_value {
867 +{ -bind => [ our $Cur_Col_Meta, $_[2] ] };
868}
869
2a238661 870sub _expand_not {
871 +{ -op => [ 'not', $_[0]->_expand_expr($_[2]) ] };
872}
873
05d37f9c 874sub _expand_bool {
875 my ($self, undef, $v) = @_;
876 if (ref($v)) {
877 return $self->_expand_expr($v);
878 }
879 puke "-bool => undef not supported" unless defined($v);
880 return $self->_expand_ident(-ident => $v);
881}
882
70f98e4b 883sub _expand_andor {
884 my ($self, $k, $v) = @_;
885 my ($logic) = $k =~ /^-(.*)$/;
886 if (ref($v) eq 'HASH') {
887 return +{ -op => [
888 $logic,
889 map $self->_expand_expr({ $_ => $v->{$_} }, $logic),
890 sort keys %$v
891 ] };
892 }
893 if (ref($v) eq 'ARRAY') {
894 $logic eq 'and' or $logic eq 'or' or puke "unknown logic: $logic";
895
896 my @expr = grep {
897 (ref($_) eq 'ARRAY' and @$_)
898 or (ref($_) eq 'HASH' and %$_)
899 or 1
900 } @$v;
901
902 my @res;
903
904 while (my ($el) = splice @expr, 0, 1) {
905 puke "Supplying an empty left hand side argument is not supported in array-pairs"
906 unless defined($el) and length($el);
907 my $elref = ref($el);
908 if (!$elref) {
909 local our $Expand_Depth = 0;
910 push(@res, grep defined, $self->_expand_expr({ $el, shift(@expr) }));
911 } elsif ($elref eq 'ARRAY') {
912 push(@res, grep defined, $self->_expand_expr($el)) if @$el;
913 } elsif (my $l = is_literal_value($el)) {
914 push @res, { -literal => $l };
915 } elsif ($elref eq 'HASH') {
916 local our $Expand_Depth = 0;
917 push @res, grep defined, $self->_expand_expr($el) if %$el;
918 } else {
919 die "notreached";
920 }
921 }
922 # ???
923 # return $res[0] if @res == 1;
924 return { -op => [ $logic, @res ] };
925 }
926 die "notreached";
927}
928
96449e8e 929sub _recurse_where {
930 my ($self, $where, $logic) = @_;
931
5492d4c2 932 # Special case: top level simple string treated as literal
933
934 my $where_exp = (ref($where)
ae56a156 935 ? $self->_expand_expr($where, $logic)
5492d4c2 936 : { -literal => [ $where ] });
e175845b 937
e3e27543 938 # dispatch expanded expression
311b2151 939
79d310f2 940 my ($sql, @bind) = defined($where_exp) ? $self->render_aqt($where_exp) : (undef);
abe1a491 941 # DBIx::Class used to call _recurse_where in scalar context
942 # something else might too...
943 if (wantarray) {
944 return ($sql, @bind);
945 }
946 else {
947 belch "Calling _recurse_where in scalar context is deprecated and will go away before 2.0";
948 return $sql;
949 }
96449e8e 950}
951
181dcebf 952sub _render_ident {
953 my ($self, $ident) = @_;
cc422895 954
9cf28dfb 955 return $self->_convert($self->_quote($ident));
cc422895 956}
957
c452734e 958my %unop_postfix = map +($_ => 1),
959 'is null', 'is not null',
960 'asc', 'desc',
961;
d13725da 962
b5b18861 963my %special = (
964 (map +($_ => do {
965 my $op = $_;
966 sub {
967 my ($self, $args) = @_;
968 my ($left, $low, $high) = @$args;
969 my ($rhsql, @rhbind) = do {
970 if (@$args == 2) {
971 puke "Single arg to between must be a literal"
972 unless $low->{-literal};
973 @{$low->{-literal}}
974 } else {
79d310f2 975 my ($l, $h) = map [ $self->render_aqt($_) ], $low, $high;
b5b18861 976 (join(' ', $l->[0], $self->_sqlcase('and'), $h->[0]),
977 @{$l}[1..$#$l], @{$h}[1..$#$h])
978 }
979 };
79d310f2 980 my ($lhsql, @lhbind) = $self->render_aqt($left);
b5b18861 981 return (
982 join(' ', '(', $lhsql, $self->_sqlcase($op), $rhsql, ')'),
983 @lhbind, @rhbind
984 );
985 }
986 }), 'between', 'not between'),
10d07c4e 987 (map +($_ => do {
988 my $op = $_;
989 sub {
990 my ($self, $args) = @_;
991 my ($lhs, $rhs) = @$args;
992 my @in_bind;
993 my @in_sql = map {
79d310f2 994 my ($sql, @bind) = $self->render_aqt($_);
10d07c4e 995 push @in_bind, @bind;
996 $sql;
997 } @$rhs;
79d310f2 998 my ($lhsql, @lbind) = $self->render_aqt($lhs);
10d07c4e 999 return (
1000 $lhsql.' '.$self->_sqlcase($op).' ( '
1001 .join(', ', @in_sql)
1002 .' )',
1003 @lbind, @in_bind
1004 );
1005 }
1006 }), 'in', 'not in'),
b5b18861 1007);
1008
181dcebf 1009sub _render_op {
1010 my ($self, $v) = @_;
d13725da 1011 my ($op, @args) = @$v;
b5b18861 1012 if (my $h = $special{$op}) {
1013 return $self->$h(\@args);
1014 }
3ae10d16 1015 my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{special_ops}};
1016 if ($us and @args > 1) {
99a65fa8 1017 puke "Special op '${op}' requires first value to be identifier"
7d93797d 1018 unless my ($ident) = map $_->{-ident}, grep ref($_) eq 'HASH', $args[0];
1019 my $k = join(($self->{name_sep}||'.'), @$ident);
dd1d0dbf 1020 local our $Expand_Depth = 1;
99a65fa8 1021 return $self->${\($us->{handler})}($k, $op, $args[1]);
1022 }
96a8d74a 1023 if (my $us = List::Util::first { $op =~ $_->{regex} } @{$self->{unary_ops}}) {
1024 return $self->${\($us->{handler})}($op, $args[0]);
1025 }
a89f349e 1026 if (my $r = $self->{render_op}{$op}) {
1027 return $self->$r(\@args);
1028 }
2143604f 1029 if (@args == 1 and $op !~ /^(and|or)$/) {
79d310f2 1030 my ($expr_sql, @bind) = $self->render_aqt($args[0]);
9e242c8c 1031 my $op_sql = $self->_sqlcase($op);
d13725da 1032 my $final_sql = (
9e242c8c 1033 $unop_postfix{lc($op)}
d13725da 1034 ? "${expr_sql} ${op_sql}"
1035 : "${op_sql} ${expr_sql}"
1036 );
3ae10d16 1037 return (($op eq 'not' || $us ? '('.$final_sql.')' : $final_sql), @bind);
16d9289c 1038 } else {
79d310f2 1039 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @args;
1c0c0f41 1040 return '' unless @parts;
230812fc 1041 my $is_andor = !!($op =~ /^(and|or)$/);
1042 return @{$parts[0]} if $is_andor and @parts == 1;
1043 my ($final_sql) = map +($is_andor ? "( ${_} )" : $_), join(
9e242c8c 1044 ' '.$self->_sqlcase($op).' ',
77617257 1045 map $_->[0], @parts
1046 );
99a65fa8 1047 return (
77617257 1048 $final_sql,
16d9289c 1049 map @{$_}[1..$#$_], @parts
99a65fa8 1050 );
d13725da 1051 }
1052 die "unhandled";
1053}
1054
352d74bc 1055sub _render_list {
1056 my ($self, $list) = @_;
79d310f2 1057 my @parts = grep length($_->[0]), map [ $self->render_aqt($_) ], @$list;
352d74bc 1058 return join(', ', map $_->[0], @parts), map @{$_}[1..$#$_], @parts;
1059}
1060
181dcebf 1061sub _render_func {
1062 my ($self, $rest) = @_;
711892b1 1063 my ($func, @args) = @$rest;
1064 my @arg_sql;
1065 my @bind = map {
1066 my @x = @$_;
1067 push @arg_sql, shift @x;
1068 @x
79d310f2 1069 } map [ $self->render_aqt($_) ], @args;
711892b1 1070 return ($self->_sqlcase($func).'('.join(', ', @arg_sql).')', @bind);
1071}
1072
181dcebf 1073sub _render_bind {
1074 my ($self, $bind) = @_;
d13725da 1075 return ($self->_convert('?'), $self->_bindtype(@$bind));
1076}
1077
181dcebf 1078sub _render_literal {
1079 my ($self, $literal) = @_;
465d43fd 1080 $self->_assert_bindval_matches_bindtype(@{$literal}[1..$#$literal]);
aa8d7bdb 1081 return @$literal;
1082}
1083
4a1f01a3 1084# Some databases (SQLite) treat col IN (1, 2) different from
1085# col IN ( (1, 2) ). Use this to strip all outer parens while
1086# adding them back in the corresponding method
1087sub _open_outer_paren {
1088 my ($self, $sql) = @_;
a5f91feb 1089
ca4f826a 1090 while (my ($inner) = $sql =~ /^ \s* \( (.*) \) \s* $/xs) {
a5f91feb 1091
1092 # there are closing parens inside, need the heavy duty machinery
1093 # to reevaluate the extraction starting from $sql (full reevaluation)
ca4f826a 1094 if ($inner =~ /\)/) {
a5f91feb 1095 require Text::Balanced;
1096
1097 my (undef, $remainder) = do {
1098 # idiotic design - writes to $@ but *DOES NOT* throw exceptions
1099 local $@;
ca4f826a 1100 Text::Balanced::extract_bracketed($sql, '()', qr/\s*/);
a5f91feb 1101 };
1102
1103 # the entire expression needs to be a balanced bracketed thing
1104 # (after an extract no remainder sans trailing space)
1105 last if defined $remainder and $remainder =~ /\S/;
1106 }
1107
1108 $sql = $inner;
1109 }
1110
1111 $sql;
4a1f01a3 1112}
1113
96449e8e 1114
96449e8e 1115#======================================================================
1116# ORDER BY
1117#======================================================================
1118
33177570 1119sub _expand_order_by {
96449e8e 1120 my ($self, $arg) = @_;
1121
33177570 1122 return unless defined($arg) and not (ref($arg) eq 'ARRAY' and !@$arg);
2b6158af 1123
4325df6a 1124 my $expander = sub {
1125 my ($self, $dir, $expr) = @_;
52ca537e 1126 my @to_expand = ref($expr) eq 'ARRAY' ? @$expr : $expr;
1127 foreach my $arg (@to_expand) {
1128 if (
1129 ref($arg) eq 'HASH'
1130 and keys %$arg > 1
1131 and grep /^-(asc|desc)$/, keys %$arg
1132 ) {
1133 puke "ordering direction hash passed to order by must have exactly one key (-asc or -desc)";
1134 }
1135 }
7384c311 1136 my @exp = map +(
1137 defined($dir) ? { -op => [ $dir =~ /^-?(.*)$/ ,=> $_ ] } : $_
1138 ),
79d310f2 1139 map $self->expand_expr($_, -ident),
74156ee9 1140 map ref($_) eq 'ARRAY' ? @$_ : $_, @to_expand;
352d74bc 1141 return (@exp > 1 ? { -list => \@exp } : $exp[0]);
4325df6a 1142 };
18c743c8 1143
7384c311 1144 local @{$self->{expand}}{qw(-asc -desc)} = (($expander) x 2);
f267b646 1145
33177570 1146 return $self->$expander(undef, $arg);
1147}
1148
1149sub _order_by {
1150 my ($self, $arg) = @_;
1151
1152 return '' unless defined(my $expanded = $self->_expand_order_by($arg));
4325df6a 1153
79d310f2 1154 my ($sql, @bind) = $self->render_aqt($expanded);
4325df6a 1155
13cd9220 1156 return '' unless length($sql);
1157
4325df6a 1158 my $final_sql = $self->_sqlcase(' order by ').$sql;
1159
1160 return wantarray ? ($final_sql, @bind) : $final_sql;
f267b646 1161}
1162
2e3cc357 1163# _order_by no longer needs to call this so doesn't but DBIC uses it.
1164
33177570 1165sub _order_by_chunks {
1166 my ($self, $arg) = @_;
1167
1168 return () unless defined(my $expanded = $self->_expand_order_by($arg));
1169
2e3cc357 1170 return $self->_chunkify_order_by($expanded);
1171}
1172
1173sub _chunkify_order_by {
1174 my ($self, $expanded) = @_;
1b630cfe 1175
79d310f2 1176 return grep length, $self->render_aqt($expanded)
1b630cfe 1177 if $expanded->{-ident} or @{$expanded->{-literal}||[]} == 1;
1178
33177570 1179 for ($expanded) {
352d74bc 1180 if (ref() eq 'HASH' and my $l = $_->{-list}) {
1181 return map $self->_chunkify_order_by($_), @$l;
33177570 1182 }
79d310f2 1183 return [ $self->render_aqt($_) ];
33177570 1184 }
1185}
1186
96449e8e 1187#======================================================================
1188# DATASOURCE (FOR NOW, JUST PLAIN TABLE OR LIST OF TABLES)
1189#======================================================================
1190
1191sub _table {
1192 my $self = shift;
1193 my $from = shift;
79d310f2 1194 ($self->render_aqt(
8476c6a3 1195 $self->_expand_maybe_list_expr($from, undef, -ident)
7ad12721 1196 ))[0];
96449e8e 1197}
1198
1199
1200#======================================================================
1201# UTILITY FUNCTIONS
1202#======================================================================
1203
8476c6a3 1204sub _expand_maybe_list_expr {
1205 my ($self, $expr, $logic, $default) = @_;
bba04f52 1206 my $e = do {
1207 if (ref($expr) eq 'ARRAY') {
352d74bc 1208 return { -list => [
4ee3313d 1209 map $self->expand_expr($_, $default), @$expr
bba04f52 1210 ] } if @$expr > 1;
1211 $expr->[0]
1212 } else {
1213 $expr
1214 }
1215 };
4ee3313d 1216 return $self->expand_expr($e, $default);
8476c6a3 1217}
1218
955e77ca 1219# highly optimized, as it's called way too often
96449e8e 1220sub _quote {
955e77ca 1221 # my ($self, $label) = @_;
96449e8e 1222
955e77ca 1223 return '' unless defined $_[1];
955e77ca 1224 return ${$_[1]} if ref($_[1]) eq 'SCALAR';
d3162b5c 1225 puke 'Identifier cannot be hashref' if ref($_[1]) eq 'HASH';
96449e8e 1226
d3162b5c 1227 unless ($_[0]->{quote_char}) {
1228 if (ref($_[1]) eq 'ARRAY') {
1229 return join($_[0]->{name_sep}||'.', @{$_[1]});
1230 } else {
1231 $_[0]->_assert_pass_injection_guard($_[1]);
1232 return $_[1];
1233 }
1234 }
96449e8e 1235
07d7c35c 1236 my $qref = ref $_[0]->{quote_char};
439834d3 1237 my ($l, $r) =
1238 !$qref ? ($_[0]->{quote_char}, $_[0]->{quote_char})
1239 : ($qref eq 'ARRAY') ? @{$_[0]->{quote_char}}
1240 : puke "Unsupported quote_char format: $_[0]->{quote_char}";
1241
46be4313 1242 my $esc = $_[0]->{escape_char} || $r;
96449e8e 1243
07d7c35c 1244 # parts containing * are naturally unquoted
d3162b5c 1245 return join(
1246 $_[0]->{name_sep}||'',
1247 map +(
1248 $_ eq '*'
1249 ? $_
1250 : do { (my $n = $_) =~ s/(\Q$esc\E|\Q$r\E)/$esc$1/g; $l . $n . $r }
1251 ),
1252 (ref($_[1]) eq 'ARRAY'
1253 ? @{$_[1]}
1254 : (
1255 $_[0]->{name_sep}
1256 ? split (/\Q$_[0]->{name_sep}\E/, $_[1] )
1257 : $_[1]
1258 )
1259 )
955e77ca 1260 );
96449e8e 1261}
1262
1263
1264# Conversion, if applicable
d7c862e0 1265sub _convert {
07d7c35c 1266 #my ($self, $arg) = @_;
7ad12721 1267 if ($_[0]->{convert_where}) {
1268 return $_[0]->_sqlcase($_[0]->{convert_where}) .'(' . $_[1] . ')';
96449e8e 1269 }
07d7c35c 1270 return $_[1];
96449e8e 1271}
1272
1273# And bindtype
d7c862e0 1274sub _bindtype {
07d7c35c 1275 #my ($self, $col, @vals) = @_;
07d7c35c 1276 # called often - tighten code
1277 return $_[0]->{bindtype} eq 'columns'
1278 ? map {[$_[1], $_]} @_[2 .. $#_]
1279 : @_[2 .. $#_]
1280 ;
96449e8e 1281}
1282
fe3ae272 1283# Dies if any element of @bind is not in [colname => value] format
1284# if bindtype is 'columns'.
1285sub _assert_bindval_matches_bindtype {
c94a6c93 1286# my ($self, @bind) = @_;
1287 my $self = shift;
fe3ae272 1288 if ($self->{bindtype} eq 'columns') {
c94a6c93 1289 for (@_) {
1290 if (!defined $_ || ref($_) ne 'ARRAY' || @$_ != 2) {
3a06278c 1291 puke "bindtype 'columns' selected, you need to pass: [column_name => bind_value]"
fe3ae272 1292 }
1293 }
1294 }
1295}
1296
96449e8e 1297sub _join_sql_clauses {
1298 my ($self, $logic, $clauses_aref, $bind_aref) = @_;
1299
1300 if (@$clauses_aref > 1) {
1301 my $join = " " . $self->_sqlcase($logic) . " ";
1302 my $sql = '( ' . join($join, @$clauses_aref) . ' )';
1303 return ($sql, @$bind_aref);
1304 }
1305 elsif (@$clauses_aref) {
1306 return ($clauses_aref->[0], @$bind_aref); # no parentheses
1307 }
1308 else {
1309 return (); # if no SQL, ignore @$bind_aref
1310 }
1311}
1312
1313
1314# Fix SQL case, if so requested
1315sub _sqlcase {
96449e8e 1316 # LDNOTE: if $self->{case} is true, then it contains 'lower', so we
1317 # don't touch the argument ... crooked logic, but let's not change it!
07d7c35c 1318 return $_[0]->{case} ? $_[1] : uc($_[1]);
96449e8e 1319}
1320
1321
1322#======================================================================
1323# DISPATCHING FROM REFKIND
1324#======================================================================
1325
1326sub _refkind {
1327 my ($self, $data) = @_;
96449e8e 1328
955e77ca 1329 return 'UNDEF' unless defined $data;
1330
1331 # blessed objects are treated like scalars
1332 my $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1333
1334 return 'SCALAR' unless $ref;
1335
1336 my $n_steps = 1;
1337 while ($ref eq 'REF') {
96449e8e 1338 $data = $$data;
955e77ca 1339 $ref = (Scalar::Util::blessed $data) ? '' : ref $data;
1340 $n_steps++ if $ref;
96449e8e 1341 }
1342
848556bc 1343 return ($ref||'SCALAR') . ('REF' x $n_steps);
96449e8e 1344}
1345
1346sub _try_refkind {
1347 my ($self, $data) = @_;
1348 my @try = ($self->_refkind($data));
1349 push @try, 'SCALAR_or_UNDEF' if $try[0] eq 'SCALAR' || $try[0] eq 'UNDEF';
1350 push @try, 'FALLBACK';
955e77ca 1351 return \@try;
96449e8e 1352}
1353
1354sub _METHOD_FOR_refkind {
1355 my ($self, $meth_prefix, $data) = @_;
f39eaa60 1356
1357 my $method;
955e77ca 1358 for (@{$self->_try_refkind($data)}) {
f39eaa60 1359 $method = $self->can($meth_prefix."_".$_)
1360 and last;
1361 }
1362
1363 return $method || puke "cannot dispatch on '$meth_prefix' for ".$self->_refkind($data);
96449e8e 1364}
1365
1366
1367sub _SWITCH_refkind {
1368 my ($self, $data, $dispatch_table) = @_;
1369
f39eaa60 1370 my $coderef;
955e77ca 1371 for (@{$self->_try_refkind($data)}) {
f39eaa60 1372 $coderef = $dispatch_table->{$_}
1373 and last;
1374 }
1375
1376 puke "no dispatch entry for ".$self->_refkind($data)
1377 unless $coderef;
1378
96449e8e 1379 $coderef->();
1380}
1381
1382
1383
1384
1385#======================================================================
1386# VALUES, GENERATE, AUTOLOAD
1387#======================================================================
1388
1389# LDNOTE: original code from nwiger, didn't touch code in that section
1390# I feel the AUTOLOAD stuff should not be the default, it should
1391# only be activated on explicit demand by user.
1392
1393sub values {
1394 my $self = shift;
1395 my $data = shift || return;
1396 puke "Argument to ", __PACKAGE__, "->values must be a \\%hash"
1397 unless ref $data eq 'HASH';
bab725ce 1398
1399 my @all_bind;
ca4f826a 1400 foreach my $k (sort keys %$data) {
bab725ce 1401 my $v = $data->{$k};
1402 $self->_SWITCH_refkind($v, {
9d48860e 1403 ARRAYREF => sub {
bab725ce 1404 if ($self->{array_datatypes}) { # array datatype
1405 push @all_bind, $self->_bindtype($k, $v);
1406 }
1407 else { # literal SQL with bind
1408 my ($sql, @bind) = @$v;
1409 $self->_assert_bindval_matches_bindtype(@bind);
1410 push @all_bind, @bind;
1411 }
1412 },
1413 ARRAYREFREF => sub { # literal SQL with bind
1414 my ($sql, @bind) = @${$v};
1415 $self->_assert_bindval_matches_bindtype(@bind);
1416 push @all_bind, @bind;
1417 },
1418 SCALARREF => sub { # literal SQL without bind
1419 },
1420 SCALAR_or_UNDEF => sub {
1421 push @all_bind, $self->_bindtype($k, $v);
1422 },
1423 });
1424 }
1425
1426 return @all_bind;
96449e8e 1427}
1428
1429sub generate {
1430 my $self = shift;
1431
1432 my(@sql, @sqlq, @sqlv);
1433
1434 for (@_) {
1435 my $ref = ref $_;
1436 if ($ref eq 'HASH') {
1437 for my $k (sort keys %$_) {
1438 my $v = $_->{$k};
1439 my $r = ref $v;
1440 my $label = $self->_quote($k);
1441 if ($r eq 'ARRAY') {
fe3ae272 1442 # literal SQL with bind
1443 my ($sql, @bind) = @$v;
1444 $self->_assert_bindval_matches_bindtype(@bind);
96449e8e 1445 push @sqlq, "$label = $sql";
fe3ae272 1446 push @sqlv, @bind;
96449e8e 1447 } elsif ($r eq 'SCALAR') {
fe3ae272 1448 # literal SQL without bind
96449e8e 1449 push @sqlq, "$label = $$v";
9d48860e 1450 } else {
96449e8e 1451 push @sqlq, "$label = ?";
1452 push @sqlv, $self->_bindtype($k, $v);
1453 }
1454 }
1455 push @sql, $self->_sqlcase('set'), join ', ', @sqlq;
1456 } elsif ($ref eq 'ARRAY') {
1457 # unlike insert(), assume these are ONLY the column names, i.e. for SQL
1458 for my $v (@$_) {
1459 my $r = ref $v;
fe3ae272 1460 if ($r eq 'ARRAY') { # literal SQL with bind
1461 my ($sql, @bind) = @$v;
1462 $self->_assert_bindval_matches_bindtype(@bind);
1463 push @sqlq, $sql;
1464 push @sqlv, @bind;
1465 } elsif ($r eq 'SCALAR') { # literal SQL without bind
96449e8e 1466 # embedded literal SQL
1467 push @sqlq, $$v;
9d48860e 1468 } else {
96449e8e 1469 push @sqlq, '?';
1470 push @sqlv, $v;
1471 }
1472 }
1473 push @sql, '(' . join(', ', @sqlq) . ')';
1474 } elsif ($ref eq 'SCALAR') {
1475 # literal SQL
1476 push @sql, $$_;
1477 } else {
1478 # strings get case twiddled
1479 push @sql, $self->_sqlcase($_);
1480 }
1481 }
1482
1483 my $sql = join ' ', @sql;
1484
1485 # this is pretty tricky
1486 # if ask for an array, return ($stmt, @bind)
1487 # otherwise, s/?/shift @sqlv/ to put it inline
1488 if (wantarray) {
1489 return ($sql, @sqlv);
1490 } else {
1491 1 while $sql =~ s/\?/my $d = shift(@sqlv);
1492 ref $d ? $d->[1] : $d/e;
1493 return $sql;
1494 }
1495}
1496
1497
1498sub DESTROY { 1 }
1499
1500sub AUTOLOAD {
1501 # This allows us to check for a local, then _form, attr
1502 my $self = shift;
1503 my($name) = $AUTOLOAD =~ /.*::(.+)/;
1504 return $self->generate($name, @_);
1505}
1506
15071;
1508
1509
1510
1511__END__
32eab2da 1512
1513=head1 NAME
1514
1515SQL::Abstract - Generate SQL from Perl data structures
1516
1517=head1 SYNOPSIS
1518
1519 use SQL::Abstract;
1520
1521 my $sql = SQL::Abstract->new;
1522
85783f3c 1523 my($stmt, @bind) = $sql->select($source, \@fields, \%where, $order);
32eab2da 1524
1525 my($stmt, @bind) = $sql->insert($table, \%fieldvals || \@values);
1526
1527 my($stmt, @bind) = $sql->update($table, \%fieldvals, \%where);
1528
1529 my($stmt, @bind) = $sql->delete($table, \%where);
1530
1531 # Then, use these in your DBI statements
1532 my $sth = $dbh->prepare($stmt);
1533 $sth->execute(@bind);
1534
1535 # Just generate the WHERE clause
85783f3c 1536 my($stmt, @bind) = $sql->where(\%where, $order);
32eab2da 1537
1538 # Return values in the same order, for hashed queries
1539 # See PERFORMANCE section for more details
1540 my @bind = $sql->values(\%fieldvals);
1541
1542=head1 DESCRIPTION
1543
1544This module was inspired by the excellent L<DBIx::Abstract>.
1545However, in using that module I found that what I really wanted
1546to do was generate SQL, but still retain complete control over my
1547statement handles and use the DBI interface. So, I set out to
1548create an abstract SQL generation module.
1549
1550While based on the concepts used by L<DBIx::Abstract>, there are
1551several important differences, especially when it comes to WHERE
1552clauses. I have modified the concepts used to make the SQL easier
1553to generate from Perl data structures and, IMO, more intuitive.
1554The underlying idea is for this module to do what you mean, based
1555on the data structures you provide it. The big advantage is that
1556you don't have to modify your code every time your data changes,
1557as this module figures it out.
1558
1559To begin with, an SQL INSERT is as easy as just specifying a hash
1560of C<key=value> pairs:
1561
1562 my %data = (
1563 name => 'Jimbo Bobson',
1564 phone => '123-456-7890',
1565 address => '42 Sister Lane',
1566 city => 'St. Louis',
1567 state => 'Louisiana',
1568 );
1569
1570The SQL can then be generated with this:
1571
1572 my($stmt, @bind) = $sql->insert('people', \%data);
1573
1574Which would give you something like this:
1575
1576 $stmt = "INSERT INTO people
1577 (address, city, name, phone, state)
1578 VALUES (?, ?, ?, ?, ?)";
1579 @bind = ('42 Sister Lane', 'St. Louis', 'Jimbo Bobson',
1580 '123-456-7890', 'Louisiana');
1581
1582These are then used directly in your DBI code:
1583
1584 my $sth = $dbh->prepare($stmt);
1585 $sth->execute(@bind);
1586
96449e8e 1587=head2 Inserting and Updating Arrays
1588
1589If your database has array types (like for example Postgres),
1590activate the special option C<< array_datatypes => 1 >>
9d48860e 1591when creating the C<SQL::Abstract> object.
96449e8e 1592Then you may use an arrayref to insert and update database array types:
1593
1594 my $sql = SQL::Abstract->new(array_datatypes => 1);
1595 my %data = (
1596 planets => [qw/Mercury Venus Earth Mars/]
1597 );
9d48860e 1598
96449e8e 1599 my($stmt, @bind) = $sql->insert('solar_system', \%data);
1600
1601This results in:
1602
1603 $stmt = "INSERT INTO solar_system (planets) VALUES (?)"
1604
1605 @bind = (['Mercury', 'Venus', 'Earth', 'Mars']);
1606
1607
1608=head2 Inserting and Updating SQL
1609
1610In order to apply SQL functions to elements of your C<%data> you may
1611specify a reference to an arrayref for the given hash value. For example,
1612if you need to execute the Oracle C<to_date> function on a value, you can
1613say something like this:
32eab2da 1614
1615 my %data = (
1616 name => 'Bill',
3ae1c5e2 1617 date_entered => \[ "to_date(?,'MM/DD/YYYY')", "03/02/2003" ],
9d48860e 1618 );
32eab2da 1619
1620The first value in the array is the actual SQL. Any other values are
1621optional and would be included in the bind values array. This gives
1622you:
1623
1624 my($stmt, @bind) = $sql->insert('people', \%data);
1625
9d48860e 1626 $stmt = "INSERT INTO people (name, date_entered)
32eab2da 1627 VALUES (?, to_date(?,'MM/DD/YYYY'))";
1628 @bind = ('Bill', '03/02/2003');
1629
1630An UPDATE is just as easy, all you change is the name of the function:
1631
1632 my($stmt, @bind) = $sql->update('people', \%data);
1633
1634Notice that your C<%data> isn't touched; the module will generate
1635the appropriately quirky SQL for you automatically. Usually you'll
1636want to specify a WHERE clause for your UPDATE, though, which is
1637where handling C<%where> hashes comes in handy...
1638
96449e8e 1639=head2 Complex where statements
1640
32eab2da 1641This module can generate pretty complicated WHERE statements
1642easily. For example, simple C<key=value> pairs are taken to mean
1643equality, and if you want to see if a field is within a set
1644of values, you can use an arrayref. Let's say we wanted to
1645SELECT some data based on this criteria:
1646
1647 my %where = (
1648 requestor => 'inna',
1649 worker => ['nwiger', 'rcwe', 'sfz'],
1650 status => { '!=', 'completed' }
1651 );
1652
1653 my($stmt, @bind) = $sql->select('tickets', '*', \%where);
1654
1655The above would give you something like this:
1656
1657 $stmt = "SELECT * FROM tickets WHERE
1658 ( requestor = ? ) AND ( status != ? )
1659 AND ( worker = ? OR worker = ? OR worker = ? )";
1660 @bind = ('inna', 'completed', 'nwiger', 'rcwe', 'sfz');
1661
1662Which you could then use in DBI code like so:
1663
1664 my $sth = $dbh->prepare($stmt);
1665 $sth->execute(@bind);
1666
1667Easy, eh?
1668
0da0fe34 1669=head1 METHODS
32eab2da 1670
13cc86af 1671The methods are simple. There's one for every major SQL operation,
32eab2da 1672and a constructor you use first. The arguments are specified in a
13cc86af 1673similar order for each method (table, then fields, then a where
32eab2da 1674clause) to try and simplify things.
1675
32eab2da 1676=head2 new(option => 'value')
1677
1678The C<new()> function takes a list of options and values, and returns
1679a new B<SQL::Abstract> object which can then be used to generate SQL
1680through the methods below. The options accepted are:
1681
1682=over
1683
1684=item case
1685
1686If set to 'lower', then SQL will be generated in all lowercase. By
1687default SQL is generated in "textbook" case meaning something like:
1688
1689 SELECT a_field FROM a_table WHERE some_field LIKE '%someval%'
1690
96449e8e 1691Any setting other than 'lower' is ignored.
1692
32eab2da 1693=item cmp
1694
1695This determines what the default comparison operator is. By default
1696it is C<=>, meaning that a hash like this:
1697
1698 %where = (name => 'nwiger', email => 'nate@wiger.org');
1699
1700Will generate SQL like this:
1701
1702 WHERE name = 'nwiger' AND email = 'nate@wiger.org'
1703
1704However, you may want loose comparisons by default, so if you set
1705C<cmp> to C<like> you would get SQL such as:
1706
1707 WHERE name like 'nwiger' AND email like 'nate@wiger.org'
1708
3af02ccb 1709You can also override the comparison on an individual basis - see
32eab2da 1710the huge section on L</"WHERE CLAUSES"> at the bottom.
1711
96449e8e 1712=item sqltrue, sqlfalse
1713
1714Expressions for inserting boolean values within SQL statements.
6e0c6552 1715By default these are C<1=1> and C<1=0>. They are used
1716by the special operators C<-in> and C<-not_in> for generating
1717correct SQL even when the argument is an empty array (see below).
96449e8e 1718
32eab2da 1719=item logic
1720
1721This determines the default logical operator for multiple WHERE
7cac25e6 1722statements in arrays or hashes. If absent, the default logic is "or"
1723for arrays, and "and" for hashes. This means that a WHERE
32eab2da 1724array of the form:
1725
1726 @where = (
9d48860e 1727 event_date => {'>=', '2/13/99'},
1728 event_date => {'<=', '4/24/03'},
32eab2da 1729 );
1730
7cac25e6 1731will generate SQL like this:
32eab2da 1732
1733 WHERE event_date >= '2/13/99' OR event_date <= '4/24/03'
1734
1735This is probably not what you want given this query, though (look
1736at the dates). To change the "OR" to an "AND", simply specify:
1737
1738 my $sql = SQL::Abstract->new(logic => 'and');
1739
1740Which will change the above C<WHERE> to:
1741
1742 WHERE event_date >= '2/13/99' AND event_date <= '4/24/03'
1743
96449e8e 1744The logic can also be changed locally by inserting
be21dde3 1745a modifier in front of an arrayref:
96449e8e 1746
9d48860e 1747 @where = (-and => [event_date => {'>=', '2/13/99'},
7cac25e6 1748 event_date => {'<=', '4/24/03'} ]);
96449e8e 1749
1750See the L</"WHERE CLAUSES"> section for explanations.
1751
32eab2da 1752=item convert
1753
1754This will automatically convert comparisons using the specified SQL
1755function for both column and value. This is mostly used with an argument
1756of C<upper> or C<lower>, so that the SQL will have the effect of
1757case-insensitive "searches". For example, this:
1758
1759 $sql = SQL::Abstract->new(convert => 'upper');
1760 %where = (keywords => 'MaKe iT CAse inSeNSItive');
1761
1762Will turn out the following SQL:
1763
1764 WHERE upper(keywords) like upper('MaKe iT CAse inSeNSItive')
1765
1766The conversion can be C<upper()>, C<lower()>, or any other SQL function
1767that can be applied symmetrically to fields (actually B<SQL::Abstract> does
1768not validate this option; it will just pass through what you specify verbatim).
1769
1770=item bindtype
1771
1772This is a kludge because many databases suck. For example, you can't
1773just bind values using DBI's C<execute()> for Oracle C<CLOB> or C<BLOB> fields.
1774Instead, you have to use C<bind_param()>:
1775
1776 $sth->bind_param(1, 'reg data');
1777 $sth->bind_param(2, $lots, {ora_type => ORA_CLOB});
1778
1779The problem is, B<SQL::Abstract> will normally just return a C<@bind> array,
1780which loses track of which field each slot refers to. Fear not.
1781
1782If you specify C<bindtype> in new, you can determine how C<@bind> is returned.
1783Currently, you can specify either C<normal> (default) or C<columns>. If you
1784specify C<columns>, you will get an array that looks like this:
1785
1786 my $sql = SQL::Abstract->new(bindtype => 'columns');
1787 my($stmt, @bind) = $sql->insert(...);
1788
1789 @bind = (
1790 [ 'column1', 'value1' ],
1791 [ 'column2', 'value2' ],
1792 [ 'column3', 'value3' ],
1793 );
1794
1795You can then iterate through this manually, using DBI's C<bind_param()>.
e3f9dff4 1796
32eab2da 1797 $sth->prepare($stmt);
1798 my $i = 1;
1799 for (@bind) {
1800 my($col, $data) = @$_;
1801 if ($col eq 'details' || $col eq 'comments') {
1802 $sth->bind_param($i, $data, {ora_type => ORA_CLOB});
1803 } elsif ($col eq 'image') {
1804 $sth->bind_param($i, $data, {ora_type => ORA_BLOB});
1805 } else {
1806 $sth->bind_param($i, $data);
1807 }
1808 $i++;
1809 }
1810 $sth->execute; # execute without @bind now
1811
1812Now, why would you still use B<SQL::Abstract> if you have to do this crap?
1813Basically, the advantage is still that you don't have to care which fields
1814are or are not included. You could wrap that above C<for> loop in a simple
1815sub called C<bind_fields()> or something and reuse it repeatedly. You still
1816get a layer of abstraction over manual SQL specification.
1817
3ae1c5e2 1818Note that if you set L</bindtype> to C<columns>, the C<\[ $sql, @bind ]>
deb148a2 1819construct (see L</Literal SQL with placeholders and bind values (subqueries)>)
1820will expect the bind values in this format.
1821
32eab2da 1822=item quote_char
1823
1824This is the character that a table or column name will be quoted
9d48860e 1825with. By default this is an empty string, but you could set it to
32eab2da 1826the character C<`>, to generate SQL like this:
1827
1828 SELECT `a_field` FROM `a_table` WHERE `some_field` LIKE '%someval%'
1829
96449e8e 1830Alternatively, you can supply an array ref of two items, the first being the left
1831hand quote character, and the second the right hand quote character. For
1832example, you could supply C<['[',']']> for SQL Server 2000 compliant quotes
1833that generates SQL like this:
1834
1835 SELECT [a_field] FROM [a_table] WHERE [some_field] LIKE '%someval%'
1836
9d48860e 1837Quoting is useful if you have tables or columns names that are reserved
96449e8e 1838words in your database's SQL dialect.
32eab2da 1839
46be4313 1840=item escape_char
1841
1842This is the character that will be used to escape L</quote_char>s appearing
1843in an identifier before it has been quoted.
1844
80790166 1845The parameter default in case of a single L</quote_char> character is the quote
46be4313 1846character itself.
1847
1848When opening-closing-style quoting is used (L</quote_char> is an arrayref)
9de2bd86 1849this parameter defaults to the B<closing (right)> L</quote_char>. Occurrences
46be4313 1850of the B<opening (left)> L</quote_char> within the identifier are currently left
1851untouched. The default for opening-closing-style quotes may change in future
1852versions, thus you are B<strongly encouraged> to specify the escape character
1853explicitly.
1854
32eab2da 1855=item name_sep
1856
1857This is the character that separates a table and column name. It is
1858necessary to specify this when the C<quote_char> option is selected,
1859so that tables and column names can be individually quoted like this:
1860
1861 SELECT `table`.`one_field` FROM `table` WHERE `table`.`other_field` = 1
1862
b6251592 1863=item injection_guard
1864
1865A regular expression C<qr/.../> that is applied to any C<-function> and unquoted
1866column name specified in a query structure. This is a safety mechanism to avoid
1867injection attacks when mishandling user input e.g.:
1868
1869 my %condition_as_column_value_pairs = get_values_from_user();
1870 $sqla->select( ... , \%condition_as_column_value_pairs );
1871
1872If the expression matches an exception is thrown. Note that literal SQL
1873supplied via C<\'...'> or C<\['...']> is B<not> checked in any way.
1874
1875Defaults to checking for C<;> and the C<GO> keyword (TransactSQL)
1876
96449e8e 1877=item array_datatypes
32eab2da 1878
9d48860e 1879When this option is true, arrayrefs in INSERT or UPDATE are
1880interpreted as array datatypes and are passed directly
96449e8e 1881to the DBI layer.
1882When this option is false, arrayrefs are interpreted
1883as literal SQL, just like refs to arrayrefs
1884(but this behavior is for backwards compatibility; when writing
1885new queries, use the "reference to arrayref" syntax
1886for literal SQL).
32eab2da 1887
32eab2da 1888
96449e8e 1889=item special_ops
32eab2da 1890
9d48860e 1891Takes a reference to a list of "special operators"
96449e8e 1892to extend the syntax understood by L<SQL::Abstract>.
1893See section L</"SPECIAL OPERATORS"> for details.
32eab2da 1894
59f23b3d 1895=item unary_ops
1896
9d48860e 1897Takes a reference to a list of "unary operators"
59f23b3d 1898to extend the syntax understood by L<SQL::Abstract>.
1899See section L</"UNARY OPERATORS"> for details.
1900
32eab2da 1901
32eab2da 1902
96449e8e 1903=back
32eab2da 1904
02288357 1905=head2 insert($table, \@values || \%fieldvals, \%options)
32eab2da 1906
1907This is the simplest function. You simply give it a table name
1908and either an arrayref of values or hashref of field/value pairs.
1909It returns an SQL INSERT statement and a list of bind values.
96449e8e 1910See the sections on L</"Inserting and Updating Arrays"> and
1911L</"Inserting and Updating SQL"> for information on how to insert
1912with those data types.
32eab2da 1913
02288357 1914The optional C<\%options> hash reference may contain additional
1915options to generate the insert SQL. Currently supported options
1916are:
1917
1918=over 4
1919
1920=item returning
1921
1922Takes either a scalar of raw SQL fields, or an array reference of
1923field names, and adds on an SQL C<RETURNING> statement at the end.
1924This allows you to return data generated by the insert statement
1925(such as row IDs) without performing another C<SELECT> statement.
1926Note, however, this is not part of the SQL standard and may not
1927be supported by all database engines.
1928
1929=back
1930
95904db5 1931=head2 update($table, \%fieldvals, \%where, \%options)
32eab2da 1932
1933This takes a table, hashref of field/value pairs, and an optional
86298391 1934hashref L<WHERE clause|/WHERE CLAUSES>. It returns an SQL UPDATE function and a list
32eab2da 1935of bind values.
96449e8e 1936See the sections on L</"Inserting and Updating Arrays"> and
1937L</"Inserting and Updating SQL"> for information on how to insert
1938with those data types.
32eab2da 1939
95904db5 1940The optional C<\%options> hash reference may contain additional
1941options to generate the update SQL. Currently supported options
1942are:
1943
1944=over 4
1945
1946=item returning
1947
1948See the C<returning> option to
1949L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
1950
1951=back
1952
96449e8e 1953=head2 select($source, $fields, $where, $order)
32eab2da 1954
9d48860e 1955This returns a SQL SELECT statement and associated list of bind values, as
be21dde3 1956specified by the arguments:
32eab2da 1957
96449e8e 1958=over
32eab2da 1959
96449e8e 1960=item $source
32eab2da 1961
9d48860e 1962Specification of the 'FROM' part of the statement.
96449e8e 1963The argument can be either a plain scalar (interpreted as a table
1964name, will be quoted), or an arrayref (interpreted as a list
1965of table names, joined by commas, quoted), or a scalarref
063097a3 1966(literal SQL, not quoted).
32eab2da 1967
96449e8e 1968=item $fields
32eab2da 1969
9d48860e 1970Specification of the list of fields to retrieve from
96449e8e 1971the source.
1972The argument can be either an arrayref (interpreted as a list
9d48860e 1973of field names, will be joined by commas and quoted), or a
96449e8e 1974plain scalar (literal SQL, not quoted).
521647e7 1975Please observe that this API is not as flexible as that of
1976the first argument C<$source>, for backwards compatibility reasons.
32eab2da 1977
96449e8e 1978=item $where
32eab2da 1979
96449e8e 1980Optional argument to specify the WHERE part of the query.
1981The argument is most often a hashref, but can also be
9d48860e 1982an arrayref or plain scalar --
96449e8e 1983see section L<WHERE clause|/"WHERE CLAUSES"> for details.
32eab2da 1984
96449e8e 1985=item $order
32eab2da 1986
96449e8e 1987Optional argument to specify the ORDER BY part of the query.
9d48860e 1988The argument can be a scalar, a hashref or an arrayref
96449e8e 1989-- see section L<ORDER BY clause|/"ORDER BY CLAUSES">
1990for details.
32eab2da 1991
96449e8e 1992=back
32eab2da 1993
32eab2da 1994
85327cd5 1995=head2 delete($table, \%where, \%options)
32eab2da 1996
86298391 1997This takes a table name and optional hashref L<WHERE clause|/WHERE CLAUSES>.
32eab2da 1998It returns an SQL DELETE statement and list of bind values.
1999
85327cd5 2000The optional C<\%options> hash reference may contain additional
2001options to generate the delete SQL. Currently supported options
2002are:
2003
2004=over 4
2005
2006=item returning
2007
2008See the C<returning> option to
2009L<insert|/insert($table, \@values || \%fieldvals, \%options)>.
2010
2011=back
2012
85783f3c 2013=head2 where(\%where, $order)
32eab2da 2014
2015This is used to generate just the WHERE clause. For example,
2016if you have an arbitrary data structure and know what the
2017rest of your SQL is going to look like, but want an easy way
2018to produce a WHERE clause, use this. It returns an SQL WHERE
2019clause and list of bind values.
2020
32eab2da 2021
2022=head2 values(\%data)
2023
2024This just returns the values from the hash C<%data>, in the same
2025order that would be returned from any of the other above queries.
2026Using this allows you to markedly speed up your queries if you
2027are affecting lots of rows. See below under the L</"PERFORMANCE"> section.
2028
32eab2da 2029=head2 generate($any, 'number', $of, \@data, $struct, \%types)
2030
2031Warning: This is an experimental method and subject to change.
2032
2033This returns arbitrarily generated SQL. It's a really basic shortcut.
2034It will return two different things, depending on return context:
2035
2036 my($stmt, @bind) = $sql->generate('create table', \$table, \@fields);
2037 my $stmt_and_val = $sql->generate('create table', \$table, \@fields);
2038
2039These would return the following:
2040
2041 # First calling form
2042 $stmt = "CREATE TABLE test (?, ?)";
2043 @bind = (field1, field2);
2044
2045 # Second calling form
2046 $stmt_and_val = "CREATE TABLE test (field1, field2)";
2047
2048Depending on what you're trying to do, it's up to you to choose the correct
2049format. In this example, the second form is what you would want.
2050
2051By the same token:
2052
2053 $sql->generate('alter session', { nls_date_format => 'MM/YY' });
2054
2055Might give you:
2056
2057 ALTER SESSION SET nls_date_format = 'MM/YY'
2058
2059You get the idea. Strings get their case twiddled, but everything
2060else remains verbatim.
2061
0da0fe34 2062=head1 EXPORTABLE FUNCTIONS
2063
2064=head2 is_plain_value
2065
2066Determines if the supplied argument is a plain value as understood by this
2067module:
2068
2069=over
2070
2071=item * The value is C<undef>
2072
2073=item * The value is a non-reference
2074
2075=item * The value is an object with stringification overloading
2076
2077=item * The value is of the form C<< { -value => $anything } >>
2078
2079=back
2080
9de2bd86 2081On failure returns C<undef>, on success returns a B<scalar> reference
966200cc 2082to the original supplied argument.
0da0fe34 2083
843a94b5 2084=over
2085
2086=item * Note
2087
2088The stringification overloading detection is rather advanced: it takes
2089into consideration not only the presence of a C<""> overload, but if that
2090fails also checks for enabled
2091L<autogenerated versions of C<"">|overload/Magic Autogeneration>, based
2092on either C<0+> or C<bool>.
2093
2094Unfortunately testing in the field indicates that this
2095detection B<< may tickle a latent bug in perl versions before 5.018 >>,
2096but only when very large numbers of stringifying objects are involved.
2097At the time of writing ( Sep 2014 ) there is no clear explanation of
2098the direct cause, nor is there a manageably small test case that reliably
2099reproduces the problem.
2100
2101If you encounter any of the following exceptions in B<random places within
2102your application stack> - this module may be to blame:
2103
2104 Operation "ne": no method found,
2105 left argument in overloaded package <something>,
2106 right argument in overloaded package <something>
2107
2108or perhaps even
2109
2110 Stub found while resolving method "???" overloading """" in package <something>
2111
2112If you fall victim to the above - please attempt to reduce the problem
2113to something that could be sent to the L<SQL::Abstract developers
1f490ae4 2114|DBIx::Class/GETTING HELP/SUPPORT>
843a94b5 2115(either publicly or privately). As a workaround in the meantime you can
2116set C<$ENV{SQLA_ISVALUE_IGNORE_AUTOGENERATED_STRINGIFICATION}> to a true
2117value, which will most likely eliminate your problem (at the expense of
2118not being able to properly detect exotic forms of stringification).
2119
2120This notice and environment variable will be removed in a future version,
2121as soon as the underlying problem is found and a reliable workaround is
2122devised.
2123
2124=back
2125
0da0fe34 2126=head2 is_literal_value
2127
2128Determines if the supplied argument is a literal value as understood by this
2129module:
2130
2131=over
2132
2133=item * C<\$sql_string>
2134
2135=item * C<\[ $sql_string, @bind_values ]>
2136
0da0fe34 2137=back
2138
9de2bd86 2139On failure returns C<undef>, on success returns an B<array> reference
966200cc 2140containing the unpacked version of the supplied literal SQL and bind values.
0da0fe34 2141
32eab2da 2142=head1 WHERE CLAUSES
2143
96449e8e 2144=head2 Introduction
2145
32eab2da 2146This module uses a variation on the idea from L<DBIx::Abstract>. It
2147is B<NOT>, repeat I<not> 100% compatible. B<The main logic of this
2148module is that things in arrays are OR'ed, and things in hashes
2149are AND'ed.>
2150
2151The easiest way to explain is to show lots of examples. After
2152each C<%where> hash shown, it is assumed you used:
2153
2154 my($stmt, @bind) = $sql->where(\%where);
2155
2156However, note that the C<%where> hash can be used directly in any
2157of the other functions as well, as described above.
2158
96449e8e 2159=head2 Key-value pairs
2160
32eab2da 2161So, let's get started. To begin, a simple hash:
2162
2163 my %where = (
2164 user => 'nwiger',
2165 status => 'completed'
2166 );
2167
2168Is converted to SQL C<key = val> statements:
2169
2170 $stmt = "WHERE user = ? AND status = ?";
2171 @bind = ('nwiger', 'completed');
2172
2173One common thing I end up doing is having a list of values that
2174a field can be in. To do this, simply specify a list inside of
2175an arrayref:
2176
2177 my %where = (
2178 user => 'nwiger',
2179 status => ['assigned', 'in-progress', 'pending'];
2180 );
2181
2182This simple code will create the following:
9d48860e 2183
32eab2da 2184 $stmt = "WHERE user = ? AND ( status = ? OR status = ? OR status = ? )";
2185 @bind = ('nwiger', 'assigned', 'in-progress', 'pending');
2186
9d48860e 2187A field associated to an empty arrayref will be considered a
7cac25e6 2188logical false and will generate 0=1.
8a68b5be 2189
b864ba9b 2190=head2 Tests for NULL values
2191
2192If the value part is C<undef> then this is converted to SQL <IS NULL>
2193
2194 my %where = (
2195 user => 'nwiger',
2196 status => undef,
2197 );
2198
2199becomes:
2200
2201 $stmt = "WHERE user = ? AND status IS NULL";
2202 @bind = ('nwiger');
2203
e9614080 2204To test if a column IS NOT NULL:
2205
2206 my %where = (
2207 user => 'nwiger',
2208 status => { '!=', undef },
2209 );
cc422895 2210
6e0c6552 2211=head2 Specific comparison operators
96449e8e 2212
32eab2da 2213If you want to specify a different type of operator for your comparison,
2214you can use a hashref for a given column:
2215
2216 my %where = (
2217 user => 'nwiger',
2218 status => { '!=', 'completed' }
2219 );
2220
2221Which would generate:
2222
2223 $stmt = "WHERE user = ? AND status != ?";
2224 @bind = ('nwiger', 'completed');
2225
2226To test against multiple values, just enclose the values in an arrayref:
2227
96449e8e 2228 status => { '=', ['assigned', 'in-progress', 'pending'] };
2229
f2d5020d 2230Which would give you:
96449e8e 2231
2232 "WHERE status = ? OR status = ? OR status = ?"
2233
2234
2235The hashref can also contain multiple pairs, in which case it is expanded
32eab2da 2236into an C<AND> of its elements:
2237
2238 my %where = (
2239 user => 'nwiger',
2240 status => { '!=', 'completed', -not_like => 'pending%' }
2241 );
2242
2243 # Or more dynamically, like from a form
2244 $where{user} = 'nwiger';
2245 $where{status}{'!='} = 'completed';
2246 $where{status}{'-not_like'} = 'pending%';
2247
2248 # Both generate this
2249 $stmt = "WHERE user = ? AND status != ? AND status NOT LIKE ?";
2250 @bind = ('nwiger', 'completed', 'pending%');
2251
96449e8e 2252
32eab2da 2253To get an OR instead, you can combine it with the arrayref idea:
2254
2255 my %where => (
2256 user => 'nwiger',
1a6f2a03 2257 priority => [ { '=', 2 }, { '>', 5 } ]
32eab2da 2258 );
2259
2260Which would generate:
2261
1a6f2a03 2262 $stmt = "WHERE ( priority = ? OR priority > ? ) AND user = ?";
2263 @bind = ('2', '5', 'nwiger');
32eab2da 2264
44b9e502 2265If you want to include literal SQL (with or without bind values), just use a
13cc86af 2266scalar reference or reference to an arrayref as the value:
44b9e502 2267
2268 my %where = (
2269 date_entered => { '>' => \["to_date(?, 'MM/DD/YYYY')", "11/26/2008"] },
2270 date_expires => { '<' => \"now()" }
2271 );
2272
2273Which would generate:
2274
13cc86af 2275 $stmt = "WHERE date_entered > to_date(?, 'MM/DD/YYYY') AND date_expires < now()";
44b9e502 2276 @bind = ('11/26/2008');
2277
96449e8e 2278
2279=head2 Logic and nesting operators
2280
2281In the example above,
2282there is a subtle trap if you want to say something like
32eab2da 2283this (notice the C<AND>):
2284
2285 WHERE priority != ? AND priority != ?
2286
2287Because, in Perl you I<can't> do this:
2288
13cc86af 2289 priority => { '!=' => 2, '!=' => 1 }
32eab2da 2290
2291As the second C<!=> key will obliterate the first. The solution
2292is to use the special C<-modifier> form inside an arrayref:
2293
9d48860e 2294 priority => [ -and => {'!=', 2},
96449e8e 2295 {'!=', 1} ]
2296
32eab2da 2297
2298Normally, these would be joined by C<OR>, but the modifier tells it
2299to use C<AND> instead. (Hint: You can use this in conjunction with the
2300C<logic> option to C<new()> in order to change the way your queries
2301work by default.) B<Important:> Note that the C<-modifier> goes
2302B<INSIDE> the arrayref, as an extra first element. This will
2303B<NOT> do what you think it might:
2304
2305 priority => -and => [{'!=', 2}, {'!=', 1}] # WRONG!
2306
2307Here is a quick list of equivalencies, since there is some overlap:
2308
2309 # Same
2310 status => {'!=', 'completed', 'not like', 'pending%' }
2311 status => [ -and => {'!=', 'completed'}, {'not like', 'pending%'}]
2312
2313 # Same
2314 status => {'=', ['assigned', 'in-progress']}
2315 status => [ -or => {'=', 'assigned'}, {'=', 'in-progress'}]
2316 status => [ {'=', 'assigned'}, {'=', 'in-progress'} ]
2317
e3f9dff4 2318
2319
be21dde3 2320=head2 Special operators: IN, BETWEEN, etc.
96449e8e 2321
32eab2da 2322You can also use the hashref format to compare a list of fields using the
2323C<IN> comparison operator, by specifying the list as an arrayref:
2324
2325 my %where = (
2326 status => 'completed',
2327 reportid => { -in => [567, 2335, 2] }
2328 );
2329
2330Which would generate:
2331
2332 $stmt = "WHERE status = ? AND reportid IN (?,?,?)";
2333 @bind = ('completed', '567', '2335', '2');
2334
9d48860e 2335The reverse operator C<-not_in> generates SQL C<NOT IN> and is used in
96449e8e 2336the same way.
2337
6e0c6552 2338If the argument to C<-in> is an empty array, 'sqlfalse' is generated
be21dde3 2339(by default: C<1=0>). Similarly, C<< -not_in => [] >> generates
2340'sqltrue' (by default: C<1=1>).
6e0c6552 2341
e41c3bdd 2342In addition to the array you can supply a chunk of literal sql or
2343literal sql with bind:
6e0c6552 2344
e41c3bdd 2345 my %where = {
2346 customer => { -in => \[
2347 'SELECT cust_id FROM cust WHERE balance > ?',
2348 2000,
2349 ],
2350 status => { -in => \'SELECT status_codes FROM states' },
2351 };
6e0c6552 2352
e41c3bdd 2353would generate:
2354
2355 $stmt = "WHERE (
2356 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
2357 AND status IN ( SELECT status_codes FROM states )
2358 )";
2359 @bind = ('2000');
2360
0dfd2442 2361Finally, if the argument to C<-in> is not a reference, it will be
2362treated as a single-element array.
e41c3bdd 2363
2364Another pair of operators is C<-between> and C<-not_between>,
96449e8e 2365used with an arrayref of two values:
32eab2da 2366
2367 my %where = (
2368 user => 'nwiger',
2369 completion_date => {
2370 -not_between => ['2002-10-01', '2003-02-06']
2371 }
2372 );
2373
2374Would give you:
2375
2376 WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
2377
e41c3bdd 2378Just like with C<-in> all plausible combinations of literal SQL
2379are possible:
2380
2381 my %where = {
2382 start0 => { -between => [ 1, 2 ] },
2383 start1 => { -between => \["? AND ?", 1, 2] },
2384 start2 => { -between => \"lower(x) AND upper(y)" },
9d48860e 2385 start3 => { -between => [
e41c3bdd 2386 \"lower(x)",
2387 \["upper(?)", 'stuff' ],
2388 ] },
2389 };
2390
2391Would give you:
2392
2393 $stmt = "WHERE (
2394 ( start0 BETWEEN ? AND ? )
2395 AND ( start1 BETWEEN ? AND ? )
2396 AND ( start2 BETWEEN lower(x) AND upper(y) )
2397 AND ( start3 BETWEEN lower(x) AND upper(?) )
2398 )";
2399 @bind = (1, 2, 1, 2, 'stuff');
2400
2401
9d48860e 2402These are the two builtin "special operators"; but the
be21dde3 2403list can be expanded: see section L</"SPECIAL OPERATORS"> below.
96449e8e 2404
59f23b3d 2405=head2 Unary operators: bool
97a920ef 2406
2407If you wish to test against boolean columns or functions within your
2408database you can use the C<-bool> and C<-not_bool> operators. For
2409example to test the column C<is_user> being true and the column
827bb0eb 2410C<is_enabled> being false you would use:-
97a920ef 2411
2412 my %where = (
2413 -bool => 'is_user',
2414 -not_bool => 'is_enabled',
2415 );
2416
2417Would give you:
2418
277b5d3f 2419 WHERE is_user AND NOT is_enabled
97a920ef 2420
0b604e9d 2421If a more complex combination is required, testing more conditions,
2422then you should use the and/or operators:-
2423
2424 my %where = (
2425 -and => [
2426 -bool => 'one',
23401b81 2427 -not_bool => { two=> { -rlike => 'bar' } },
2428 -not_bool => { three => [ { '=', 2 }, { '>', 5 } ] },
0b604e9d 2429 ],
2430 );
2431
2432Would give you:
2433
23401b81 2434 WHERE
2435 one
2436 AND
2437 (NOT two RLIKE ?)
2438 AND
2439 (NOT ( three = ? OR three > ? ))
97a920ef 2440
2441
107b72f1 2442=head2 Nested conditions, -and/-or prefixes
96449e8e 2443
32eab2da 2444So far, we've seen how multiple conditions are joined with a top-level
2445C<AND>. We can change this by putting the different conditions we want in
2446hashes and then putting those hashes in an array. For example:
2447
2448 my @where = (
2449 {
2450 user => 'nwiger',
2451 status => { -like => ['pending%', 'dispatched'] },
2452 },
2453 {
2454 user => 'robot',
2455 status => 'unassigned',
2456 }
2457 );
2458
2459This data structure would create the following:
2460
2461 $stmt = "WHERE ( user = ? AND ( status LIKE ? OR status LIKE ? ) )
2462 OR ( user = ? AND status = ? ) )";
2463 @bind = ('nwiger', 'pending', 'dispatched', 'robot', 'unassigned');
2464
107b72f1 2465
48d9f5f8 2466Clauses in hashrefs or arrayrefs can be prefixed with an C<-and> or C<-or>
be21dde3 2467to change the logic inside:
32eab2da 2468
2469 my @where = (
2470 -and => [
2471 user => 'nwiger',
48d9f5f8 2472 [
2473 -and => [ workhrs => {'>', 20}, geo => 'ASIA' ],
2474 -or => { workhrs => {'<', 50}, geo => 'EURO' },
32eab2da 2475 ],
2476 ],
2477 );
2478
2479That would yield:
2480
13cc86af 2481 $stmt = "WHERE ( user = ?
2482 AND ( ( workhrs > ? AND geo = ? )
2483 OR ( workhrs < ? OR geo = ? ) ) )";
2484 @bind = ('nwiger', '20', 'ASIA', '50', 'EURO');
107b72f1 2485
cc422895 2486=head3 Algebraic inconsistency, for historical reasons
107b72f1 2487
7cac25e6 2488C<Important note>: when connecting several conditions, the C<-and->|C<-or>
2489operator goes C<outside> of the nested structure; whereas when connecting
2490several constraints on one column, the C<-and> operator goes
be21dde3 2491C<inside> the arrayref. Here is an example combining both features:
7cac25e6 2492
2493 my @where = (
2494 -and => [a => 1, b => 2],
2495 -or => [c => 3, d => 4],
2496 e => [-and => {-like => 'foo%'}, {-like => '%bar'} ]
2497 )
2498
2499yielding
2500
9d48860e 2501 WHERE ( ( ( a = ? AND b = ? )
2502 OR ( c = ? OR d = ? )
7cac25e6 2503 OR ( e LIKE ? AND e LIKE ? ) ) )
2504
107b72f1 2505This difference in syntax is unfortunate but must be preserved for
be21dde3 2506historical reasons. So be careful: the two examples below would
107b72f1 2507seem algebraically equivalent, but they are not
2508
a948b1fe 2509 { col => [ -and =>
2510 { -like => 'foo%' },
2511 { -like => '%bar' },
2512 ] }
be21dde3 2513 # yields: WHERE ( ( col LIKE ? AND col LIKE ? ) )
107b72f1 2514
a948b1fe 2515 [ -and =>
2516 { col => { -like => 'foo%' } },
2517 { col => { -like => '%bar' } },
2518 ]
be21dde3 2519 # yields: WHERE ( ( col LIKE ? OR col LIKE ? ) )
107b72f1 2520
7cac25e6 2521
cc422895 2522=head2 Literal SQL and value type operators
96449e8e 2523
cc422895 2524The basic premise of SQL::Abstract is that in WHERE specifications the "left
2525side" is a column name and the "right side" is a value (normally rendered as
2526a placeholder). This holds true for both hashrefs and arrayref pairs as you
2527see in the L</WHERE CLAUSES> examples above. Sometimes it is necessary to
2528alter this behavior. There are several ways of doing so.
e9614080 2529
cc422895 2530=head3 -ident
2531
2532This is a virtual operator that signals the string to its right side is an
2533identifier (a column name) and not a value. For example to compare two
2534columns you would write:
32eab2da 2535
e9614080 2536 my %where = (
2537 priority => { '<', 2 },
cc422895 2538 requestor => { -ident => 'submitter' },
e9614080 2539 );
2540
2541which creates:
2542
2543 $stmt = "WHERE priority < ? AND requestor = submitter";
2544 @bind = ('2');
2545
cc422895 2546If you are maintaining legacy code you may see a different construct as
2547described in L</Deprecated usage of Literal SQL>, please use C<-ident> in new
2548code.
2549
2550=head3 -value
e9614080 2551
cc422895 2552This is a virtual operator that signals that the construct to its right side
2553is a value to be passed to DBI. This is for example necessary when you want
2554to write a where clause against an array (for RDBMS that support such
2555datatypes). For example:
e9614080 2556
32eab2da 2557 my %where = (
cc422895 2558 array => { -value => [1, 2, 3] }
32eab2da 2559 );
2560
cc422895 2561will result in:
32eab2da 2562
cc422895 2563 $stmt = 'WHERE array = ?';
2564 @bind = ([1, 2, 3]);
32eab2da 2565
cc422895 2566Note that if you were to simply say:
32eab2da 2567
2568 my %where = (
cc422895 2569 array => [1, 2, 3]
32eab2da 2570 );
2571
3af02ccb 2572the result would probably not be what you wanted:
cc422895 2573
2574 $stmt = 'WHERE array = ? OR array = ? OR array = ?';
2575 @bind = (1, 2, 3);
2576
2577=head3 Literal SQL
96449e8e 2578
cc422895 2579Finally, sometimes only literal SQL will do. To include a random snippet
2580of SQL verbatim, you specify it as a scalar reference. Consider this only
2581as a last resort. Usually there is a better way. For example:
96449e8e 2582
2583 my %where = (
cc422895 2584 priority => { '<', 2 },
2585 requestor => { -in => \'(SELECT name FROM hitmen)' },
96449e8e 2586 );
2587
cc422895 2588Would create:
96449e8e 2589
cc422895 2590 $stmt = "WHERE priority < ? AND requestor IN (SELECT name FROM hitmen)"
2591 @bind = (2);
2592
2593Note that in this example, you only get one bind parameter back, since
2594the verbatim SQL is passed as part of the statement.
2595
2596=head4 CAVEAT
2597
2598 Never use untrusted input as a literal SQL argument - this is a massive
2599 security risk (there is no way to check literal snippets for SQL
2600 injections and other nastyness). If you need to deal with untrusted input
2601 use literal SQL with placeholders as described next.
96449e8e 2602
cc422895 2603=head3 Literal SQL with placeholders and bind values (subqueries)
96449e8e 2604
2605If the literal SQL to be inserted has placeholders and bind values,
2606use a reference to an arrayref (yes this is a double reference --
2607not so common, but perfectly legal Perl). For example, to find a date
2608in Postgres you can use something like this:
2609
2610 my %where = (
3ae1c5e2 2611 date_column => \[ "= date '2008-09-30' - ?::integer", 10 ]
96449e8e 2612 )
2613
2614This would create:
2615
d2a8fe1a 2616 $stmt = "WHERE ( date_column = date '2008-09-30' - ?::integer )"
96449e8e 2617 @bind = ('10');
2618
deb148a2 2619Note that you must pass the bind values in the same format as they are returned
85783f3c 2620by L<where|/where(\%where, $order)>. This means that if you set L</bindtype>
1f490ae4 2621to C<columns>, you must provide the bind values in the
2622C<< [ column_meta => value ] >> format, where C<column_meta> is an opaque
2623scalar value; most commonly the column name, but you can use any scalar value
2624(including references and blessed references), L<SQL::Abstract> will simply
2625pass it through intact. So if C<bindtype> is set to C<columns> the above
2626example will look like:
deb148a2 2627
2628 my %where = (
3ae1c5e2 2629 date_column => \[ "= date '2008-09-30' - ?::integer", [ {} => 10 ] ]
deb148a2 2630 )
96449e8e 2631
2632Literal SQL is especially useful for nesting parenthesized clauses in the
be21dde3 2633main SQL query. Here is a first example:
96449e8e 2634
2635 my ($sub_stmt, @sub_bind) = ("SELECT c1 FROM t1 WHERE c2 < ? AND c3 LIKE ?",
2636 100, "foo%");
2637 my %where = (
2638 foo => 1234,
2639 bar => \["IN ($sub_stmt)" => @sub_bind],
2640 );
2641
be21dde3 2642This yields:
96449e8e 2643
9d48860e 2644 $stmt = "WHERE (foo = ? AND bar IN (SELECT c1 FROM t1
96449e8e 2645 WHERE c2 < ? AND c3 LIKE ?))";
2646 @bind = (1234, 100, "foo%");
2647
9d48860e 2648Other subquery operators, like for example C<"E<gt> ALL"> or C<"NOT IN">,
96449e8e 2649are expressed in the same way. Of course the C<$sub_stmt> and
9d48860e 2650its associated bind values can be generated through a former call
96449e8e 2651to C<select()> :
2652
2653 my ($sub_stmt, @sub_bind)
9d48860e 2654 = $sql->select("t1", "c1", {c2 => {"<" => 100},
96449e8e 2655 c3 => {-like => "foo%"}});
2656 my %where = (
2657 foo => 1234,
2658 bar => \["> ALL ($sub_stmt)" => @sub_bind],
2659 );
2660
2661In the examples above, the subquery was used as an operator on a column;
9d48860e 2662but the same principle also applies for a clause within the main C<%where>
be21dde3 2663hash, like an EXISTS subquery:
96449e8e 2664
9d48860e 2665 my ($sub_stmt, @sub_bind)
96449e8e 2666 = $sql->select("t1", "*", {c1 => 1, c2 => \"> t0.c0"});
48d9f5f8 2667 my %where = ( -and => [
96449e8e 2668 foo => 1234,
48d9f5f8 2669 \["EXISTS ($sub_stmt)" => @sub_bind],
2670 ]);
96449e8e 2671
2672which yields
2673
9d48860e 2674 $stmt = "WHERE (foo = ? AND EXISTS (SELECT * FROM t1
96449e8e 2675 WHERE c1 = ? AND c2 > t0.c0))";
2676 @bind = (1234, 1);
2677
2678
9d48860e 2679Observe that the condition on C<c2> in the subquery refers to
be21dde3 2680column C<t0.c0> of the main query: this is I<not> a bind
9d48860e 2681value, so we have to express it through a scalar ref.
96449e8e 2682Writing C<< c2 => {">" => "t0.c0"} >> would have generated
2683C<< c2 > ? >> with bind value C<"t0.c0"> ... not exactly
2684what we wanted here.
2685
96449e8e 2686Finally, here is an example where a subquery is used
2687for expressing unary negation:
2688
9d48860e 2689 my ($sub_stmt, @sub_bind)
96449e8e 2690 = $sql->where({age => [{"<" => 10}, {">" => 20}]});
2691 $sub_stmt =~ s/^ where //i; # don't want "WHERE" in the subclause
2692 my %where = (
2693 lname => {like => '%son%'},
48d9f5f8 2694 \["NOT ($sub_stmt)" => @sub_bind],
96449e8e 2695 );
2696
2697This yields
2698
2699 $stmt = "lname LIKE ? AND NOT ( age < ? OR age > ? )"
2700 @bind = ('%son%', 10, 20)
2701
cc422895 2702=head3 Deprecated usage of Literal SQL
2703
2704Below are some examples of archaic use of literal SQL. It is shown only as
2705reference for those who deal with legacy code. Each example has a much
2706better, cleaner and safer alternative that users should opt for in new code.
2707
2708=over
2709
2710=item *
2711
2712 my %where = ( requestor => \'IS NOT NULL' )
2713
2714 $stmt = "WHERE requestor IS NOT NULL"
2715
2716This used to be the way of generating NULL comparisons, before the handling
2717of C<undef> got formalized. For new code please use the superior syntax as
2718described in L</Tests for NULL values>.
96449e8e 2719
cc422895 2720=item *
2721
2722 my %where = ( requestor => \'= submitter' )
2723
2724 $stmt = "WHERE requestor = submitter"
2725
2726This used to be the only way to compare columns. Use the superior L</-ident>
2727method for all new code. For example an identifier declared in such a way
2728will be properly quoted if L</quote_char> is properly set, while the legacy
2729form will remain as supplied.
2730
2731=item *
2732
2733 my %where = ( is_ready => \"", completed => { '>', '2012-12-21' } )
2734
2735 $stmt = "WHERE completed > ? AND is_ready"
2736 @bind = ('2012-12-21')
2737
2738Using an empty string literal used to be the only way to express a boolean.
2739For all new code please use the much more readable
2740L<-bool|/Unary operators: bool> operator.
2741
2742=back
96449e8e 2743
2744=head2 Conclusion
2745
32eab2da 2746These pages could go on for a while, since the nesting of the data
2747structures this module can handle are pretty much unlimited (the
2748module implements the C<WHERE> expansion as a recursive function
2749internally). Your best bet is to "play around" with the module a
2750little to see how the data structures behave, and choose the best
2751format for your data based on that.
2752
2753And of course, all the values above will probably be replaced with
2754variables gotten from forms or the command line. After all, if you
2755knew everything ahead of time, you wouldn't have to worry about
2756dynamically-generating SQL and could just hardwire it into your
2757script.
2758
86298391 2759=head1 ORDER BY CLAUSES
2760
9d48860e 2761Some functions take an order by clause. This can either be a scalar (just a
18710f60 2762column name), a hashref of C<< { -desc => 'col' } >> or C<< { -asc => 'col' }
2763>>, a scalarref, an arrayref-ref, or an arrayref of any of the previous
2764forms. Examples:
1cfa1db3 2765
8c15b421 2766 Given | Will Generate
18710f60 2767 ---------------------------------------------------------------
8c15b421 2768 |
2769 'colA' | ORDER BY colA
2770 |
2771 [qw/colA colB/] | ORDER BY colA, colB
2772 |
2773 {-asc => 'colA'} | ORDER BY colA ASC
2774 |
2775 {-desc => 'colB'} | ORDER BY colB DESC
2776 |
2777 ['colA', {-asc => 'colB'}] | ORDER BY colA, colB ASC
2778 |
2779 { -asc => [qw/colA colB/] } | ORDER BY colA ASC, colB ASC
2780 |
2781 \'colA DESC' | ORDER BY colA DESC
2782 |
2783 \[ 'FUNC(colA, ?)', $x ] | ORDER BY FUNC(colA, ?)
2784 | /* ...with $x bound to ? */
2785 |
bd805d85 2786 [ | ORDER BY
2787 { -asc => 'colA' }, | colA ASC,
2788 { -desc => [qw/colB/] }, | colB DESC,
2789 { -asc => [qw/colC colD/] },| colC ASC, colD ASC,
2790 \'colE DESC', | colE DESC,
2791 \[ 'FUNC(colF, ?)', $x ], | FUNC(colF, ?)
2792 ] | /* ...with $x bound to ? */
18710f60 2793 ===============================================================
86298391 2794
96449e8e 2795
2796
2797=head1 SPECIAL OPERATORS
2798
e3f9dff4 2799 my $sqlmaker = SQL::Abstract->new(special_ops => [
3a2e1a5e 2800 {
2801 regex => qr/.../,
e3f9dff4 2802 handler => sub {
2803 my ($self, $field, $op, $arg) = @_;
2804 ...
3a2e1a5e 2805 },
2806 },
2807 {
2808 regex => qr/.../,
2809 handler => 'method_name',
e3f9dff4 2810 },
2811 ]);
2812
9d48860e 2813A "special operator" is a SQL syntactic clause that can be
e3f9dff4 2814applied to a field, instead of a usual binary operator.
be21dde3 2815For example:
e3f9dff4 2816
2817 WHERE field IN (?, ?, ?)
2818 WHERE field BETWEEN ? AND ?
2819 WHERE MATCH(field) AGAINST (?, ?)
96449e8e 2820
e3f9dff4 2821Special operators IN and BETWEEN are fairly standard and therefore
3a2e1a5e 2822are builtin within C<SQL::Abstract> (as the overridable methods
2823C<_where_field_IN> and C<_where_field_BETWEEN>). For other operators,
2824like the MATCH .. AGAINST example above which is specific to MySQL,
2825you can write your own operator handlers - supply a C<special_ops>
2826argument to the C<new> method. That argument takes an arrayref of
2827operator definitions; each operator definition is a hashref with two
2828entries:
96449e8e 2829
e3f9dff4 2830=over
2831
2832=item regex
2833
2834the regular expression to match the operator
96449e8e 2835
e3f9dff4 2836=item handler
2837
3a2e1a5e 2838Either a coderef or a plain scalar method name. In both cases
2839the expected return is C<< ($sql, @bind) >>.
2840
2841When supplied with a method name, it is simply called on the
13cc86af 2842L<SQL::Abstract> object as:
3a2e1a5e 2843
ca4f826a 2844 $self->$method_name($field, $op, $arg)
3a2e1a5e 2845
2846 Where:
2847
3a2e1a5e 2848 $field is the LHS of the operator
13cc86af 2849 $op is the part that matched the handler regex
3a2e1a5e 2850 $arg is the RHS
2851
2852When supplied with a coderef, it is called as:
2853
2854 $coderef->($self, $field, $op, $arg)
2855
e3f9dff4 2856
2857=back
2858
9d48860e 2859For example, here is an implementation
e3f9dff4 2860of the MATCH .. AGAINST syntax for MySQL
2861
2862 my $sqlmaker = SQL::Abstract->new(special_ops => [
9d48860e 2863
e3f9dff4 2864 # special op for MySql MATCH (field) AGAINST(word1, word2, ...)
9d48860e 2865 {regex => qr/^match$/i,
e3f9dff4 2866 handler => sub {
2867 my ($self, $field, $op, $arg) = @_;
2868 $arg = [$arg] if not ref $arg;
2869 my $label = $self->_quote($field);
2870 my ($placeholder) = $self->_convert('?');
2871 my $placeholders = join ", ", (($placeholder) x @$arg);
2872 my $sql = $self->_sqlcase('match') . " ($label) "
2873 . $self->_sqlcase('against') . " ($placeholders) ";
2874 my @bind = $self->_bindtype($field, @$arg);
2875 return ($sql, @bind);
2876 }
2877 },
9d48860e 2878
e3f9dff4 2879 ]);
96449e8e 2880
2881
59f23b3d 2882=head1 UNARY OPERATORS
2883
112b5232 2884 my $sqlmaker = SQL::Abstract->new(unary_ops => [
59f23b3d 2885 {
2886 regex => qr/.../,
2887 handler => sub {
2888 my ($self, $op, $arg) = @_;
2889 ...
2890 },
2891 },
2892 {
2893 regex => qr/.../,
2894 handler => 'method_name',
2895 },
2896 ]);
2897
9d48860e 2898A "unary operator" is a SQL syntactic clause that can be
59f23b3d 2899applied to a field - the operator goes before the field
2900
2901You can write your own operator handlers - supply a C<unary_ops>
2902argument to the C<new> method. That argument takes an arrayref of
2903operator definitions; each operator definition is a hashref with two
2904entries:
2905
2906=over
2907
2908=item regex
2909
2910the regular expression to match the operator
2911
2912=item handler
2913
2914Either a coderef or a plain scalar method name. In both cases
2915the expected return is C<< $sql >>.
2916
2917When supplied with a method name, it is simply called on the
13cc86af 2918L<SQL::Abstract> object as:
59f23b3d 2919
ca4f826a 2920 $self->$method_name($op, $arg)
59f23b3d 2921
2922 Where:
2923
2924 $op is the part that matched the handler regex
2925 $arg is the RHS or argument of the operator
2926
2927When supplied with a coderef, it is called as:
2928
2929 $coderef->($self, $op, $arg)
2930
2931
2932=back
2933
2934
32eab2da 2935=head1 PERFORMANCE
2936
2937Thanks to some benchmarking by Mark Stosberg, it turns out that
2938this module is many orders of magnitude faster than using C<DBIx::Abstract>.
2939I must admit this wasn't an intentional design issue, but it's a
2940byproduct of the fact that you get to control your C<DBI> handles
2941yourself.
2942
2943To maximize performance, use a code snippet like the following:
2944
2945 # prepare a statement handle using the first row
2946 # and then reuse it for the rest of the rows
2947 my($sth, $stmt);
2948 for my $href (@array_of_hashrefs) {
2949 $stmt ||= $sql->insert('table', $href);
2950 $sth ||= $dbh->prepare($stmt);
2951 $sth->execute($sql->values($href));
2952 }
2953
2954The reason this works is because the keys in your C<$href> are sorted
2955internally by B<SQL::Abstract>. Thus, as long as your data retains
2956the same structure, you only have to generate the SQL the first time
2957around. On subsequent queries, simply use the C<values> function provided
2958by this module to return your values in the correct order.
2959
b864ba9b 2960However this depends on the values having the same type - if, for
2961example, the values of a where clause may either have values
2962(resulting in sql of the form C<column = ?> with a single bind
2963value), or alternatively the values might be C<undef> (resulting in
2964sql of the form C<column IS NULL> with no bind value) then the
2965caching technique suggested will not work.
96449e8e 2966
32eab2da 2967=head1 FORMBUILDER
2968
2969If you use my C<CGI::FormBuilder> module at all, you'll hopefully
2970really like this part (I do, at least). Building up a complex query
2971can be as simple as the following:
2972
2973 #!/usr/bin/perl
2974
46dc2f3e 2975 use warnings;
2976 use strict;
2977
32eab2da 2978 use CGI::FormBuilder;
2979 use SQL::Abstract;
2980
2981 my $form = CGI::FormBuilder->new(...);
2982 my $sql = SQL::Abstract->new;
2983
2984 if ($form->submitted) {
2985 my $field = $form->field;
2986 my $id = delete $field->{id};
2987 my($stmt, @bind) = $sql->update('table', $field, {id => $id});
2988 }
2989
2990Of course, you would still have to connect using C<DBI> to run the
2991query, but the point is that if you make your form look like your
2992table, the actual query script can be extremely simplistic.
2993
2994If you're B<REALLY> lazy (I am), check out C<HTML::QuickTable> for
9d48860e 2995a fast interface to returning and formatting data. I frequently
32eab2da 2996use these three modules together to write complex database query
2997apps in under 50 lines.
2998
af733667 2999=head1 HOW TO CONTRIBUTE
3000
3001Contributions are always welcome, in all usable forms (we especially
3002welcome documentation improvements). The delivery methods include git-
3003or unified-diff formatted patches, GitHub pull requests, or plain bug
3004reports either via RT or the Mailing list. Contributors are generally
3005granted full access to the official repository after their first several
3006patches pass successful review.
3007
3008This project is maintained in a git repository. The code and related tools are
3009accessible at the following locations:
d8cc1792 3010
3011=over
3012
af733667 3013=item * Official repo: L<git://git.shadowcat.co.uk/dbsrgits/SQL-Abstract.git>
3014
3015=item * Official gitweb: L<http://git.shadowcat.co.uk/gitweb/gitweb.cgi?p=dbsrgits/SQL-Abstract.git>
3016
3017=item * GitHub mirror: L<https://github.com/dbsrgits/sql-abstract>
d8cc1792 3018
af733667 3019=item * Authorized committers: L<ssh://dbsrgits@git.shadowcat.co.uk/SQL-Abstract.git>
d8cc1792 3020
3021=back
32eab2da 3022
96449e8e 3023=head1 CHANGES
3024
3025Version 1.50 was a major internal refactoring of C<SQL::Abstract>.
3026Great care has been taken to preserve the I<published> behavior
3027documented in previous versions in the 1.* family; however,
9d48860e 3028some features that were previously undocumented, or behaved
96449e8e 3029differently from the documentation, had to be changed in order
3030to clarify the semantics. Hence, client code that was relying
9d48860e 3031on some dark areas of C<SQL::Abstract> v1.*
96449e8e 3032B<might behave differently> in v1.50.
32eab2da 3033
be21dde3 3034The main changes are:
d2a8fe1a 3035
96449e8e 3036=over
32eab2da 3037
9d48860e 3038=item *
32eab2da 3039
3ae1c5e2 3040support for literal SQL through the C<< \ [ $sql, @bind ] >> syntax.
96449e8e 3041
3042=item *
3043
145fbfc8 3044support for the { operator => \"..." } construct (to embed literal SQL)
3045
3046=item *
3047
9c37b9c0 3048support for the { operator => \["...", @bind] } construct (to embed literal SQL with bind values)
3049
3050=item *
3051
96449e8e 3052optional support for L<array datatypes|/"Inserting and Updating Arrays">
3053
9d48860e 3054=item *
96449e8e 3055
be21dde3 3056defensive programming: check arguments
96449e8e 3057
3058=item *
3059
3060fixed bug with global logic, which was previously implemented
7cac25e6 3061through global variables yielding side-effects. Prior versions would
96449e8e 3062interpret C<< [ {cond1, cond2}, [cond3, cond4] ] >>
3063as C<< "(cond1 AND cond2) OR (cond3 AND cond4)" >>.
3064Now this is interpreted
3065as C<< "(cond1 AND cond2) OR (cond3 OR cond4)" >>.
3066
96449e8e 3067
3068=item *
3069
3070fixed semantics of _bindtype on array args
3071
9d48860e 3072=item *
96449e8e 3073
3074dropped the C<_anoncopy> of the %where tree. No longer necessary,
3075we just avoid shifting arrays within that tree.
3076
3077=item *
3078
3079dropped the C<_modlogic> function
3080
3081=back
32eab2da 3082
32eab2da 3083=head1 ACKNOWLEDGEMENTS
3084
3085There are a number of individuals that have really helped out with
3086this module. Unfortunately, most of them submitted bugs via CPAN
3087so I have no idea who they are! But the people I do know are:
3088
9d48860e 3089 Ash Berlin (order_by hash term support)
b643abe1 3090 Matt Trout (DBIx::Class support)
32eab2da 3091 Mark Stosberg (benchmarking)
3092 Chas Owens (initial "IN" operator support)
3093 Philip Collins (per-field SQL functions)
3094 Eric Kolve (hashref "AND" support)
3095 Mike Fragassi (enhancements to "BETWEEN" and "LIKE")
3096 Dan Kubb (support for "quote_char" and "name_sep")
f5aab26e 3097 Guillermo Roditi (patch to cleanup "IN" and "BETWEEN", fix and tests for _order_by)
48d9f5f8 3098 Laurent Dami (internal refactoring, extensible list of special operators, literal SQL)
dbdf7648 3099 Norbert Buchmuller (support for literal SQL in hashpair, misc. fixes & tests)
e96c510a 3100 Peter Rabbitson (rewrite of SQLA::Test, misc. fixes & tests)
02288357 3101 Oliver Charles (support for "RETURNING" after "INSERT")
32eab2da 3102
3103Thanks!
3104
32eab2da 3105=head1 SEE ALSO
3106
86298391 3107L<DBIx::Class>, L<DBIx::Abstract>, L<CGI::FormBuilder>, L<HTML::QuickTable>.
32eab2da 3108
32eab2da 3109=head1 AUTHOR
3110
b643abe1 3111Copyright (c) 2001-2007 Nathan Wiger <nwiger@cpan.org>. All Rights Reserved.
3112
3113This module is actively maintained by Matt Trout <mst@shadowcatsystems.co.uk>
32eab2da 3114
abe72f94 3115For support, your best bet is to try the C<DBIx::Class> users mailing list.
3116While not an official support venue, C<DBIx::Class> makes heavy use of
3117C<SQL::Abstract>, and as such list members there are very familiar with
3118how to create queries.
3119
0d067ded 3120=head1 LICENSE
3121
d988ab87 3122This module is free software; you may copy this under the same
3123terms as perl itself (either the GNU General Public License or
3124the Artistic License)
32eab2da 3125
3126=cut