Commit | Line | Data |
4bea1fe7 |
1 | use strict; |
2 | use warnings; |
3 | |
4 | use Test::Exception; |
5 | use Test::More; |
6 | use Sub::Name; |
00a28188 |
7 | use Try::Tiny; |
199fbc45 |
8 | use DBIx::Class::Optional::Dependencies (); |
4bea1fe7 |
9 | |
10 | use lib qw(t/lib); |
11 | use DBICTest; |
12 | use DBIC::SqlMakerTest; |
13 | |
4bea1fe7 |
14 | my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/}; |
15 | |
16 | # optional: |
17 | my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_ORA_EXTRAUSER_${_}" } qw/DSN USER PASS/}; |
18 | |
19 | plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test.' |
20 | unless ($dsn && $user && $pass); |
21 | |
e6983054 |
22 | plan skip_all => 'Test needs ' . DBIx::Class::Optional::Dependencies->req_missing_for ('test_rdbms_oracle') |
23 | unless DBIx::Class::Optional::Dependencies->req_ok_for ('test_rdbms_oracle'); |
24 | |
25 | $ENV{NLS_SORT} = "BINARY"; |
26 | $ENV{NLS_COMP} = "BINARY"; |
27 | $ENV{NLS_LANG} = "AMERICAN"; |
28 | |
cb464582 |
29 | { |
30 | package # hide from PAUSE |
31 | DBICTest::Schema::ArtistFQN; |
32 | |
33 | use base 'DBIx::Class::Core'; |
34 | |
35 | __PACKAGE__->table( |
a6646e1b |
36 | $ENV{DBICTEST_ORA_USER} |
07cda1c5 |
37 | ? (uc $ENV{DBICTEST_ORA_USER}) . '.artist' |
a6646e1b |
38 | : '??_no_user_??' |
cb464582 |
39 | ); |
40 | __PACKAGE__->add_columns( |
07cda1c5 |
41 | 'artistid' => { |
42 | data_type => 'integer', |
43 | is_auto_increment => 1, |
44 | }, |
45 | 'name' => { |
46 | data_type => 'varchar', |
47 | size => 100, |
48 | is_nullable => 1, |
49 | }, |
50 | 'autoinc_col' => { |
51 | data_type => 'integer', |
52 | is_auto_increment => 1, |
53 | }, |
8b9473f5 |
54 | 'default_value_col' => { |
55 | data_type => 'varchar', |
56 | size => 100, |
57 | is_nullable => 0, |
58 | retrieve_on_insert => 1, |
59 | } |
cb464582 |
60 | ); |
bf51641f |
61 | __PACKAGE__->set_primary_key(qw/ artistid autoinc_col /); |
cb464582 |
62 | |
63 | 1; |
64 | } |
65 | |
cb464582 |
66 | DBICTest::Schema->load_classes('ArtistFQN'); |
0567538f |
67 | |
07cda1c5 |
68 | # This is in Core now, but it's here just to test that it doesn't break |
69 | DBICTest::Schema::Artist->load_components('PK::Auto'); |
70 | # These are compat shims for PK::Auto... |
71 | DBICTest::Schema::CD->load_components('PK::Auto::Oracle'); |
72 | DBICTest::Schema::Track->load_components('PK::Auto::Oracle'); |
ba12b23f |
73 | |
0567538f |
74 | |
bf51641f |
75 | # check if we indeed do support stuff |
f116ff4e |
76 | my $v = do { |
77 | my $v = DBICTest::Schema->connect($dsn, $user, $pass)->storage->_dbh_get_info(18); |
bf51641f |
78 | $v =~ /^(\d+)\.(\d+)/ |
79 | or die "Unparseable Oracle server version: $v\n"; |
80 | |
f116ff4e |
81 | sprintf('%d.%03d', $1, $2); |
82 | }; |
83 | |
538878de |
84 | my $test_server_supports_only_orajoins = $v < 9; |
f116ff4e |
85 | |
bf51641f |
86 | # TODO find out which version supports the RETURNING syntax |
86b23415 |
87 | # 8i (8.1) has it and earlier docs are a 404 on oracle.com |
f116ff4e |
88 | my $test_server_supports_insert_returning = $v >= 8.001; |
89 | |
bf51641f |
90 | is ( |
91 | DBICTest::Schema->connect($dsn, $user, $pass)->storage->_use_insert_returning, |
92 | $test_server_supports_insert_returning, |
93 | 'insert returning capability guessed correctly' |
94 | ); |
95 | |
f116ff4e |
96 | ########## |
538878de |
97 | # the recyclebin (new for 10g) sometimes comes in the way |
98 | my $on_connect_sql = $v >= 10 ? ["ALTER SESSION SET recyclebin = OFF"] : []; |
f116ff4e |
99 | |
100 | # iterate all tests on following options |
101 | my @tryopt = ( |
102 | { on_connect_do => $on_connect_sql }, |
103 | { quote_char => '"', on_connect_do => $on_connect_sql }, |
104 | ); |
105 | |
106 | # keep a database handle open for cleanup |
107 | my ($dbh, $dbh2); |
108 | |
bf51641f |
109 | my $schema; |
f116ff4e |
110 | for my $use_insert_returning ($test_server_supports_insert_returning ? (1,0) : (0) ) { |
111 | for my $force_ora_joins ($test_server_supports_only_orajoins ? (0) : (0,1) ) { |
112 | |
113 | no warnings qw/once/; |
114 | local *DBICTest::Schema::connection = subname 'DBICTest::Schema::connection' => sub { |
115 | my $s = shift->next::method (@_); |
116 | $s->storage->_use_insert_returning ($use_insert_returning); |
117 | $s->storage->sql_maker_class('DBIx::Class::SQLMaker::OracleJoins') if $force_ora_joins; |
118 | $s; |
119 | }; |
120 | |
121 | for my $opt (@tryopt) { |
122 | # clean all cached sequences from previous run |
123 | for (map { values %{DBICTest::Schema->source($_)->columns_info} } (qw/Artist CD Track/) ) { |
124 | delete $_->{sequence}; |
125 | } |
bf51641f |
126 | |
f116ff4e |
127 | my $schema = DBICTest::Schema->connect($dsn, $user, $pass, $opt); |
07cda1c5 |
128 | |
f116ff4e |
129 | $dbh = $schema->storage->dbh; |
130 | my $q = $schema->storage->sql_maker->quote_char || ''; |
bf51641f |
131 | |
f116ff4e |
132 | do_creates($dbh, $q); |
bf51641f |
133 | |
f116ff4e |
134 | _run_tests($schema, $opt); |
135 | } |
bf51641f |
136 | } |
137 | } |
07cda1c5 |
138 | |
bf51641f |
139 | sub _run_tests { |
140 | my ($schema, $opt) = @_; |
07cda1c5 |
141 | |
bf51641f |
142 | my $q = $schema->storage->sql_maker->quote_char || ''; |
ab4f4e4c |
143 | |
144 | # test primary key handling with multiple triggers |
07cda1c5 |
145 | my ($new, $seq); |
0567538f |
146 | |
bf51641f |
147 | my $new_artist = $schema->resultset('Artist')->create({ name => 'foo' }); |
148 | my $new_cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' }); |
6f5f880d |
149 | |
bf51641f |
150 | SKIP: { |
151 | skip 'not detecting sequences when using INSERT ... RETURNING', 4 |
152 | if $schema->storage->_use_insert_returning; |
153 | |
154 | is($new_artist->artistid, 1, "Oracle Auto-PK worked for standard sqlt-like trigger"); |
155 | $seq = $new_artist->result_source->column_info('artistid')->{sequence}; |
156 | $seq = $$seq if ref $seq; |
157 | like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger'); |
158 | |
159 | is($new_cd->cdid, 1, 'Oracle Auto-PK worked - using scalar ref as table name/custom weird trigger'); |
160 | $seq = $new_cd->result_source->column_info('cdid')->{sequence}; |
161 | $seq = $$seq if ref $seq; |
162 | like ($seq, qr/\.${q}cd_seq${q}$/, 'Correct PK sequence selected for custom trigger'); |
163 | } |
e6dd7b42 |
164 | |
07cda1c5 |
165 | # test PKs again with fully-qualified table name |
166 | my $artistfqn_rs = $schema->resultset('ArtistFQN'); |
167 | my $artist_rsrc = $artistfqn_rs->result_source; |
ab4f4e4c |
168 | |
07cda1c5 |
169 | delete $artist_rsrc->column_info('artistid')->{sequence}; |
170 | $new = $artistfqn_rs->create( { name => 'bar' } ); |
ab4f4e4c |
171 | |
bf51641f |
172 | is_deeply( {map { $_ => $new->$_ } $artist_rsrc->primary_columns}, |
173 | { artistid => 2, autoinc_col => 2}, |
174 | "Oracle Multi-Auto-PK worked with fully-qualified tablename" ); |
cb464582 |
175 | |
ab4f4e4c |
176 | |
07cda1c5 |
177 | delete $artist_rsrc->column_info('artistid')->{sequence}; |
178 | $new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } ); |
179 | |
180 | is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" ); |
181 | is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename"); |
bf51641f |
182 | |
8b9473f5 |
183 | |
184 | is( $new->default_value_col, 'default_value', $schema->storage->_use_insert_returning |
185 | ? 'Check retrieve_on_insert on default_value_col with INSERT ... RETURNING' |
186 | : 'Check retrieve_on_insert on default_value_col without INSERT ... RETURNING' |
187 | ); |
188 | |
bf51641f |
189 | SKIP: { |
190 | skip 'not detecting sequences when using INSERT ... RETURNING', 1 |
191 | if $schema->storage->_use_insert_returning; |
192 | |
193 | $seq = $new->result_source->column_info('artistid')->{sequence}; |
194 | $seq = $$seq if ref $seq; |
195 | like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger'); |
196 | } |
ab4f4e4c |
197 | |
ab4f4e4c |
198 | |
199 | # test LIMIT support |
07cda1c5 |
200 | for (1..6) { |
ab4f4e4c |
201 | $schema->resultset('Artist')->create({ name => 'Artist ' . $_ }); |
07cda1c5 |
202 | } |
203 | my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' } }, { |
204 | rows => 3, |
205 | offset => 4, |
206 | order_by => 'artistid' |
207 | }); |
208 | |
209 | is( $it->count, 2, "LIMIT count past end of RS ok" ); |
210 | is( $it->next->name, "Artist 5", "iterator->next ok" ); |
211 | is( $it->next->name, "Artist 6", "iterator->next ok" ); |
212 | is( $it->next, undef, "next past end of resultset ok" ); |
213 | |
07cda1c5 |
214 | # test identifiers over the 30 char limit |
215 | lives_ok { |
216 | my @results = $schema->resultset('CD')->search(undef, { |
217 | prefetch => 'very_long_artist_relationship', |
218 | rows => 3, |
219 | offset => 0, |
220 | })->all; |
221 | ok( scalar @results > 0, 'limit with long identifiers returned something'); |
222 | } 'limit with long identifiers executed successfully'; |
ab4f4e4c |
223 | |
ab4f4e4c |
224 | |
62d4dbae |
225 | # test rel names over the 30 char limit |
ab4f4e4c |
226 | my $query = $schema->resultset('Artist')->search({ |
227 | artistid => 1 |
6c0230de |
228 | }, { |
229 | prefetch => 'cds_very_very_very_long_relationship_name' |
230 | }); |
231 | |
232 | lives_and { |
07cda1c5 |
233 | is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1 |
ab4f4e4c |
234 | } 'query with rel name over 30 chars survived and worked'; |
235 | |
19c4cc62 |
236 | # test rel names over the 30 char limit using group_by and join |
237 | { |
238 | my @group_cols = ( 'me.name' ); |
239 | my $query = $schema->resultset('Artist')->search({ |
240 | artistid => 1 |
241 | }, { |
242 | select => \@group_cols, |
243 | as => [map { /^\w+\.(\w+)$/ } @group_cols], |
244 | join => [qw( cds_very_very_very_long_relationship_name )], |
245 | group_by => \@group_cols, |
246 | }); |
247 | |
248 | lives_and { |
249 | my @got = $query->get_column('name')->all(); |
250 | is_deeply \@got, [$new_artist->name]; |
251 | } 'query with rel name over 30 chars worked on join, group_by for me col'; |
252 | |
253 | lives_and { |
254 | is $query->count(), 1 |
255 | } 'query with rel name over 30 chars worked on join, group_by, count for me col'; |
256 | } |
257 | { |
258 | my @group_cols = ( 'cds_very_very_very_long_relationship_name.title' ); |
259 | my $query = $schema->resultset('Artist')->search({ |
260 | artistid => 1 |
261 | }, { |
262 | select => \@group_cols, |
263 | as => [map { /^\w+\.(\w+)$/ } @group_cols], |
264 | join => [qw( cds_very_very_very_long_relationship_name )], |
265 | group_by => \@group_cols, |
266 | }); |
267 | |
268 | lives_and { |
269 | my @got = $query->get_column('title')->all(); |
270 | is_deeply \@got, [$new_cd->title]; |
271 | } 'query with rel name over 30 chars worked on join, group_by for long rel col'; |
272 | |
273 | lives_and { |
274 | is $query->count(), 1 |
275 | } 'query with rel name over 30 chars worked on join, group_by, count for long rel col'; |
276 | } |
277 | |
ab4f4e4c |
278 | # rel name over 30 char limit with user condition |
279 | # This requires walking the SQLA data structure. |
280 | { |
ab4f4e4c |
281 | $query = $schema->resultset('Artist')->search({ |
282 | 'cds_very_very_very_long_relationship_name.title' => 'EP C' |
283 | }, { |
284 | prefetch => 'cds_very_very_very_long_relationship_name' |
285 | }); |
286 | |
287 | lives_and { |
288 | is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1 |
289 | } 'query with rel name over 30 chars and user condition survived and worked'; |
290 | } |
07cda1c5 |
291 | |
6c0230de |
292 | |
9900b569 |
293 | # test join with row count ambiguity |
07cda1c5 |
294 | my $cd = $schema->resultset('CD')->next; |
295 | my $track = $cd->create_related('tracks', { position => 1, title => 'Track1'} ); |
296 | my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, { |
297 | join => 'cd', rows => 2 |
298 | }); |
d2a3958e |
299 | |
07cda1c5 |
300 | ok(my $row = $tjoin->next); |
301 | |
302 | is($row->title, 'Track1', "ambiguous column ok"); |
2660b14e |
303 | |
d2a3958e |
304 | |
2660b14e |
305 | |
286f32b3 |
306 | # check count distinct with multiple columns |
07cda1c5 |
307 | my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' }); |
11d68671 |
308 | |
07cda1c5 |
309 | my $tcount = $schema->resultset('Track')->search( |
310 | {}, |
311 | { |
312 | select => [ qw/position title/ ], |
313 | distinct => 1, |
314 | } |
315 | ); |
316 | is($tcount->count, 2, 'multiple column COUNT DISTINCT ok'); |
11d68671 |
317 | |
07cda1c5 |
318 | $tcount = $schema->resultset('Track')->search( |
319 | {}, |
320 | { |
321 | columns => [ qw/position title/ ], |
322 | distinct => 1, |
323 | } |
324 | ); |
325 | is($tcount->count, 2, 'multiple column COUNT DISTINCT ok'); |
286f32b3 |
326 | |
07cda1c5 |
327 | $tcount = $schema->resultset('Track')->search( |
328 | {}, |
329 | { |
330 | group_by => [ qw/position title/ ] |
331 | } |
332 | ); |
333 | is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok'); |
2660b14e |
334 | |
e8e971f2 |
335 | |
07cda1c5 |
336 | # check group_by |
337 | my $g_rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset => 1 }); |
338 | is( scalar $g_rs->all, 1, "Group by with limit OK" ); |
339 | |
bd691933 |
340 | |
b7b18f32 |
341 | # test with_deferred_fk_checks |
07cda1c5 |
342 | lives_ok { |
343 | $schema->storage->with_deferred_fk_checks(sub { |
344 | $schema->resultset('Track')->create({ |
345 | trackid => 999, cd => 999, position => 1, title => 'deferred FK track' |
346 | }); |
347 | $schema->resultset('CD')->create({ |
348 | artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd' |
349 | }); |
b7b18f32 |
350 | }); |
07cda1c5 |
351 | } 'with_deferred_fk_checks code survived'; |
b7b18f32 |
352 | |
07cda1c5 |
353 | is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track', |
8b9473f5 |
354 | 'code in with_deferred_fk_checks worked'; |
07cda1c5 |
355 | |
356 | throws_ok { |
357 | $schema->resultset('Track')->create({ |
358 | trackid => 1, cd => 9999, position => 1, title => 'Track1' |
359 | }); |
360 | } qr/constraint/i, 'with_deferred_fk_checks is off'; |
b7b18f32 |
361 | |
b7b18f32 |
362 | |
ccd6f984 |
363 | # test auto increment using sequences WITHOUT triggers |
07cda1c5 |
364 | for (1..5) { |
39b8d119 |
365 | my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' }); |
366 | is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key"); |
367 | is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key"); |
368 | is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key"); |
07cda1c5 |
369 | } |
370 | my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 }); |
371 | is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually"); |
372 | |
ccd6f984 |
373 | |
12e05c15 |
374 | # test BLOBs |
07cda1c5 |
375 | SKIP: { |
376 | TODO: { |
377 | my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) ); |
378 | $binstr{'large'} = $binstr{'small'} x 1024; |
8068691e |
379 | |
00a28188 |
380 | my $maxloblen = (length $binstr{'large'}) + 5; |
07cda1c5 |
381 | note "Localizing LongReadLen to $maxloblen to avoid truncation of test data"; |
382 | local $dbh->{'LongReadLen'} = $maxloblen; |
5db2758d |
383 | |
07cda1c5 |
384 | my $rs = $schema->resultset('BindType'); |
5db2758d |
385 | |
07cda1c5 |
386 | if ($DBD::Oracle::VERSION eq '1.23') { |
387 | throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) } |
388 | qr/broken/, |
389 | 'throws on blob insert with DBD::Oracle == 1.23'; |
5db2758d |
390 | |
00a28188 |
391 | skip 'buggy BLOB support in DBD::Oracle 1.23', 1; |
07cda1c5 |
392 | } |
5db2758d |
393 | |
07cda1c5 |
394 | # disable BLOB mega-output |
395 | my $orig_debug = $schema->storage->debug; |
f3f6c13a |
396 | |
07cda1c5 |
397 | local $TODO = 'Something is confusing column bindtype assignment when quotes are active' |
86b23415 |
398 | . ': https://rt.cpan.org/Ticket/Display.html?id=64206' |
07cda1c5 |
399 | if $q; |
5db2758d |
400 | |
00a28188 |
401 | my $id; |
402 | foreach my $size (qw( small large )) { |
403 | $id++; |
d7f20fdf |
404 | |
00819de0 |
405 | if ($size eq 'small') { |
406 | $schema->storage->debug($orig_debug); |
407 | } |
408 | elsif ($size eq 'large') { |
409 | $schema->storage->debug(0); |
410 | } |
411 | |
00a28188 |
412 | my $str = $binstr{$size}; |
413 | lives_ok { |
414 | $rs->create( { 'id' => $id, blob => "blob:$str", clob => "clob:$str" } ) |
415 | } "inserted $size without dying"; |
416 | |
5e782048 |
417 | my %kids = %{$schema->storage->_dbh->{CachedKids}}; |
00a28188 |
418 | my @objs = $rs->search({ blob => "blob:$str", clob => "clob:$str" })->all; |
5e782048 |
419 | is_deeply ( |
420 | $schema->storage->_dbh->{CachedKids}, |
421 | \%kids, |
422 | 'multi-part LOB equality query was not cached', |
423 | ) if $size eq 'large'; |
424 | is @objs, 1, 'One row found matching on both LOBs'; |
00a28188 |
425 | ok (try { $objs[0]->blob }||'' eq "blob:$str", 'blob inserted/retrieved correctly'); |
426 | ok (try { $objs[0]->clob }||'' eq "clob:$str", 'clob inserted/retrieved correctly'); |
427 | |
b1efaea0 |
428 | TODO: { |
429 | local $TODO = '-like comparison on blobs not tested before ora 10 (fails on 8i)' |
430 | if $schema->storage->_server_info->{normalized_dbms_version} < 10; |
431 | |
432 | lives_ok { |
433 | @objs = $rs->search({ clob => { -like => 'clob:%' } })->all; |
434 | ok (@objs, 'rows found matching CLOB with a LIKE query'); |
435 | } 'Query with like on blob succeeds'; |
436 | } |
00a28188 |
437 | |
5e782048 |
438 | ok(my $subq = $rs->search( |
439 | { blob => "blob:$str", clob => "clob:$str" }, |
440 | { |
441 | from => \ "(SELECT * FROM ${q}bindtype_test${q} WHERE ${q}id${q} != ?) ${q}me${q}", |
442 | bind => [ [ undef => 12345678 ] ], |
443 | } |
444 | )->get_column('id')->as_query); |
00a28188 |
445 | |
446 | @objs = $rs->search({ id => { -in => $subq } })->all; |
447 | is (@objs, 1, 'One row found matching on both LOBs as a subquery'); |
5e782048 |
448 | |
449 | lives_ok { |
00819de0 |
450 | $rs->search({ id => $id, blob => "blob:$str", clob => "clob:$str" }) |
5e782048 |
451 | ->update({ blob => 'updated blob', clob => 'updated clob' }); |
e12571af |
452 | } 'blob UPDATE with blobs in WHERE clause survived'; |
5e782048 |
453 | |
454 | @objs = $rs->search({ blob => "updated blob", clob => 'updated clob' })->all; |
455 | is @objs, 1, 'found updated row'; |
456 | ok (try { $objs[0]->blob }||'' eq "updated blob", 'blob updated/retrieved correctly'); |
457 | ok (try { $objs[0]->clob }||'' eq "updated clob", 'clob updated/retrieved correctly'); |
458 | |
459 | lives_ok { |
e12571af |
460 | $rs->search({ id => $id }) |
461 | ->update({ blob => 're-updated blob', clob => 're-updated clob' }); |
462 | } 'blob UPDATE without blobs in WHERE clause survived'; |
463 | |
464 | @objs = $rs->search({ blob => 're-updated blob', clob => 're-updated clob' })->all; |
465 | is @objs, 1, 'found updated row'; |
466 | ok (try { $objs[0]->blob }||'' eq 're-updated blob', 'blob updated/retrieved correctly'); |
467 | ok (try { $objs[0]->clob }||'' eq 're-updated clob', 'clob updated/retrieved correctly'); |
468 | |
469 | lives_ok { |
470 | $rs->search({ blob => "re-updated blob", clob => "re-updated clob" }) |
5e782048 |
471 | ->delete; |
472 | } 'blob DELETE with WHERE clause survived'; |
e12571af |
473 | @objs = $rs->search({ blob => "re-updated blob", clob => 're-updated clob' })->all; |
5e782048 |
474 | is @objs, 0, 'row deleted successfully'; |
d7f20fdf |
475 | } |
f3f6c13a |
476 | |
07cda1c5 |
477 | $schema->storage->debug ($orig_debug); |
478 | }} |
479 | |
a5a27e7a |
480 | # test populate (identity, success and error handling) |
481 | my $art_rs = $schema->resultset('Artist'); |
482 | |
483 | my $seq_pos = $art_rs->get_column('artistid')->max; |
484 | ok($seq_pos, 'Starting with something in the artist table'); |
485 | |
486 | |
487 | my $pop_rs = $schema->resultset('Artist')->search( |
488 | { name => { -like => 'pop_art_%' } }, |
489 | { order_by => 'artistid' } |
490 | ); |
491 | |
492 | $art_rs->delete; |
493 | lives_ok { |
494 | $pop_rs->populate([ |
495 | map { +{ name => "pop_art_$_" } } |
496 | (1,2,3) |
497 | ]); |
498 | |
499 | is_deeply ( |
500 | [ $pop_rs->get_column('artistid')->all ], |
501 | [ map { $seq_pos + $_ } (1,2,3) ], |
502 | 'Sequence works after empty-table insertion' |
503 | ); |
504 | } 'Populate without identity does not throw'; |
505 | |
506 | lives_ok { |
507 | $pop_rs->populate([ |
508 | map { +{ artistid => $_, name => "pop_art_$_" } } |
509 | (1,2,3) |
510 | ]); |
511 | |
512 | is_deeply ( |
513 | [ $pop_rs->get_column('artistid')->all ], |
514 | [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ], |
515 | 'Explicit id population works' |
516 | ); |
517 | } 'Populate with identity does not throw'; |
518 | |
519 | throws_ok { |
520 | $pop_rs->populate([ |
521 | map { +{ artistid => $_, name => "pop_art_$_" } } |
522 | (200, 1, 300) |
523 | ]); |
524 | } qr/unique constraint.+populate slice.+name => "pop_art_1"/s, 'Partially failed populate throws'; |
525 | |
526 | is_deeply ( |
527 | [ $pop_rs->get_column('artistid')->all ], |
528 | [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ], |
529 | 'Partially failed populate did not alter table contents' |
530 | ); |
5db2758d |
531 | |
f116ff4e |
532 | # test complex join (exercise orajoins) |
533 | lives_ok { |
534 | my @hri = $schema->resultset('CD')->search( |
535 | { 'artist.name' => 'pop_art_1', 'me.cdid' => { '!=', 999} }, |
536 | { join => 'artist', prefetch => 'tracks', rows => 4, order_by => 'tracks.trackid' } |
537 | )->hri_dump->all; |
538 | |
539 | my $expect = [{ |
540 | artist => 1, |
541 | cdid => 1, |
542 | genreid => undef, |
543 | single_track => undef, |
544 | title => "EP C", |
545 | tracks => [ |
546 | { |
547 | cd => 1, |
548 | last_updated_at => undef, |
549 | last_updated_on => undef, |
550 | position => 1, |
551 | title => "Track1", |
552 | trackid => 1 |
553 | }, |
554 | { |
555 | cd => 1, |
556 | last_updated_at => undef, |
557 | last_updated_on => undef, |
558 | position => 1, |
559 | title => "Track2", |
560 | trackid => 2 |
561 | }, |
562 | ], |
563 | year => 2003 |
564 | }]; |
565 | |
566 | is_deeply ( |
567 | \@hri, |
568 | $expect, |
569 | 'Correct set of data prefetched', |
570 | ); |
571 | |
572 | } 'complex prefetch ok'; |
573 | |
df6e3f5c |
574 | # test sequence detection from a different schema |
07cda1c5 |
575 | SKIP: { |
576 | TODO: { |
577 | skip ((join '', |
578 | 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user', |
bf51641f |
579 | ' to run the cross-schema sequence detection test.'), |
07cda1c5 |
580 | 1) unless $dsn2 && $user2 && $user2 ne $user; |
9d7d2f00 |
581 | |
bf51641f |
582 | skip 'not detecting cross-schema sequence name when using INSERT ... RETURNING', 1 |
583 | if $schema->storage->_use_insert_returning; |
584 | |
8b9473f5 |
585 | # Oracle8i Reference Release 2 (8.1.6) |
07cda1c5 |
586 | # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993 |
587 | # Oracle Database Reference 10g Release 2 (10.2) |
588 | # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297 |
589 | local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..." |
590 | if $schema->storage->_server_info->{normalized_dbms_version} < 9; |
606b30c3 |
591 | |
bf51641f |
592 | my $schema2 = $schema->connect($dsn2, $user2, $pass2, $opt); |
a6646e1b |
593 | my $dbh2 = $schema2->storage->dbh; |
df6e3f5c |
594 | |
a6646e1b |
595 | # create identically named tables/sequences in the other schema |
596 | do_creates($dbh2, $q); |
df6e3f5c |
597 | |
a6646e1b |
598 | # grand select privileges to the 2nd user |
599 | $dbh->do("GRANT INSERT ON ${q}artist${q} TO " . uc $user2); |
8b9473f5 |
600 | $dbh->do("GRANT SELECT ON ${q}artist${q} TO " . uc $user2); |
a6646e1b |
601 | $dbh->do("GRANT SELECT ON ${q}artist_pk_seq${q} TO " . uc $user2); |
602 | $dbh->do("GRANT SELECT ON ${q}artist_autoinc_seq${q} TO " . uc $user2); |
df6e3f5c |
603 | |
a6646e1b |
604 | # test with a fully qualified table (user1/schema prepended) |
605 | my $rs2 = $schema2->resultset('ArtistFQN'); |
606 | delete $rs2->result_source->column_info('artistid')->{sequence}; |
df6e3f5c |
607 | |
07cda1c5 |
608 | lives_and { |
a6646e1b |
609 | my $row = $rs2->create({ name => 'From Different Schema' }); |
07cda1c5 |
610 | ok $row->artistid; |
611 | } 'used autoinc sequence across schemas'; |
612 | |
613 | # now quote the sequence name (do_creates always uses an lc name) |
614 | my $q_seq = $q |
615 | ? '"artist_pk_seq"' |
616 | : '"ARTIST_PK_SEQ"' |
617 | ; |
a6646e1b |
618 | delete $rs2->result_source->column_info('artistid')->{sequence}; |
619 | $dbh->do(qq{ |
07cda1c5 |
620 | CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q} |
621 | BEFORE INSERT ON ${q}artist${q} |
622 | FOR EACH ROW |
623 | BEGIN |
624 | IF :new.${q}artistid${q} IS NULL THEN |
625 | SELECT $q_seq.nextval |
626 | INTO :new.${q}artistid${q} |
627 | FROM DUAL; |
628 | END IF; |
629 | END; |
630 | }); |
72044892 |
631 | |
72044892 |
632 | |
07cda1c5 |
633 | lives_and { |
a6646e1b |
634 | my $row = $rs2->create({ name => 'From Different Schema With Quoted Sequence' }); |
07cda1c5 |
635 | ok $row->artistid; |
636 | } 'used quoted autoinc sequence across schemas'; |
72044892 |
637 | |
a6646e1b |
638 | is_deeply $rs2->result_source->column_info('artistid')->{sequence}, |
639 | \( (uc $user) . ".$q_seq"), |
07cda1c5 |
640 | 'quoted sequence name correctly extracted'; |
a6646e1b |
641 | |
642 | # try an insert operation on the default user2 artist |
643 | my $art1 = $schema->resultset('Artist'); |
644 | my $art2 = $schema2->resultset('Artist'); |
645 | my $art1_count = $art1->count || 0; |
646 | my $art2_count = $art2->count; |
647 | |
648 | is( $art2_count, 0, 'No artists created yet in second schema' ); |
649 | |
650 | delete $art2->result_source->column_info('artistid')->{sequence}; |
651 | my $new_art = $art2->create({ name => '2nd best' }); |
652 | |
653 | is ($art1->count, $art1_count, 'No new rows in main schema'); |
654 | is ($art2->count, 1, 'One artist create in 2nd schema'); |
655 | |
656 | is( $new_art->artistid, 1, 'Expected first PK' ); |
657 | |
658 | do_clean ($dbh2); |
07cda1c5 |
659 | }} |
660 | |
661 | do_clean ($dbh); |
662 | } |
df6e3f5c |
663 | |
86cc4156 |
664 | done_testing; |
665 | |
df6e3f5c |
666 | sub do_creates { |
07cda1c5 |
667 | my ($dbh, $q) = @_; |
668 | |
669 | do_clean($dbh); |
670 | |
671 | $dbh->do("CREATE SEQUENCE ${q}artist_autoinc_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
672 | $dbh->do("CREATE SEQUENCE ${q}artist_pk_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
673 | $dbh->do("CREATE SEQUENCE ${q}cd_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
674 | $dbh->do("CREATE SEQUENCE ${q}track_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
675 | |
676 | $dbh->do("CREATE SEQUENCE ${q}nonpkid_seq${q} START WITH 20 MAXVALUE 999999 MINVALUE 0"); |
677 | # this one is always quoted as per manually specified sequence => |
678 | $dbh->do('CREATE SEQUENCE "pkid1_seq" START WITH 1 MAXVALUE 999999 MINVALUE 0'); |
679 | # this one is always unquoted as per manually specified sequence => |
df6e3f5c |
680 | $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0"); |
df6e3f5c |
681 | |
8b9473f5 |
682 | $dbh->do("CREATE TABLE ${q}artist${q} (${q}artistid${q} NUMBER(12), ${q}name${q} VARCHAR(255),${q}default_value_col${q} VARCHAR(255) DEFAULT 'default_value', ${q}autoinc_col${q} NUMBER(12), ${q}rank${q} NUMBER(38), ${q}charfield${q} VARCHAR2(10))"); |
07cda1c5 |
683 | $dbh->do("ALTER TABLE ${q}artist${q} ADD (CONSTRAINT ${q}artist_pk${q} PRIMARY KEY (${q}artistid${q}))"); |
df6e3f5c |
684 | |
07cda1c5 |
685 | $dbh->do("CREATE TABLE ${q}sequence_test${q} (${q}pkid1${q} NUMBER(12), ${q}pkid2${q} NUMBER(12), ${q}nonpkid${q} NUMBER(12), ${q}name${q} VARCHAR(255))"); |
686 | $dbh->do("ALTER TABLE ${q}sequence_test${q} ADD (CONSTRAINT ${q}sequence_test_constraint${q} PRIMARY KEY (${q}pkid1${q}, ${q}pkid2${q}))"); |
df6e3f5c |
687 | |
07cda1c5 |
688 | # table cd will be unquoted => Oracle will see it as uppercase |
689 | $dbh->do("CREATE TABLE cd (${q}cdid${q} NUMBER(12), ${q}artist${q} NUMBER(12), ${q}title${q} VARCHAR(255), ${q}year${q} VARCHAR(4), ${q}genreid${q} NUMBER(12), ${q}single_track${q} NUMBER(12))"); |
690 | $dbh->do("ALTER TABLE cd ADD (CONSTRAINT ${q}cd_pk${q} PRIMARY KEY (${q}cdid${q}))"); |
df6e3f5c |
691 | |
3d98c75e |
692 | $dbh->do("CREATE TABLE ${q}track${q} (${q}trackid${q} NUMBER(12), ${q}cd${q} NUMBER(12) REFERENCES CD(${q}cdid${q}) DEFERRABLE, ${q}position${q} NUMBER(12), ${q}title${q} VARCHAR(255), ${q}last_updated_on${q} DATE, ${q}last_updated_at${q} DATE)"); |
07cda1c5 |
693 | $dbh->do("ALTER TABLE ${q}track${q} ADD (CONSTRAINT ${q}track_pk${q} PRIMARY KEY (${q}trackid${q}))"); |
df6e3f5c |
694 | |
f3a9ea3d |
695 | $dbh->do("CREATE TABLE ${q}bindtype_test${q} (${q}id${q} integer NOT NULL PRIMARY KEY, ${q}bytea${q} integer NULL, ${q}blob${q} blob NULL, ${q}clob${q} clob NULL, ${q}a_memo${q} integer NULL)"); |
12e05c15 |
696 | |
df6e3f5c |
697 | $dbh->do(qq{ |
07cda1c5 |
698 | CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_auto${q} |
699 | BEFORE INSERT ON ${q}artist${q} |
ab4f4e4c |
700 | FOR EACH ROW |
701 | BEGIN |
07cda1c5 |
702 | IF :new.${q}autoinc_col${q} IS NULL THEN |
703 | SELECT ${q}artist_autoinc_seq${q}.nextval |
704 | INTO :new.${q}autoinc_col${q} |
ab4f4e4c |
705 | FROM DUAL; |
706 | END IF; |
707 | END; |
708 | }); |
07cda1c5 |
709 | |
ab4f4e4c |
710 | $dbh->do(qq{ |
07cda1c5 |
711 | CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q} |
712 | BEFORE INSERT ON ${q}artist${q} |
df6e3f5c |
713 | FOR EACH ROW |
714 | BEGIN |
07cda1c5 |
715 | IF :new.${q}artistid${q} IS NULL THEN |
716 | SELECT ${q}artist_pk_seq${q}.nextval |
717 | INTO :new.${q}artistid${q} |
df6e3f5c |
718 | FROM DUAL; |
719 | END IF; |
720 | END; |
721 | }); |
07cda1c5 |
722 | |
df6e3f5c |
723 | $dbh->do(qq{ |
07cda1c5 |
724 | CREATE OR REPLACE TRIGGER ${q}cd_insert_trg${q} |
df6e3f5c |
725 | BEFORE INSERT OR UPDATE ON cd |
726 | FOR EACH ROW |
07cda1c5 |
727 | |
6f5f880d |
728 | DECLARE |
729 | tmpVar NUMBER; |
730 | |
df6e3f5c |
731 | BEGIN |
6f5f880d |
732 | tmpVar := 0; |
733 | |
07cda1c5 |
734 | IF :new.${q}cdid${q} IS NULL THEN |
735 | SELECT ${q}cd_seq${q}.nextval |
6f5f880d |
736 | INTO tmpVar |
737 | FROM dual; |
738 | |
07cda1c5 |
739 | :new.${q}cdid${q} := tmpVar; |
df6e3f5c |
740 | END IF; |
741 | END; |
742 | }); |
07cda1c5 |
743 | |
df6e3f5c |
744 | $dbh->do(qq{ |
07cda1c5 |
745 | CREATE OR REPLACE TRIGGER ${q}track_insert_trg${q} |
746 | BEFORE INSERT ON ${q}track${q} |
df6e3f5c |
747 | FOR EACH ROW |
748 | BEGIN |
07cda1c5 |
749 | IF :new.${q}trackid${q} IS NULL THEN |
750 | SELECT ${q}track_seq${q}.nextval |
751 | INTO :new.${q}trackid${q} |
df6e3f5c |
752 | FROM DUAL; |
753 | END IF; |
754 | END; |
755 | }); |
756 | } |
757 | |
0567538f |
758 | # clean up our mess |
07cda1c5 |
759 | sub do_clean { |
760 | |
761 | my $dbh = shift || return; |
762 | |
763 | for my $q ('', '"') { |
764 | my @clean = ( |
765 | "DROP TRIGGER ${q}track_insert_trg${q}", |
766 | "DROP TRIGGER ${q}cd_insert_trg${q}", |
767 | "DROP TRIGGER ${q}artist_insert_trg_auto${q}", |
768 | "DROP TRIGGER ${q}artist_insert_trg_pk${q}", |
769 | "DROP SEQUENCE ${q}nonpkid_seq${q}", |
770 | "DROP SEQUENCE ${q}pkid2_seq${q}", |
771 | "DROP SEQUENCE ${q}pkid1_seq${q}", |
772 | "DROP SEQUENCE ${q}track_seq${q}", |
773 | "DROP SEQUENCE ${q}cd_seq${q}", |
774 | "DROP SEQUENCE ${q}artist_autoinc_seq${q}", |
775 | "DROP SEQUENCE ${q}artist_pk_seq${q}", |
776 | "DROP TABLE ${q}bindtype_test${q}", |
777 | "DROP TABLE ${q}sequence_test${q}", |
778 | "DROP TABLE ${q}track${q}", |
779 | "DROP TABLE ${q}cd${q}", |
780 | "DROP TABLE ${q}artist${q}", |
781 | ); |
782 | eval { $dbh -> do ($_) } for @clean; |
783 | } |
784 | } |
785 | |
3ff5b740 |
786 | END { |
a6646e1b |
787 | for ($dbh, $dbh2) { |
788 | next unless $_; |
07cda1c5 |
789 | local $SIG{__WARN__} = sub {}; |
a6646e1b |
790 | do_clean($_); |
791 | $_->disconnect; |
df6e3f5c |
792 | } |
3ff5b740 |
793 | } |