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