7 use SQL::Abstract::Test import => ['is_same_sql_bind'];
13 # -nest has been undocumented on purpose, but is still supported for the
14 # foreseable future. Do not rip out the -nest tests before speaking to
15 # someone on the DBIC mailing list or in irc.perl.org#dbix-class
23 args => ['test', '*'],
24 stmt => 'SELECT * FROM test',
25 stmt_q => 'SELECT * FROM `test`',
30 args => ['test', [qw(one two three)]],
31 stmt => 'SELECT one, two, three FROM test',
32 stmt_q => 'SELECT `one`, `two`, `three` FROM `test`',
37 args => ['test', '*', { a => 0 }, [qw/boom bada bing/]],
38 stmt => 'SELECT * FROM test WHERE ( a = ? ) ORDER BY boom, bada, bing',
39 stmt_q => 'SELECT * FROM `test` WHERE ( `a` = ? ) ORDER BY `boom`, `bada`, `bing`',
44 args => ['test', '*', [ { a => 5 }, { b => 6 } ]],
45 stmt => 'SELECT * FROM test WHERE ( ( a = ? ) OR ( b = ? ) )',
46 stmt_q => 'SELECT * FROM `test` WHERE ( ( `a` = ? ) OR ( `b` = ? ) )',
51 args => ['test', '*', undef, ['id']],
52 stmt => 'SELECT * FROM test ORDER BY id',
53 stmt_q => 'SELECT * FROM `test` ORDER BY `id`',
58 args => ['test', '*', { a => 'boom' } , ['id']],
59 stmt => 'SELECT * FROM test WHERE ( a = ? ) ORDER BY id',
60 stmt_q => 'SELECT * FROM `test` WHERE ( `a` = ? ) ORDER BY `id`',
65 args => ['test', '*', { a => ['boom', 'bang'] }],
66 stmt => 'SELECT * FROM test WHERE ( ( ( a = ? ) OR ( a = ? ) ) )',
67 stmt_q => 'SELECT * FROM `test` WHERE ( ( ( `a` = ? ) OR ( `a` = ? ) ) )',
68 bind => ['boom', 'bang']
72 args => [[qw/test1 test2/], '*', { 'test1.a' => { 'In', ['boom', 'bang'] } }],
73 stmt => 'SELECT * FROM test1, test2 WHERE ( test1.a IN ( ?, ? ) )',
74 stmt_q => 'SELECT * FROM `test1`, `test2` WHERE ( `test1`.`a` IN ( ?, ? ) )',
75 bind => ['boom', 'bang']
79 args => ['test', '*', { a => { 'between', ['boom', 'bang'] } }],
80 stmt => 'SELECT * FROM test WHERE ( a BETWEEN ? AND ? )',
81 stmt_q => 'SELECT * FROM `test` WHERE ( `a` BETWEEN ? AND ? )',
82 bind => ['boom', 'bang']
86 args => ['test', '*', { a => { '!=', 'boom' } }],
87 stmt => 'SELECT * FROM test WHERE ( a != ? )',
88 stmt_q => 'SELECT * FROM `test` WHERE ( `a` != ? )',
93 args => ['test', {a => 'boom'}, {a => undef}],
94 stmt => 'UPDATE test SET a = ? WHERE ( a IS NULL )',
95 stmt_q => 'UPDATE `test` SET `a` = ? WHERE ( `a` IS NULL )',
100 args => ['test', {a => 'boom'}, { a => {'!=', "bang" }} ],
101 stmt => 'UPDATE test SET a = ? WHERE ( a != ? )',
102 stmt_q => 'UPDATE `test` SET `a` = ? WHERE ( `a` != ? )',
103 bind => ['boom', 'bang']
107 args => ['test', {'a-funny-flavored-candy' => 'yummy', b => 'oops'}, { a42 => "bang" }],
108 stmt => 'UPDATE test SET a-funny-flavored-candy = ?, b = ? WHERE ( a42 = ? )',
109 stmt_q => 'UPDATE `test` SET `a-funny-flavored-candy` = ?, `b` = ? WHERE ( `a42` = ? )',
110 bind => ['yummy', 'oops', 'bang']
114 args => ['test', {requestor => undef}],
115 stmt => 'DELETE FROM test WHERE ( requestor IS NULL )',
116 stmt_q => 'DELETE FROM `test` WHERE ( `requestor` IS NULL )',
121 args => [[qw/test1 test2 test3/],
122 { 'test1.field' => \'!= test2.field',
123 user => {'!=','nwiger'} },
125 stmt => 'DELETE FROM test1, test2, test3 WHERE ( test1.field != test2.field AND user != ? )',
126 stmt_q => 'DELETE FROM `test1`, `test2`, `test3` WHERE ( `test1`.`field` != test2.field AND `user` != ? )', # test2.field is a literal value, cannnot be quoted.
131 args => ['test', {a => 1, b => 2, c => 3, d => 4, e => 5}],
132 stmt => 'INSERT INTO test (a, b, c, d, e) VALUES (?, ?, ?, ?, ?)',
133 stmt_q => 'INSERT INTO `test` (`a`, `b`, `c`, `d`, `e`) VALUES (?, ?, ?, ?, ?)',
134 bind => [qw/1 2 3 4 5/],
138 args => ['test', [qw/1 2 3 4 5/]],
139 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?)',
140 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?)',
141 bind => [qw/1 2 3 4 5/],
145 args => ['test', [qw/1 2 3 4 5/, undef]],
146 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?, ?)',
147 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?, ?)',
148 bind => [qw/1 2 3 4 5/, undef],
152 args => ['test', {a => 1, b => 2, c => 3, d => 4, e => 5}],
153 stmt => 'UPDATE test SET a = ?, b = ?, c = ?, d = ?, e = ?',
154 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = ?, `c` = ?, `d` = ?, `e` = ?',
155 bind => [qw/1 2 3 4 5/],
159 args => ['test', {a => 1, b => 2, c => 3, d => 4, e => 5}, {a => {'in', [1..5]}}],
160 stmt => 'UPDATE test SET a = ?, b = ?, c = ?, d = ?, e = ? WHERE ( a IN ( ?, ?, ?, ?, ? ) )',
161 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = ?, `c` = ?, `d` = ?, `e` = ? WHERE ( `a` IN ( ?, ?, ?, ?, ? ) )',
162 bind => [qw/1 2 3 4 5 1 2 3 4 5/],
166 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", '02/02/02']}, {a => {'between', [1,2]}}],
167 stmt => 'UPDATE test SET a = ?, b = to_date(?, \'MM/DD/YY\') WHERE ( a BETWEEN ? AND ? )',
168 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = to_date(?, \'MM/DD/YY\') WHERE ( `a` BETWEEN ? AND ? )',
169 bind => [qw(1 02/02/02 1 2)],
173 args => ['test.table', {high_limit => \'max(all_limits)', low_limit => 4} ],
174 stmt => 'INSERT INTO test.table (high_limit, low_limit) VALUES (max(all_limits), ?)',
175 stmt_q => 'INSERT INTO `test`.`table` (`high_limit`, `low_limit`) VALUES (max(all_limits), ?)',
180 args => ['test.table', [ \'max(all_limits)', 4 ] ],
181 stmt => 'INSERT INTO test.table VALUES (max(all_limits), ?)',
182 stmt_q => 'INSERT INTO `test`.`table` VALUES (max(all_limits), ?)',
187 new => {bindtype => 'columns'},
188 args => ['test.table', {one => 2, three => 4, five => 6} ],
189 stmt => 'INSERT INTO test.table (five, one, three) VALUES (?, ?, ?)',
190 stmt_q => 'INSERT INTO `test`.`table` (`five`, `one`, `three`) VALUES (?, ?, ?)',
191 bind => [['five', 6], ['one', 2], ['three', 4]], # alpha order, man...
195 new => {bindtype => 'columns', case => 'lower'},
196 args => ['test.table', [qw/one two three/], {one => 2, three => 4, five => 6} ],
197 stmt => 'select one, two, three from test.table where ( five = ? and one = ? and three = ? )',
198 stmt_q => 'select `one`, `two`, `three` from `test`.`table` where ( `five` = ? and `one` = ? and `three` = ? )',
199 bind => [['five', 6], ['one', 2], ['three', 4]], # alpha order, man...
203 new => {bindtype => 'columns', cmp => 'like'},
204 args => ['testin.table2', {One => 22, Three => 44, FIVE => 66},
205 {Beer => 'is', Yummy => '%YES%', IT => ['IS','REALLY','GOOD']}],
206 stmt => 'UPDATE testin.table2 SET FIVE = ?, One = ?, Three = ? WHERE '
207 . '( Beer LIKE ? AND ( ( IT LIKE ? ) OR ( IT LIKE ? ) OR ( IT LIKE ? ) ) AND Yummy LIKE ? )',
208 stmt_q => 'UPDATE `testin`.`table2` SET `FIVE` = ?, `One` = ?, `Three` = ? WHERE '
209 . '( `Beer` LIKE ? AND ( ( `IT` LIKE ? ) OR ( `IT` LIKE ? ) OR ( `IT` LIKE ? ) ) AND `Yummy` LIKE ? )',
210 bind => [['FIVE', 66], ['One', 22], ['Three', 44], ['Beer','is'],
211 ['IT','IS'], ['IT','REALLY'], ['IT','GOOD'], ['Yummy','%YES%']],
215 args => ['test', '*', {priority => [ -and => {'!=', 2}, { -not_like => '3%'} ]}],
216 stmt => 'SELECT * FROM test WHERE ( ( ( priority != ? ) AND ( priority NOT LIKE ? ) ) )',
217 stmt_q => 'SELECT * FROM `test` WHERE ( ( ( `priority` != ? ) AND ( `priority` NOT LIKE ? ) ) )',
222 args => ['Yo Momma', '*', { user => 'nwiger',
223 -nest => [ workhrs => {'>', 20}, geo => 'ASIA' ] }],
224 stmt => 'SELECT * FROM Yo Momma WHERE ( ( ( workhrs > ? ) OR ( geo = ? ) ) AND user = ? )',
225 stmt_q => 'SELECT * FROM `Yo Momma` WHERE ( ( ( `workhrs` > ? ) OR ( `geo` = ? ) ) AND `user` = ? )',
226 bind => [qw(20 ASIA nwiger)],
230 args => ['taco_punches', { one => 2, three => 4 },
231 { bland => [ -and => {'!=', 'yes'}, {'!=', 'YES'} ],
232 tasty => { '!=', [qw(yes YES)] },
233 -nest => [ face => [ -or => {'=', 'mr.happy'}, {'=', undef} ] ] },
235 stmt => 'UPDATE taco_punches SET one = ?, three = ? WHERE ( ( ( ( ( face = ? ) OR ( face IS NULL ) ) ) )'
236 . ' AND ( ( bland != ? ) AND ( bland != ? ) ) AND ( ( tasty != ? ) OR ( tasty != ? ) ) )',
237 stmt_q => 'UPDATE `taco_punches` SET `one` = ?, `three` = ? WHERE ( ( ( ( ( `face` = ? ) OR ( `face` IS NULL ) ) ) )'
238 . ' AND ( ( `bland` != ? ) AND ( `bland` != ? ) ) AND ( ( `tasty` != ? ) OR ( `tasty` != ? ) ) )',
239 bind => [qw(2 4 mr.happy yes YES yes YES)],
243 args => ['jeff', '*', { name => {'ilike', '%smith%', -not_in => ['Nate','Jim','Bob','Sally']},
244 -nest => [ -or => [ -and => [age => { -between => [20,30] }, age => {'!=', 25} ],
245 yob => {'<', 1976} ] ] } ],
246 stmt => 'SELECT * FROM jeff WHERE ( ( ( ( ( ( ( age BETWEEN ? AND ? ) AND ( age != ? ) ) ) OR ( yob < ? ) ) ) )'
247 . ' AND name NOT IN ( ?, ?, ?, ? ) AND name ILIKE ? )',
248 stmt_q => 'SELECT * FROM `jeff` WHERE ( ( ( ( ( ( ( `age` BETWEEN ? AND ? ) AND ( `age` != ? ) ) ) OR ( `yob` < ? ) ) ) )'
249 . ' AND `name` NOT IN ( ?, ?, ?, ? ) AND `name` ILIKE ? )',
250 bind => [qw(20 30 25 1976 Nate Jim Bob Sally %smith%)]
254 args => ['fhole', {fpoles => 4}, [
255 { race => [qw/-or black white asian /] },
256 { -nest => { firsttime => [-or => {'=','yes'}, undef] } },
257 { -and => [ { firstname => {-not_like => 'candace'} }, { lastname => {-in => [qw(jugs canyon towers)] } } ] },
259 stmt => 'UPDATE fhole SET fpoles = ? WHERE ( ( ( ( ( ( ( race = ? ) OR ( race = ? ) OR ( race = ? ) ) ) ) ) )'
260 . ' OR ( ( ( ( firsttime = ? ) OR ( firsttime IS NULL ) ) ) ) OR ( ( ( firstname NOT LIKE ? ) ) AND ( lastname IN (?, ?, ?) ) ) )',
261 stmt_q => 'UPDATE `fhole` SET `fpoles` = ? WHERE ( ( ( ( ( ( ( `race` = ? ) OR ( `race` = ? ) OR ( `race` = ? ) ) ) ) ) )'
262 . ' OR ( ( ( ( `firsttime` = ? ) OR ( `firsttime` IS NULL ) ) ) ) OR ( ( ( `firstname` NOT LIKE ? ) ) AND ( `lastname` IN( ?, ?, ? )) ) )',
263 bind => [qw(4 black white asian yes candace jugs canyon towers)]
267 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", '02/02/02']}],
268 stmt => 'INSERT INTO test (a, b) VALUES (?, to_date(?, \'MM/DD/YY\'))',
269 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, to_date(?, \'MM/DD/YY\'))',
270 bind => [qw(1 02/02/02)],
274 args => ['test', '*', { a => \["= to_date(?, 'MM/DD/YY')", '02/02/02']}],
275 stmt => q{SELECT * FROM test WHERE ( a = to_date(?, 'MM/DD/YY') )},
276 stmt_q => q{SELECT * FROM `test` WHERE ( `a` = to_date(?, 'MM/DD/YY') )},
277 bind => ['02/02/02'],
281 new => {array_datatypes => 1},
282 args => ['test', {a => 1, b => [1, 1, 2, 3, 5, 8]}],
283 stmt => 'INSERT INTO test (a, b) VALUES (?, ?)',
284 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, ?)',
285 bind => [1, [1, 1, 2, 3, 5, 8]],
289 new => {bindtype => 'columns', array_datatypes => 1},
290 args => ['test', {a => 1, b => [1, 1, 2, 3, 5, 8]}],
291 stmt => 'INSERT INTO test (a, b) VALUES (?, ?)',
292 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, ?)',
293 bind => [[a => 1], [b => [1, 1, 2, 3, 5, 8]]],
297 new => {array_datatypes => 1},
298 args => ['test', {a => 1, b => [1, 1, 2, 3, 5, 8]}],
299 stmt => 'UPDATE test SET a = ?, b = ?',
300 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = ?',
301 bind => [1, [1, 1, 2, 3, 5, 8]],
305 new => {bindtype => 'columns', array_datatypes => 1},
306 args => ['test', {a => 1, b => [1, 1, 2, 3, 5, 8]}],
307 stmt => 'UPDATE test SET a = ?, b = ?',
308 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = ?',
309 bind => [[a => 1], [b => [1, 1, 2, 3, 5, 8]]],
313 args => ['test', '*', { a => {'>', \'1 + 1'}, b => 8 }],
314 stmt => 'SELECT * FROM test WHERE ( a > 1 + 1 AND b = ? )',
315 stmt_q => 'SELECT * FROM `test` WHERE ( `a` > 1 + 1 AND `b` = ? )',
320 args => ['test', '*', { a => {'<' => \["to_date(?, 'MM/DD/YY')", '02/02/02']}, b => 8 }],
321 stmt => 'SELECT * FROM test WHERE ( a < to_date(?, \'MM/DD/YY\') AND b = ? )',
322 stmt_q => 'SELECT * FROM `test` WHERE ( `a` < to_date(?, \'MM/DD/YY\') AND `b` = ? )',
323 bind => ['02/02/02', 8],
325 { #TODO in SQLA >= 2.0 it will die instead (we kept this just because old SQLA passed it through)
327 args => ['test', {a => 1, b => 2, c => 3, d => 4, e => { answer => 42 }}],
328 stmt => 'INSERT INTO test (a, b, c, d, e) VALUES (?, ?, ?, ?, ?)',
329 stmt_q => 'INSERT INTO `test` (`a`, `b`, `c`, `d`, `e`) VALUES (?, ?, ?, ?, ?)',
330 bind => [qw/1 2 3 4/, { answer => 42}],
331 warns => qr/HASH ref as bind value in insert is not supported/i,
335 args => ['test', {a => 1, b => \["42"]}, {a => {'between', [1,2]}}],
336 stmt => 'UPDATE test SET a = ?, b = 42 WHERE ( a BETWEEN ? AND ? )',
337 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = 42 WHERE ( `a` BETWEEN ? AND ? )',
342 args => ['test', {a => 1, b => \["42"]}],
343 stmt => 'INSERT INTO test (a, b) VALUES (?, 42)',
344 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, 42)',
349 args => ['test', '*', { a => \["= 42"], b => 1}],
350 stmt => q{SELECT * FROM test WHERE ( a = 42 ) AND (b = ? )},
351 stmt_q => q{SELECT * FROM `test` WHERE ( `a` = 42 ) AND ( `b` = ? )},
356 args => ['test', '*', { a => {'<' => \["42"]}, b => 8 }],
357 stmt => 'SELECT * FROM test WHERE ( a < 42 AND b = ? )',
358 stmt_q => 'SELECT * FROM `test` WHERE ( `a` < 42 AND `b` = ? )',
363 new => {bindtype => 'columns'},
364 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", [dummy => '02/02/02']]}],
365 stmt => 'INSERT INTO test (a, b) VALUES (?, to_date(?, \'MM/DD/YY\'))',
366 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, to_date(?, \'MM/DD/YY\'))',
367 bind => [[a => '1'], [dummy => '02/02/02']],
371 new => {bindtype => 'columns'},
372 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", [dummy => '02/02/02']]}, {a => {'between', [1,2]}}],
373 stmt => 'UPDATE test SET a = ?, b = to_date(?, \'MM/DD/YY\') WHERE ( a BETWEEN ? AND ? )',
374 stmt_q => 'UPDATE `test` SET `a` = ?, `b` = to_date(?, \'MM/DD/YY\') WHERE ( `a` BETWEEN ? AND ? )',
375 bind => [[a => '1'], [dummy => '02/02/02'], [a => '1'], [a => '2']],
379 new => {bindtype => 'columns'},
380 args => ['test', '*', { a => \["= to_date(?, 'MM/DD/YY')", [dummy => '02/02/02']]}],
381 stmt => q{SELECT * FROM test WHERE ( a = to_date(?, 'MM/DD/YY') )},
382 stmt_q => q{SELECT * FROM `test` WHERE ( `a` = to_date(?, 'MM/DD/YY') )},
383 bind => [[dummy => '02/02/02']],
387 new => {bindtype => 'columns'},
388 args => ['test', '*', { a => {'<' => \["to_date(?, 'MM/DD/YY')", [dummy => '02/02/02']]}, b => 8 }],
389 stmt => 'SELECT * FROM test WHERE ( a < to_date(?, \'MM/DD/YY\') AND b = ? )',
390 stmt_q => 'SELECT * FROM `test` WHERE ( `a` < to_date(?, \'MM/DD/YY\') AND `b` = ? )',
391 bind => [[dummy => '02/02/02'], [b => 8]],
395 new => {bindtype => 'columns'},
396 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", '02/02/02']}],
397 throws => qr/bindtype 'columns' selected, you need to pass: \[column_name => bind_value\]/,
401 new => {bindtype => 'columns'},
402 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", '02/02/02']}, {a => {'between', [1,2]}}],
403 throws => qr/bindtype 'columns' selected, you need to pass: \[column_name => bind_value\]/,
407 new => {bindtype => 'columns'},
408 args => ['test', '*', { a => \["= to_date(?, 'MM/DD/YY')", '02/02/02']}],
409 throws => qr/bindtype 'columns' selected, you need to pass: \[column_name => bind_value\]/,
413 new => {bindtype => 'columns'},
414 args => ['test', '*', { a => {'<' => \["to_date(?, 'MM/DD/YY')", '02/02/02']}, b => 8 }],
415 throws => qr/bindtype 'columns' selected, you need to pass: \[column_name => bind_value\]/,
419 args => ['test', '*', { foo => { '>=' => [] }} ],
420 throws => qr/\Qoperator '>=' applied on an empty array (field 'foo')/,
424 new => {bindtype => 'columns'},
425 args => ['test', '*', { a => {-in => \["(SELECT d FROM to_date(?, 'MM/DD/YY') AS d)", [dummy => '02/02/02']]}, b => 8 }],
426 stmt => 'SELECT * FROM test WHERE ( a IN (SELECT d FROM to_date(?, \'MM/DD/YY\') AS d) AND b = ? )',
427 stmt_q => 'SELECT * FROM `test` WHERE ( `a` IN (SELECT d FROM to_date(?, \'MM/DD/YY\') AS d) AND `b` = ? )',
428 bind => [[dummy => '02/02/02'], [b => 8]],
432 new => {bindtype => 'columns'},
433 args => ['test', '*', { a => {-in => \["(SELECT d FROM to_date(?, 'MM/DD/YY') AS d)", '02/02/02']}, b => 8 }],
434 throws => qr/bindtype 'columns' selected, you need to pass: \[column_name => bind_value\]/,
438 new => {bindtype => 'columns'},
439 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", [{dummy => 1} => '02/02/02']]}],
440 stmt => 'INSERT INTO test (a, b) VALUES (?, to_date(?, \'MM/DD/YY\'))',
441 stmt_q => 'INSERT INTO `test` (`a`, `b`) VALUES (?, to_date(?, \'MM/DD/YY\'))',
442 bind => [[a => '1'], [{dummy => 1} => '02/02/02']],
446 new => {bindtype => 'columns'},
447 args => ['test', {a => 1, b => \["to_date(?, 'MM/DD/YY')", [{dummy => 1} => '02/02/02']], c => { -lower => 'foo' }}, {a => {'between', [1,2]}}],
448 stmt => "UPDATE test SET a = ?, b = to_date(?, 'MM/DD/YY'), c = LOWER ? WHERE ( a BETWEEN ? AND ? )",
449 stmt_q => "UPDATE `test` SET `a` = ?, `b` = to_date(?, 'MM/DD/YY'), `c` = LOWER ? WHERE ( `a` BETWEEN ? AND ? )",
450 bind => [[a => '1'], [{dummy => 1} => '02/02/02'], [c => 'foo'], [a => '1'], [a => '2']],
454 new => {bindtype => 'columns'},
455 args => ['test', '*', { a => \["= to_date(?, 'MM/DD/YY')", [{dummy => 1} => '02/02/02']]}],
456 stmt => q{SELECT * FROM test WHERE ( a = to_date(?, 'MM/DD/YY') )},
457 stmt_q => q{SELECT * FROM `test` WHERE ( `a` = to_date(?, 'MM/DD/YY') )},
458 bind => [[{dummy => 1} => '02/02/02']],
462 new => {bindtype => 'columns'},
463 args => ['test', '*', { a => {'<' => \["to_date(?, 'MM/DD/YY')", [{dummy => 1} => '02/02/02']]}, b => 8 }],
464 stmt => 'SELECT * FROM test WHERE ( a < to_date(?, \'MM/DD/YY\') AND b = ? )',
465 stmt_q => 'SELECT * FROM `test` WHERE ( `a` < to_date(?, \'MM/DD/YY\') AND `b` = ? )',
466 bind => [[{dummy => 1} => '02/02/02'], [b => 8]],
470 new => {bindtype => 'columns'},
471 args => ['test', '*', { -or => [ -and => [ a => 'a', b => 'b' ], -and => [ c => 'c', d => 'd' ] ] }],
472 stmt => 'SELECT * FROM test WHERE ( a = ? AND b = ? ) OR ( c = ? AND d = ? )',
473 stmt_q => 'SELECT * FROM `test` WHERE ( `a` = ? AND `b` = ? ) OR ( `c` = ? AND `d` = ? )',
474 bind => [[a => 'a'], [b => 'b'], [ c => 'c'],[ d => 'd']],
478 new => {bindtype => 'columns'},
479 args => ['test', '*', [ { a => 1, b => 1}, [ a => 2, b => 2] ] ],
480 stmt => 'SELECT * FROM test WHERE ( a = ? AND b = ? ) OR ( a = ? OR b = ? )',
481 stmt_q => 'SELECT * FROM `test` WHERE ( `a` = ? AND `b` = ? ) OR ( `a` = ? OR `b` = ? )',
482 bind => [[a => 1], [b => 1], [ a => 2], [ b => 2]],
486 new => {bindtype => 'columns'},
487 args => ['test', '*', [ [ a => 1, b => 1], { a => 2, b => 2 } ] ],
488 stmt => 'SELECT * FROM test WHERE ( a = ? OR b = ? ) OR ( a = ? AND b = ? )',
489 stmt_q => 'SELECT * FROM `test` WHERE ( `a` = ? OR `b` = ? ) OR ( `a` = ? AND `b` = ? )',
490 bind => [[a => 1], [b => 1], [ a => 2], [ b => 2]],
494 args => ['test', [qw/1 2 3 4 5/], { returning => 'id' }],
495 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?) RETURNING id',
496 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?) RETURNING `id`',
497 bind => [qw/1 2 3 4 5/],
501 args => ['test', [qw/1 2 3 4 5/], { returning => 'id, foo, bar' }],
502 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?) RETURNING id, foo, bar',
503 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?) RETURNING `id, foo, bar`',
504 bind => [qw/1 2 3 4 5/],
508 args => ['test', [qw/1 2 3 4 5/], { returning => [qw(id foo bar) ] }],
509 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?) RETURNING id, foo, bar',
510 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?) RETURNING `id`, `foo`, `bar`',
511 bind => [qw/1 2 3 4 5/],
515 args => ['test', [qw/1 2 3 4 5/], { returning => \'id, foo, bar' }],
516 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?) RETURNING id, foo, bar',
517 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?) RETURNING id, foo, bar',
518 bind => [qw/1 2 3 4 5/],
522 args => ['test', [qw/1 2 3 4 5/], { returning => \'id' }],
523 stmt => 'INSERT INTO test VALUES (?, ?, ?, ?, ?) RETURNING id',
524 stmt_q => 'INSERT INTO `test` VALUES (?, ?, ?, ?, ?) RETURNING id',
525 bind => [qw/1 2 3 4 5/],
529 new => {bindtype => 'columns'},
530 args => ['test', '*', [ Y => { '=' => { -max => { -LENGTH => { -min => 'x' } } } } ] ],
531 stmt => 'SELECT * FROM test WHERE ( Y = ( MAX( LENGTH( MIN ? ) ) ) )',
532 stmt_q => 'SELECT * FROM `test` WHERE ( `Y` = ( MAX( LENGTH( MIN ? ) ) ) )',
533 bind => [[Y => 'x']],
537 args => ['test', '*', { a => { -in => [] }, b => { -not_in => [] }, c => { -in => 42 } }],
538 stmt => 'SELECT * FROM test WHERE ( 0=1 AND 1=1 AND c IN ( ? ))',
539 stmt_q => 'SELECT * FROM `test` WHERE ( 0=1 AND 1=1 AND `c` IN ( ? ))',
544 args => ['test', '*', { a => { -in => [] }, b => { -not_in => [] } }],
545 stmt => 'SELECT * FROM test WHERE ( 0=1 AND 1=1 )',
546 stmt_q => 'SELECT * FROM `test` WHERE ( 0=1 AND 1=1 )',
551 \QSQL::Abstract before v1.75 used to generate incorrect SQL \E
552 \Qwhen the -IN operator was given an undef-containing list: \E
553 \Q!!!AUDIT YOUR CODE AND DATA!!! (the upcoming Data::Query-based \E
554 \Qversion of SQL::Abstract will emit the logically correct SQL \E
555 \Qinstead of raising this exception)\E
558 args => ['test', '*', { a => { -in => [42, undef] }, b => { -not_in => [42, undef] } } ],
559 stmt => 'SELECT * FROM test WHERE ( ( a IN ( ? ) OR a IS NULL ) AND b NOT IN ( ? ) AND b IS NOT NULL )',
560 stmt_q => 'SELECT * FROM `test` WHERE ( ( `a` IN ( ? ) OR `a` IS NULL ) AND `b` NOT IN ( ? ) AND `b` IS NOT NULL )',
565 \QSQL::Abstract before v1.75 used to generate incorrect SQL \E
566 \Qwhen the -IN operator was given an undef-containing list: \E
567 \Q!!!AUDIT YOUR CODE AND DATA!!! (the upcoming Data::Query-based \E
568 \Qversion of SQL::Abstract will emit the logically correct SQL \E
569 \Qinstead of raising this exception)\E
572 args => ['test', '*', { a => { -in => [undef] }, b => { -not_in => [undef] } } ],
573 stmt => 'SELECT * FROM test WHERE ( a IS NULL AND b IS NOT NULL )',
574 stmt_q => 'SELECT * FROM `test` WHERE ( `a` IS NULL AND `b` IS NOT NULL )',
579 args => ['test', '*', { a => { -in => undef } }],
580 throws => qr/Argument passed to the 'IN' operator can not be undefined/,
585 my $new = $t->{new} || {};
587 for my $quoted (0, 1) {
589 my $maker = SQL::Abstract->new(%$new, $quoted
590 ? (quote_char => '`', name_sep => '.')
598 ($stmt, @bind) = $maker->$op (@ { $t->{args} } );
601 if (my $e = $t->{throws}) {
616 $quoted ? $t->{stmt_q}: $t->{stmt},