6 use SQL::Abstract::Test import => [qw(is_same_sql_bind diag_where)];
10 my @in_between_tests = (
12 where => { x => { -between => [1, 2] } },
13 stmt => 'WHERE (x BETWEEN ? AND ?)',
15 test => '-between with two placeholders',
18 where => { x => { -between => [\"1", 2] } },
19 stmt => 'WHERE (x BETWEEN 1 AND ?)',
21 test => '-between with one literal sql arg and one placeholder',
24 where => { x => { -between => [1, \"2"] } },
25 stmt => 'WHERE (x BETWEEN ? AND 2)',
27 test => '-between with one placeholder and one literal sql arg',
30 where => { x => { -between => [\'current_date - 1', \'current_date - 0'] } },
31 stmt => 'WHERE (x BETWEEN current_date - 1 AND current_date - 0)',
33 test => '-between with two literal sql arguments',
36 where => { x => { -between => [ \['current_date - ?', 1], \['current_date - ?', 0] ] } },
37 stmt => 'WHERE (x BETWEEN current_date - ? AND current_date - ?)',
39 test => '-between with two literal sql arguments with bind',
42 where => { x => { -between => \['? AND ?', 1, 2] } },
43 stmt => 'WHERE (x BETWEEN ? AND ?)',
45 test => '-between with literal sql with placeholders (\["? AND ?", scalar, scalar])',
48 where => { x => { -between => \["'something' AND ?", 2] } },
49 stmt => "WHERE (x BETWEEN 'something' AND ?)",
51 test => '-between with literal sql with one literal arg and one placeholder (\["\'something\' AND ?", scalar])',
54 where => { x => { -between => \["? AND 'something'", 1] } },
55 stmt => "WHERE (x BETWEEN ? AND 'something')",
57 test => '-between with literal sql with one placeholder and one literal arg (\["? AND \'something\'", scalar])',
60 where => { x => { -between => \"'this' AND 'that'" } },
61 stmt => "WHERE (x BETWEEN 'this' AND 'that')",
63 test => '-between with literal sql with a literal (\"\'this\' AND \'that\'")',
66 # generate a set of invalid -between tests
68 where => { x => { -between => $_ } },
69 test => 'invalid -between args',
70 throws => qr|Operator 'BETWEEN' requires either an arrayref with two defined values or expressions, or a single literal scalarref/arrayref-ref|,
87 start0 => { -between => [ 1, { -upper => 2 } ] },
88 start1 => { -between => \["? AND ?", 1, 2] },
89 start2 => { -between => \"lower(x) AND upper(y)" },
90 start3 => { -between => [
92 \["upper(?)", 'stuff' ],
96 ( start0 BETWEEN ? AND UPPER ? )
97 AND ( start1 BETWEEN ? AND ? )
98 AND ( start2 BETWEEN lower(x) AND upper(y) )
99 AND ( start3 BETWEEN lower(x) AND upper(?) )
101 bind => [1, 2, 1, 2, 'stuff'],
102 test => '-between POD test',
105 args => { bindtype => 'columns' },
107 start0 => { -between => [ 1, { -upper => 2 } ] },
108 start1 => { -between => \["? AND ?", [ start1 => 1], [start1 => 2] ] },
109 start2 => { -between => \"lower(x) AND upper(y)" },
110 start3 => { -between => [
112 \["upper(?)", [ start3 => 'stuff'] ],
116 ( start0 BETWEEN ? AND UPPER ? )
117 AND ( start1 BETWEEN ? AND ? )
118 AND ( start2 BETWEEN lower(x) AND upper(y) )
119 AND ( start3 BETWEEN lower(x) AND upper(?) )
126 [ start3 => 'stuff' ],
128 test => '-between POD test',
132 parenthesis_significant => 1,
133 where => { x => { -in => [ 1 .. 3] } },
134 stmt => "WHERE ( x IN (?, ?, ?) )",
136 test => '-in with an array of scalars',
139 parenthesis_significant => 1,
140 where => { x => { -in => [] } },
141 stmt => "WHERE ( 0=1 )",
143 test => '-in with an empty array',
146 parenthesis_significant => 1,
147 where => { x => { -in => \'( 1,2,lower(y) )' } },
148 stmt => "WHERE ( x IN ( 1,2,lower(y) ) )",
150 test => '-in with a literal scalarref',
153 # note that outer parens are opened even though literal was requested below
155 parenthesis_significant => 1,
156 where => { x => { -in => \['( ( ?,?,lower(y) ) )', 1, 2] } },
157 stmt => "WHERE ( x IN ( ?,?,lower(y) ) )",
159 test => '-in with a literal arrayrefref',
162 parenthesis_significant => 1,
164 status => { -in => \"(SELECT status_codes\nFROM states)" },
166 stmt => " WHERE ( status IN ( SELECT status_codes FROM states )) ",
168 test => '-in multi-line subquery test',
171 parenthesis_significant => 1,
173 customer => { -in => \[
174 'SELECT cust_id FROM cust WHERE balance > ?',
177 status => { -in => \'SELECT status_codes FROM states' },
181 customer IN ( SELECT cust_id FROM cust WHERE balance > ? )
182 AND status IN ( SELECT status_codes FROM states )
186 test => '-in POD test',
190 where => { x => { -in => [ \['LOWER(?)', 'A' ], \'LOWER(b)', { -lower => 'c' } ] } },
191 stmt => " WHERE ( x IN ( LOWER(?), LOWER(b), LOWER ? ) )",
193 test => '-in with an array of function array refs with args',
197 \QSQL::Abstract before v1.75 used to generate incorrect SQL \E
198 \Qwhen the -IN operator was given an undef-containing list: \E
199 \Q!!!AUDIT YOUR CODE AND DATA!!! (the upcoming Data::Query-based \E
200 \Qversion of SQL::Abstract will emit the logically correct SQL \E
201 \Qinstead of raising this exception)\E
203 where => { x => { -in => [ 1, undef ] } },
204 stmt => " WHERE ( x IN ( ? ) OR x IS NULL )",
206 test => '-in with undef as an element',
210 \QSQL::Abstract before v1.75 used to generate incorrect SQL \E
211 \Qwhen the -IN operator was given an undef-containing list: \E
212 \Q!!!AUDIT YOUR CODE AND DATA!!! (the upcoming Data::Query-based \E
213 \Qversion of SQL::Abstract will emit the logically correct SQL \E
214 \Qinstead of raising this exception)\E
216 where => { x => { -in => [ 1, undef, 2, 3, undef ] } },
217 stmt => " WHERE ( x IN ( ?, ?, ? ) OR x IS NULL )",
219 test => '-in with multiple undef elements',
223 for my $case (@in_between_tests) {
225 local $TODO = $case->{todo} if $case->{todo};
226 local $SQL::Abstract::Test::parenthesis_significant = $case->{parenthesis_significant};
228 my $sql = SQL::Abstract->new ($case->{args} || {});
230 if (my $e = $case->{throws}) {
231 throws_ok { $sql->where($case->{where}) } $e;
236 ($stmt, @bind) = $sql->where($case->{where});
237 } [], 'No warnings within in-between tests';
244 ) || diag_where ( $case->{where} );