Revision history for SQL::Abstract
- Fixed a couple of untrapped undefined warnings
+ - Make -in/-between accept literal sql in all logical
+ variants - see POD for details
+ - Unroll parenthesis around IN arguments to accomodate
+ crappy databases
revision 1.58 2009-09-04 15:20 (UTC)
----------------------------
(by default : C<1=0>). Similarly, C<< -not_in => [] >> generates
'sqltrue' (by default : C<1=1>).
+In addition to the array you can supply a chunk of literal sql or
+literal sql with bind:
+ my %where = {
+ customer => { -in => \[
+ 'SELECT cust_id FROM cust WHERE balance > ?',
+ 2000,
+ ],
+ status => { -in => \'SELECT status_codes FROM states' },
+ };
-Another pair of operators is C<-between> and C<-not_between>,
+would generate:
+
+ $stmt = "WHERE (
+ customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
+ AND status IN ( SELECT status_codes FROM states )
+ )";
+ @bind = ('2000');
+
+
+
+Another pair of operators is C<-between> and C<-not_between>,
used with an arrayref of two values:
my %where = (
WHERE user = ? AND completion_date NOT BETWEEN ( ? AND ? )
+Just like with C<-in> all plausible combinations of literal SQL
+are possible:
+
+ my %where = {
+ start0 => { -between => [ 1, 2 ] },
+ start1 => { -between => \["? AND ?", 1, 2] },
+ start2 => { -between => \"lower(x) AND upper(y)" },
+ start3 => { -between => [
+ \"lower(x)",
+ \["upper(?)", 'stuff' ],
+ ] },
+ };
+
+Would give you:
+
+ $stmt = "WHERE (
+ ( start0 BETWEEN ? AND ? )
+ AND ( start1 BETWEEN ? AND ? )
+ AND ( start2 BETWEEN lower(x) AND upper(y) )
+ AND ( start3 BETWEEN lower(x) AND upper(?) )
+ )";
+ @bind = (1, 2, 1, 2, 'stuff');
+
+
These are the two builtin "special operators"; but the
list can be expanded : see section L</"SPECIAL OPERATORS"> below.
);
-TMTOWTDI.
+TMTOWTDI
Conditions on boolean columns can be expressed in the same way, passing
a reference to an empty string, however using liternal SQL in this way
bind => [],
test => '-between with literal sql with a literal (\"\'this\' AND \'that\'")',
},
-
+ {
+ where => {
+ start0 => { -between => [ 1, 2 ] },
+ start1 => { -between => \["? AND ?", 1, 2] },
+ start2 => { -between => \"lower(x) AND upper(y)" },
+ start3 => { -between => [
+ \"lower(x)",
+ \["upper(?)", 'stuff' ],
+ ] },
+ },
+ stmt => "WHERE (
+ ( start0 BETWEEN ? AND ? )
+ AND ( start1 BETWEEN ? AND ? )
+ AND ( start2 BETWEEN lower(x) AND upper(y) )
+ AND ( start3 BETWEEN lower(x) AND upper(?) )
+ )",
+ bind => [1, 2, 1, 2, 'stuff'],
+ test => '-between POD test',
+ },
{
parenthesis_significant => 1,
},
{
parenthesis_significant => 1,
+ where => { x => { -in => [] } },
+ stmt => "WHERE ( 0=1 )",
+ bind => [],
+ test => '-in with an empty array',
+ },
+ {
+ parenthesis_significant => 1,
where => { x => { -in => \'( 1,2,lower(y) )' } },
stmt => "WHERE ( x IN (1, 2, lower(y) ) )",
bind => [],
bind => [1, 2],
test => '-in with a literal arrayrefref',
},
+ {
+ parenthesis_significant => 1,
+ where => {
+ customer => { -in => \[
+ 'SELECT cust_id FROM cust WHERE balance > ?',
+ 2000,
+ ]},
+ status => { -in => \'SELECT status_codes FROM states' },
+ },
+ stmt => "
+ WHERE ((
+ customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
+ AND status IN ( SELECT status_codes FROM states )
+ ))
+ ",
+ bind => [2000],
+ test => '-in POD test',
+ },
);
plan tests => @in_between_tests*4;