From: Peter Rabbitson Date: Tue, 22 Sep 2009 08:35:26 +0000 (+0000) Subject: Documentation and changes X-Git-Tag: v1.70~140 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=e41c3bdda9401514dcc02a3877346e4db953f41a;p=dbsrgits%2FSQL-Abstract.git Documentation and changes --- diff --git a/Changes b/Changes index ea6cca4..efa235b 100644 --- a/Changes +++ b/Changes @@ -1,6 +1,10 @@ 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) ---------------------------- diff --git a/lib/SQL/Abstract.pm b/lib/SQL/Abstract.pm index 431d428..012f8f9 100644 --- a/lib/SQL/Abstract.pm +++ b/lib/SQL/Abstract.pm @@ -1972,9 +1972,28 @@ If the argument to C<-in> is an empty array, 'sqlfalse' is generated (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 = ( @@ -1988,6 +2007,30 @@ Would give you: 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 below. @@ -2142,7 +2185,7 @@ with this: ); -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 diff --git a/t/05in_between.t b/t/05in_between.t index ae6e61c..aa0b13a 100644 --- a/t/05in_between.t +++ b/t/05in_between.t @@ -64,7 +64,25 @@ my @in_between_tests = ( 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, @@ -75,6 +93,13 @@ my @in_between_tests = ( }, { 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 => [], @@ -87,6 +112,24 @@ my @in_between_tests = ( 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;