refactor code needing version
[dbsrgits/DBIx-Class.git] / t / resultset / update_delete.t
CommitLineData
ff1234ad 1use strict;
2use warnings;
3
4use lib qw(t/lib);
5use Test::More;
6use Test::Exception;
31073ac7 7
8use DBICTest::Schema::CD;
9BEGIN {
10 # the default scalarref table name will not work well for this test
11 DBICTest::Schema::CD->table('cd');
12}
13
ff1234ad 14use DBICTest;
15
be64931c 16my $schema = DBICTest->init_schema;
17
ff1234ad 18my $tkfks = $schema->resultset('FourKeys_to_TwoKeys');
19
fd8076c8 20my ($fa, $fb, $fc) = $tkfks->related_resultset ('fourkeys')->populate ([
ff1234ad 21 [qw/foo bar hello goodbye sensors read_count/],
22 [qw/1 1 1 1 a 10 /],
23 [qw/2 2 2 2 b 20 /],
fd8076c8 24 [qw/1 1 1 2 c 30 /],
ff1234ad 25]);
26
27# This is already provided by DBICTest
28#my ($ta, $tb) = $tkfk->related_resultset ('twokeys')->populate ([
29# [qw/artist cd /],
30# [qw/1 1 /],
31# [qw/2 2 /],
32#]);
33my ($ta, $tb) = $schema->resultset ('TwoKeys')
34 ->search ( [ { artist => 1, cd => 1 }, { artist => 2, cd => 2 } ])
35 ->all;
36
37my $tkfk_cnt = $tkfks->count;
38
39my $non_void_ctx = $tkfks->populate ([
40 { autopilot => 'a', fourkeys => $fa, twokeys => $ta, pilot_sequence => 10 },
41 { autopilot => 'b', fourkeys => $fb, twokeys => $tb, pilot_sequence => 20 },
42 { autopilot => 'x', fourkeys => $fa, twokeys => $tb, pilot_sequence => 30 },
43 { autopilot => 'y', fourkeys => $fb, twokeys => $ta, pilot_sequence => 40 },
44]);
45is ($tkfks->count, $tkfk_cnt += 4, 'FourKeys_to_TwoKeys populated succesfully');
46
47#
48# Make sure the forced group by works (i.e. the joining does not cause double-updates)
49#
50
51# create a resultset matching $fa and $fb only
fd8076c8 52my $fks = $schema->resultset ('FourKeys')->search (
53 {
54 sensors => { '!=', 'c' },
55 ( map { $_ => [1, 2] } qw/foo bar hello goodbye/ ),
eb58c082 56 }, { join => { fourkeys_to_twokeys => 'twokeys' }}
fd8076c8 57);
ff1234ad 58
59is ($fks->count, 4, 'Joined FourKey count correct (2x2)');
2cfc22dd 60$schema->is_executed_sql_bind( sub {
61 $fks->update ({ read_count => \ 'read_count + 1' })
62}, [[
be64931c 63 'UPDATE fourkeys
64 SET read_count = read_count + 1
fd8076c8 65 WHERE ( ( ( bar = ? OR bar = ? ) AND ( foo = ? OR foo = ? ) AND ( goodbye = ? OR goodbye = ? ) AND ( hello = ? OR hello = ? ) AND sensors != ? ) )
66 ',
2cfc22dd 67 (1, 2) x 4,
68 'c',
69]], 'Correct update-SQL with multijoin with pruning' );
fd8076c8 70
71is ($fa->discard_changes->read_count, 11, 'Update ran only once on discard-join resultset');
72is ($fb->discard_changes->read_count, 21, 'Update ran only once on discard-join resultset');
73is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier');
74
75# make the multi-join stick
eb58c082 76my $fks_multi = $fks->search({ 'fourkeys_to_twokeys.pilot_sequence' => { '!=' => 666 } });
2cfc22dd 77$schema->is_executed_sql_bind( sub {
78 $fks_multi->update ({ read_count => \ 'read_count + 1' })
79}, [
80 [ 'BEGIN' ],
81 [
82 'SELECT me.foo, me.bar, me.hello, me.goodbye
83 FROM fourkeys me
84 LEFT JOIN fourkeys_to_twokeys fourkeys_to_twokeys
85 ON fourkeys_to_twokeys.f_bar = me.bar AND fourkeys_to_twokeys.f_foo = me.foo AND fourkeys_to_twokeys.f_goodbye = me.goodbye AND fourkeys_to_twokeys.f_hello = me.hello
86 WHERE ( bar = ? OR bar = ? ) AND ( foo = ? OR foo = ? ) AND fourkeys_to_twokeys.pilot_sequence != ? AND ( goodbye = ? OR goodbye = ? ) AND ( hello = ? OR hello = ? ) AND sensors != ?
87 GROUP BY me.foo, me.bar, me.hello, me.goodbye
88 ',
89 (1, 2) x 2,
90 666,
91 (1, 2) x 2,
92 'c',
93 ],
94 [
95 'UPDATE fourkeys
96 SET read_count = read_count + 1
97 WHERE ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? ) OR ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? )
98 ',
99 ( (1) x 4, (2) x 4 ),
100 ],
101 [ 'COMMIT' ],
102], 'Correct update-SQL with multijoin without pruning' );
ff1234ad 103
fd8076c8 104is ($fa->discard_changes->read_count, 12, 'Update ran only once on joined resultset');
105is ($fb->discard_changes->read_count, 22, 'Update ran only once on joined resultset');
106is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier');
be64931c 107
31160673 108$schema->is_executed_sql_bind( sub {
109 my $res = $fks_multi->search (\' "blah" = "bleh" ')->delete;
110 ok ($res, 'operation is true');
111 cmp_ok ($res, '==', 0, 'zero rows affected');
112}, [
113 [ 'BEGIN' ],
114 [
115 'SELECT me.foo, me.bar, me.hello, me.goodbye
116 FROM fourkeys me
117 LEFT JOIN fourkeys_to_twokeys fourkeys_to_twokeys
118 ON fourkeys_to_twokeys.f_bar = me.bar AND fourkeys_to_twokeys.f_foo = me.foo AND fourkeys_to_twokeys.f_goodbye = me.goodbye AND fourkeys_to_twokeys.f_hello = me.hello
119 WHERE "blah" = "bleh" AND ( bar = ? OR bar = ? ) AND ( foo = ? OR foo = ? ) AND fourkeys_to_twokeys.pilot_sequence != ? AND ( goodbye = ? OR goodbye = ? ) AND ( hello = ? OR hello = ? ) AND sensors != ?
120 GROUP BY me.foo, me.bar, me.hello, me.goodbye
121 ',
122 (1, 2) x 2,
123 666,
124 (1, 2) x 2,
125 'c',
126 ],
127 [ 'COMMIT' ],
128], 'Correct null-delete-SQL with multijoin without pruning' );
129
130
be64931c 131# try the same sql with forced multicolumn in
2cfc22dd 132$schema->is_executed_sql_bind( sub {
133 local $schema->storage->{_use_multicolumn_in} = 1;
134
135 # this can't actually execute on sqlite
136 eval { $fks_multi->update ({ read_count => \ 'read_count + 1' }) };
137}, [[
be64931c 138 'UPDATE fourkeys
139 SET read_count = read_count + 1
140 WHERE (
141 (foo, bar, hello, goodbye) IN (
142 SELECT me.foo, me.bar, me.hello, me.goodbye
143 FROM fourkeys me
fd8076c8 144 LEFT JOIN fourkeys_to_twokeys fourkeys_to_twokeys ON
145 fourkeys_to_twokeys.f_bar = me.bar
146 AND fourkeys_to_twokeys.f_foo = me.foo
147 AND fourkeys_to_twokeys.f_goodbye = me.goodbye
148 AND fourkeys_to_twokeys.f_hello = me.hello
8d005ad9 149 WHERE ( bar = ? OR bar = ? ) AND ( foo = ? OR foo = ? ) AND fourkeys_to_twokeys.pilot_sequence != ? AND ( goodbye = ? OR goodbye = ? ) AND ( hello = ? OR hello = ? ) AND sensors != ?
be64931c 150 )
151 )
152 ',
2cfc22dd 153 ( 1, 2) x 2,
154 666,
155 ( 1, 2) x 2,
156 'c',
157]], 'Correct update-SQL with multicolumn in support' );
158
159$schema->is_executed_sql_bind( sub {
160 $fks->search({ 'twokeys.artist' => { '!=' => 666 } })->update({ read_count => \ 'read_count + 1' });
161}, [
162 [ 'BEGIN' ],
fd8076c8 163 [
2cfc22dd 164 'SELECT me.foo, me.bar, me.hello, me.goodbye
165 FROM fourkeys me
166 LEFT JOIN fourkeys_to_twokeys fourkeys_to_twokeys
167 ON fourkeys_to_twokeys.f_bar = me.bar AND fourkeys_to_twokeys.f_foo = me.foo AND fourkeys_to_twokeys.f_goodbye = me.goodbye AND fourkeys_to_twokeys.f_hello = me.hello
168 LEFT JOIN twokeys twokeys
169 ON twokeys.artist = fourkeys_to_twokeys.t_artist AND twokeys.cd = fourkeys_to_twokeys.t_cd
170 WHERE ( bar = ? OR bar = ? ) AND ( foo = ? OR foo = ? ) AND ( goodbye = ? OR goodbye = ? ) AND ( hello = ? OR hello = ? ) AND sensors != ? AND twokeys.artist != ?
171 GROUP BY me.foo, me.bar, me.hello, me.goodbye
172 ',
173 (1, 2) x 4,
174 'c',
175 666,
fd8076c8 176 ],
2cfc22dd 177 [
178 'UPDATE fourkeys
179 SET read_count = read_count + 1
180 WHERE ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? ) OR ( bar = ? AND foo = ? AND goodbye = ? AND hello = ? )
181 ',
182 ( (1) x 4, (2) x 4 ),
183 ],
184 [ 'COMMIT' ],
185], 'Correct update-SQL with premultiplied restricting join without pruning' );
eb58c082 186
187is ($fa->discard_changes->read_count, 13, 'Update ran only once on joined resultset');
188is ($fb->discard_changes->read_count, 23, 'Update ran only once on joined resultset');
189is ($fc->discard_changes->read_count, 30, 'Update did not touch outlier');
190
ff1234ad 191#
be64931c 192# Make sure multicolumn in or the equivalent functions correctly
ff1234ad 193#
194
195my $sub_rs = $tkfks->search (
196 [
197 { map { $_ => 1 } qw/artist.artistid cd.cdid fourkeys.foo fourkeys.bar fourkeys.hello fourkeys.goodbye/ },
198 { map { $_ => 2 } qw/artist.artistid cd.cdid fourkeys.foo fourkeys.bar fourkeys.hello fourkeys.goodbye/ },
199 ],
200 {
201 join => [ 'fourkeys', { twokeys => [qw/artist cd/] } ],
202 },
203);
204
205is ($sub_rs->count, 2, 'Only two rows from fourkeys match');
206
207# attempts to delete a grouped rs should fail miserably
208throws_ok (
209 sub { $sub_rs->search ({}, { distinct => 1 })->delete },
210 qr/attempted a delete operation on a resultset which does group_by/,
211 'Grouped rs update/delete not allowed',
212);
213
214# grouping on PKs only should pass
af668ad6 215$sub_rs->search (
216 {},
217 {
be64931c 218 group_by => [ reverse $sub_rs->result_source->primary_columns ], # reverse to make sure the PK-list comparison works
af668ad6 219 },
220)->update ({ pilot_sequence => \ 'pilot_sequence + 1' });
ff1234ad 221
222is_deeply (
223 [ $tkfks->search ({ autopilot => [qw/a b x y/]}, { order_by => 'autopilot' })
8273e845 224 ->get_column ('pilot_sequence')->all
ff1234ad 225 ],
226 [qw/11 21 30 40/],
227 'Only two rows incremented',
228);
229
af668ad6 230# also make sure weird scalarref usage works (RT#51409)
231$tkfks->search (
232 \ 'pilot_sequence BETWEEN 11 AND 21',
233)->update ({ pilot_sequence => \ 'pilot_sequence + 1' });
234
235is_deeply (
236 [ $tkfks->search ({ autopilot => [qw/a b x y/]}, { order_by => 'autopilot' })
8273e845 237 ->get_column ('pilot_sequence')->all
af668ad6 238 ],
239 [qw/12 22 30 40/],
240 'Only two rows incremented (where => scalarref works)',
241);
242
59ac6523 243{
244 my $rs = $schema->resultset('FourKeys_to_TwoKeys')->search (
245 {
246 -or => [
247 { 'me.pilot_sequence' => 12 },
248 { 'me.autopilot' => 'b' },
249 ],
250 }
251 );
252 lives_ok { $rs->update({ autopilot => 'z' }) }
253 'Update with table name qualifier in -or conditions lives';
254 is_deeply (
255 [ $tkfks->search ({ pilot_sequence => [12, 22]})
256 ->get_column ('autopilot')->all
257 ],
258 [qw/z z/],
259 '... and yields the right data',
260 );
261}
262
263
ff1234ad 264$sub_rs->delete;
ff1234ad 265is ($tkfks->count, $tkfk_cnt -= 2, 'Only two rows deleted');
fef47a8e 266
267# make sure limit-only deletion works
268cmp_ok ($tkfk_cnt, '>', 1, 'More than 1 row left');
269$tkfks->search ({}, { rows => 1 })->delete;
270is ($tkfks->count, $tkfk_cnt -= 1, 'Only one row deleted');
271
887d8da0 272
fd8076c8 273# check with sql-equality, as sqlite will accept most bad sql just fine
fd8076c8 274{
275 my $rs = $schema->resultset('CD')->search(
276 { 'me.year' => { '!=' => 2010 } },
277 );
278
2cfc22dd 279 $schema->is_executed_sql_bind( sub {
280 $rs->search({}, { join => 'liner_notes' })->delete;
281 }, [[
fd8076c8 282 'DELETE FROM cd WHERE ( year != ? )',
2cfc22dd 283 2010,
284 ]], 'Non-restricting multijoins properly thrown out' );
fd8076c8 285
2cfc22dd 286 $schema->is_executed_sql_bind( sub {
287 $rs->search({}, { prefetch => 'liner_notes' })->delete;
288 }, [[
fd8076c8 289 'DELETE FROM cd WHERE ( year != ? )',
2cfc22dd 290 2010,
291 ]], 'Non-restricting multiprefetch thrown out' );
fd8076c8 292
2cfc22dd 293 $schema->is_executed_sql_bind( sub {
294 $rs->search({}, { prefetch => 'artist' })->delete;
295 }, [[
fd8076c8 296 'DELETE FROM cd WHERE ( cdid IN ( SELECT me.cdid FROM cd me JOIN artist artist ON artist.artistid = me.artist WHERE ( me.year != ? ) ) )',
2cfc22dd 297 2010,
298 ]], 'Restricting prefetch left in, selector thrown out');
fd8076c8 299
2cfc22dd 300### switch artist and cd to fully qualified table names
301### make sure nothing is stripped out
554f3621 302 my $cd_rsrc = $schema->source('CD');
303 $cd_rsrc->name('main.cd');
304 $cd_rsrc->relationship_info($_)->{attrs}{cascade_delete} = 0
305 for $cd_rsrc->relationships;
306
307 my $art_rsrc = $schema->source('Artist');
308 $art_rsrc->name(\'main.artist');
309 $art_rsrc->relationship_info($_)->{attrs}{cascade_delete} = 0
310 for $art_rsrc->relationships;
311
2cfc22dd 312 $schema->is_executed_sql_bind( sub {
313 $rs->delete
314 }, [[
315 'DELETE FROM main.cd WHERE year != ?',
316 2010,
317 ]], 'delete with fully qualified table name' );
554f3621 318
319 $rs->create({ title => 'foo', artist => 1, year => 2000 });
2cfc22dd 320 $schema->is_executed_sql_bind( sub {
321 $rs->delete_all
322 }, [
323 [ 'BEGIN' ],
324 [
325 'SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track FROM main.cd me WHERE me.year != ?',
326 2010,
327 ],
328 [
329 'DELETE FROM main.cd WHERE ( cdid = ? )',
330 1,
331 ],
332 [ 'COMMIT' ],
333 ], 'delete_all with fully qualified table name' );
554f3621 334
335 $rs->create({ cdid => 42, title => 'foo', artist => 2, year => 2000 });
2cfc22dd 336 my $cd42 = $rs->find(42);
337
338 $schema->is_executed_sql_bind( sub {
339 $cd42->delete
340 }, [[
341 'DELETE FROM main.cd WHERE cdid = ?',
342 42,
343 ]], 'delete of object from table with fully qualified name' );
344
345 $schema->is_executed_sql_bind( sub {
346 $cd42->related_resultset('artist')->delete
347 }, [[
554f3621 348 'DELETE FROM main.artist WHERE ( artistid IN ( SELECT me.artistid FROM main.artist me WHERE ( me.artistid = ? ) ) )',
2cfc22dd 349 2,
350 ]], 'delete of related object from scalarref fully qualified named table' );
351
352 my $art3 = $schema->resultset('Artist')->find(3);
554f3621 353
2cfc22dd 354 $schema->is_executed_sql_bind( sub {
355 $art3->related_resultset('cds')->delete;
356 }, [[
554f3621 357 'DELETE FROM main.cd WHERE ( artist = ? )',
2cfc22dd 358 3,
359 ]], 'delete of related object from fully qualified named table' );
fd8076c8 360
2cfc22dd 361 $schema->is_executed_sql_bind( sub {
362 $art3->cds_unordered->delete;
363 }, [[
554f3621 364 'DELETE FROM main.cd WHERE ( artist = ? )',
2cfc22dd 365 3,
366 ]], 'delete of related object from fully qualified named table via relaccessor' );
554f3621 367
2cfc22dd 368 $schema->is_executed_sql_bind( sub {
369 $rs->search({}, { prefetch => 'artist' })->delete;
370 }, [[
554f3621 371 'DELETE FROM main.cd WHERE ( cdid IN ( SELECT me.cdid FROM main.cd me JOIN main.artist artist ON artist.artistid = me.artist WHERE ( me.year != ? ) ) )',
2cfc22dd 372 2010,
373 ]], 'delete with fully qualified table name and subquery correct' );
fd8076c8 374
31073ac7 375 # check that as_subselect_rs works ok
376 # inner query is untouched, then a selector
377 # and an IN condition
2cfc22dd 378 $schema->is_executed_sql_bind( sub {
379 $schema->resultset('CD')->search({
380 'me.cdid' => 1,
381 'artist.name' => 'partytimecity',
382 }, {
383 join => 'artist',
384 })->as_subselect_rs->delete;
385 }, [[
31073ac7 386 '
554f3621 387 DELETE FROM main.cd
31073ac7 388 WHERE (
389 cdid IN (
390 SELECT me.cdid
391 FROM (
392 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
554f3621 393 FROM main.cd me
394 JOIN main.artist artist ON artist.artistid = me.artist
31073ac7 395 WHERE artist.name = ? AND me.cdid = ?
396 ) me
397 )
398 )
399 ',
2cfc22dd 400 'partytimecity',
401 1,
402 ]], 'Delete from as_subselect_rs works correctly' );
fd8076c8 403}
887d8da0 404
fef47a8e 405done_testing;