improve Oracle sequence detection and related test output
[dbsrgits/DBIx-Class.git] / t / 73oracle.t
CommitLineData
cb464582 1{
2 package # hide from PAUSE
3 DBICTest::Schema::ArtistFQN;
4
5 use base 'DBIx::Class::Core';
6
7 __PACKAGE__->table(
8 defined $ENV{DBICTEST_ORA_USER}
9 ? $ENV{DBICTEST_ORA_USER} . '.artist'
10 : 'artist'
11 );
12 __PACKAGE__->add_columns(
13 'artistid' => {
14 data_type => 'integer',
15 is_auto_increment => 1,
16 },
17 'name' => {
18 data_type => 'varchar',
19 size => 100,
20 is_nullable => 1,
21 },
22 );
23 __PACKAGE__->set_primary_key('artistid');
24
25 1;
26}
27
70350518 28use strict;
e6dd7b42 29use warnings;
70350518 30
5db2758d 31use Test::Exception;
70350518 32use Test::More;
ab6e0924 33
70350518 34use lib qw(t/lib);
35use DBICTest;
8ce8340f 36use DBIC::SqlMakerTest;
0567538f 37
df6e3f5c 38my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
39
40# optional:
9d7d2f00 41my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_ORA_EXTRAUSER_${_}" } qw/DSN USER PASS/};
0567538f 42
70350518 43plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' .
39b8d119 44 'Warning: This test drops and creates tables called \'artist\', \'cd\', \'track\' and \'sequence_test\''.
45 ' as well as following sequences: \'pkid1_seq\', \'pkid2_seq\' and \'nonpkid_seq\''
0567538f 46 unless ($dsn && $user && $pass);
47
cb464582 48DBICTest::Schema->load_classes('ArtistFQN');
9900b569 49my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
0567538f 50
3ff5b740 51my $dbh = $schema->storage->dbh;
0567538f 52
df6e3f5c 53do_creates($dbh);
0567538f 54
5db2758d 55{
56 # Swiped from t/bindtype_columns.t to avoid creating my own Resultset.
57
58 local $SIG{__WARN__} = sub {};
59 eval { $dbh->do('DROP TABLE bindtype_test') };
60
61 $dbh->do(qq[
e6dd7b42 62 CREATE TABLE bindtype_test
5db2758d 63 (
64 id integer NOT NULL PRIMARY KEY,
65 bytea integer NULL,
66 blob blob NULL,
67 clob clob NULL
68 )
69 ],{ RaiseError => 1, PrintError => 1 });
70}
71
3ff5b740 72# This is in Core now, but it's here just to test that it doesn't break
73$schema->class('Artist')->load_components('PK::Auto');
74# These are compat shims for PK::Auto...
75$schema->class('CD')->load_components('PK::Auto::Oracle');
76$schema->class('Track')->load_components('PK::Auto::Oracle');
0567538f 77
78# test primary key handling
3ff5b740 79my $new = $schema->resultset('Artist')->create({ name => 'foo' });
c8f4b52b 80is($new->artistid, 1, "Oracle Auto-PK worked");
0567538f 81
e6dd7b42 82my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
62d4dbae 83is($cd->cdid, 1, "Oracle Auto-PK worked - using scalar ref as table name");
e6dd7b42 84
cb464582 85# test again with fully-qualified table name
86$new = $schema->resultset('ArtistFQN')->create( { name => 'bar' } );
87is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
88
62d4dbae 89# test rel names over the 30 char limit
90my $query = $schema->resultset('Artist')->search({
6c0230de 91 artistid => 1
62d4dbae 92}, {
93 prefetch => 'cds_very_very_very_long_relationship_name'
94});
95
96lives_and {
6c0230de 97 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
62d4dbae 98} 'query with rel name over 30 chars survived and worked';
99
6c0230de 100# rel name over 30 char limit with user condition
101# This requires walking the SQLA data structure.
102{
103 local $TODO = 'user condition on rel longer than 30 chars';
104
105 $query = $schema->resultset('Artist')->search({
106 'cds_very_very_very_long_relationship_name.title' => 'EP C'
107 }, {
108 prefetch => 'cds_very_very_very_long_relationship_name'
109 });
110
111 lives_and {
112 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
113 } 'query with rel name over 30 chars and user condition survived and worked';
114}
115
9900b569 116# test join with row count ambiguity
d2a3958e 117
c0024355 118my $track = $schema->resultset('Track')->create({ cd => $cd->cdid,
9900b569 119 position => 1, title => 'Track1' });
3ff5b740 120my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
2660b14e 121 { join => 'cd',
122 rows => 2 }
123);
124
d2a3958e 125ok(my $row = $tjoin->next);
126
127is($row->title, 'Track1', "ambiguous column ok");
2660b14e 128
286f32b3 129# check count distinct with multiple columns
c0024355 130my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
11d68671 131
3ff5b740 132my $tcount = $schema->resultset('Track')->search(
11d68671 133 {},
134 {
135 select => [ qw/position title/ ],
136 distinct => 1,
137 }
138);
f12f0d97 139is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
11d68671 140
141$tcount = $schema->resultset('Track')->search(
142 {},
143 {
144 columns => [ qw/position title/ ],
145 distinct => 1,
146 }
147);
f12f0d97 148is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
286f32b3 149
11d68671 150$tcount = $schema->resultset('Track')->search(
151 {},
e6dd7b42 152 {
11d68671 153 group_by => [ qw/position title/ ]
154 }
155);
f12f0d97 156is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
2660b14e 157
0567538f 158# test LIMIT support
159for (1..6) {
3ff5b740 160 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
0567538f 161}
3ff5b740 162my $it = $schema->resultset('Artist')->search( {},
0567538f 163 { rows => 3,
cb464582 164 offset => 3,
0567538f 165 order_by => 'artistid' }
166);
167is( $it->count, 3, "LIMIT count ok" );
168is( $it->next->name, "Artist 2", "iterator->next ok" );
169$it->next;
170$it->next;
171is( $it->next, undef, "next past end of resultset ok" );
172
e8e971f2 173{
174 my $rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset=>1 });
175 my @results = $rs->all;
176 is( scalar @results, 1, "Group by with limit OK" );
177}
178
bd691933 179# test identifiers over the 30 char limit
180{
181 lives_ok {
182 my @results = $schema->resultset('CD')->search(undef, {
183 prefetch => 'very_long_artist_relationship',
184 rows => 3,
185 offset => 0,
186 })->all;
187 ok( scalar @results > 0, 'limit with long identifiers returned something');
188 } 'limit with long identifiers executed successfully';
189}
190
b7b18f32 191# test with_deferred_fk_checks
192lives_ok {
193 $schema->storage->with_deferred_fk_checks(sub {
194 $schema->resultset('Track')->create({
195 trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
196 });
197 $schema->resultset('CD')->create({
198 artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
199 });
200 });
201} 'with_deferred_fk_checks code survived';
202
203is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
204 'code in with_deferred_fk_checks worked';
205
206throws_ok {
207 $schema->resultset('Track')->create({
208 trackid => 1, cd => 9999, position => 1, title => 'Track1'
209 });
210} qr/constraint/i, 'with_deferred_fk_checks is off';
211
ccd6f984 212# test auto increment using sequences WITHOUT triggers
39b8d119 213for (1..5) {
214 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
215 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
216 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
217 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
218}
219my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
220is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
ccd6f984 221
8068691e 222SKIP: {
d7f20fdf 223 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
224 $binstr{'large'} = $binstr{'small'} x 1024;
8068691e 225
d7f20fdf 226 my $maxloblen = length $binstr{'large'};
227 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
228 local $dbh->{'LongReadLen'} = $maxloblen;
5db2758d 229
d7f20fdf 230 my $rs = $schema->resultset('BindType');
231 my $id = 0;
5db2758d 232
931e5d43 233 if ($DBD::Oracle::VERSION eq '1.23') {
234 throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
235 qr/broken/,
236 'throws on blob insert with DBD::Oracle == 1.23';
5db2758d 237
931e5d43 238 skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
239 }
5db2758d 240
d7f20fdf 241 foreach my $type (qw( blob clob )) {
242 foreach my $size (qw( small large )) {
243 $id++;
5db2758d 244
d7f20fdf 245 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
246 "inserted $size $type without dying";
247
248 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
249 }
250 }
5db2758d 251}
252
bc6ae32e 253
254### test hierarchical queries
c0024355 255if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) {
256 my $source = $schema->source('Artist');
257
258 $source->add_column( 'parentid' );
259
260 $source->add_relationship('children', 'DBICTest::Schema::Artist',
261 { 'foreign.parentid' => 'self.artistid' },
262 {
263 accessor => 'multi',
264 join_type => 'LEFT',
265 cascade_delete => 1,
266 cascade_copy => 1,
267 } );
268 $source->add_relationship('parent', 'DBICTest::Schema::Artist',
269 { 'foreign.artistid' => 'self.parentid' },
270 { accessor => 'single' } );
271 DBICTest::Schema::Artist->add_column( 'parentid' );
272 DBICTest::Schema::Artist->has_many(
273 children => 'DBICTest::Schema::Artist',
274 { 'foreign.parentid' => 'self.artistid' }
275 );
276 DBICTest::Schema::Artist->belongs_to(
277 parent => 'DBICTest::Schema::Artist',
278 { 'foreign.artistid' => 'self.parentid' }
279 );
280
281 $schema->resultset('Artist')->create ({
282 name => 'root',
5c810af7 283 rank => 1,
c0024355 284 cds => [],
285 children => [
286 {
287 name => 'child1',
5c810af7 288 rank => 2,
c0024355 289 children => [
290 {
291 name => 'grandchild',
5c810af7 292 rank => 3,
c0024355 293 cds => [
294 {
295 title => "grandchilds's cd" ,
296 year => '2008',
297 tracks => [
298 {
299 position => 1,
300 title => 'Track 1 grandchild',
301 }
302 ],
303 }
304 ],
305 children => [
306 {
307 name => 'greatgrandchild',
5c810af7 308 rank => 3,
c0024355 309 }
310 ],
311 }
312 ],
313 },
314 {
315 name => 'child2',
5c810af7 316 rank => 3,
c0024355 317 },
318 ],
319 });
320
2a7879e2 321 $schema->resultset('Artist')->create(
322 {
323 name => 'cycle-root',
324 children => [
325 {
326 name => 'cycle-child1',
327 children => [ { name => 'cycle-grandchild' } ],
328 },
329 { name => 'cycle-child2' },
330 ],
331 }
332 );
333
334 $schema->resultset('Artist')->find({ name => 'cycle-root' })
335 ->update({ parentid => \'artistid' });
336
bc6ae32e 337 # select the whole tree
c0024355 338 {
bc6ae32e 339 my $rs = $schema->resultset('Artist')->search({}, {
340 start_with => { name => 'root' },
341 connect_by => { parentid => { -prior => \ 'artistid' } },
342 });
343
344 is_same_sql_bind (
345 $rs->as_query,
346 '(
347 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
348 FROM artist me
349 START WITH name = ?
1756ae89 350 CONNECT BY parentid = PRIOR artistid
bc6ae32e 351 )',
352 [ [ name => 'root'] ],
353 );
354 is_deeply (
355 [ $rs->get_column ('name')->all ],
356 [ qw/root child1 grandchild greatgrandchild child2/ ],
357 'got artist tree',
358 );
359
360
361 is_same_sql_bind (
362 $rs->count_rs->as_query,
363 '(
364 SELECT COUNT( * )
365 FROM artist me
366 START WITH name = ?
1756ae89 367 CONNECT BY parentid = PRIOR artistid
bc6ae32e 368 )',
369 [ [ name => 'root'] ],
370 );
371
c0024355 372 is( $rs->count, 5, 'Connect By count ok' );
c0024355 373 }
374
bc6ae32e 375 # use order siblings by statement
c0024355 376 {
bc6ae32e 377 my $rs = $schema->resultset('Artist')->search({}, {
378 start_with => { name => 'root' },
379 connect_by => { parentid => { -prior => \ 'artistid' } },
380 order_siblings_by => { -desc => 'name' },
381 });
382
383 is_same_sql_bind (
384 $rs->as_query,
385 '(
386 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
387 FROM artist me
388 START WITH name = ?
1756ae89 389 CONNECT BY parentid = PRIOR artistid
bc6ae32e 390 ORDER SIBLINGS BY name DESC
391 )',
392 [ [ name => 'root'] ],
393 );
394
395 is_deeply (
396 [ $rs->get_column ('name')->all ],
397 [ qw/root child2 child1 grandchild greatgrandchild/ ],
398 'Order Siblings By ok',
399 );
c0024355 400 }
401
bc6ae32e 402 # get the root node
c0024355 403 {
bc6ae32e 404 my $rs = $schema->resultset('Artist')->search({ parentid => undef }, {
b34a62e5 405 start_with => { name => 'root' },
406 connect_by => { parentid => { -prior => \ 'artistid' } },
bc6ae32e 407 });
408
409 is_same_sql_bind (
410 $rs->as_query,
411 '(
412 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
413 FROM artist me
414 WHERE ( parentid IS NULL )
415 START WITH name = ?
1756ae89 416 CONNECT BY parentid = PRIOR artistid
bc6ae32e 417 )',
b34a62e5 418 [ [ name => 'root'] ],
bc6ae32e 419 );
420
421 is_deeply(
422 [ $rs->get_column('name')->all ],
423 [ 'root' ],
424 'found root node',
425 );
c0024355 426 }
427
bc6ae32e 428 # combine a connect by with a join
c0024355 429 {
bc6ae32e 430 my $rs = $schema->resultset('Artist')->search(
431 {'cds.title' => { -like => '%cd'} },
432 {
433 join => 'cds',
434 start_with => { 'me.name' => 'root' },
435 connect_by => { parentid => { -prior => \ 'artistid' } },
436 }
437 );
438
439 is_same_sql_bind (
440 $rs->as_query,
441 '(
442 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
443 FROM artist me
444 LEFT JOIN cd cds ON cds.artist = me.artistid
445 WHERE ( cds.title LIKE ? )
446 START WITH me.name = ?
1756ae89 447 CONNECT BY parentid = PRIOR artistid
bc6ae32e 448 )',
449 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
450 );
451
452 is_deeply(
453 [ $rs->get_column('name')->all ],
454 [ 'grandchild' ],
455 'Connect By with a join result name ok'
456 );
457
458
459 is_same_sql_bind (
460 $rs->count_rs->as_query,
461 '(
462 SELECT COUNT( * )
463 FROM artist me
464 LEFT JOIN cd cds ON cds.artist = me.artistid
465 WHERE ( cds.title LIKE ? )
466 START WITH me.name = ?
1756ae89 467 CONNECT BY parentid = PRIOR artistid
bc6ae32e 468 )',
469 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
470 );
471
c0024355 472 is( $rs->count, 1, 'Connect By with a join; count ok' );
c0024355 473 }
474
bc6ae32e 475 # combine a connect by with order_by
c0024355 476 {
bc6ae32e 477 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 478 start_with => { name => 'root' },
479 connect_by => { parentid => { -prior => \ 'artistid' } },
480 order_by => { -asc => [ 'LEVEL', 'name' ] },
bc6ae32e 481 });
482
483 is_same_sql_bind (
484 $rs->as_query,
485 '(
486 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
487 FROM artist me
488 START WITH name = ?
1756ae89 489 CONNECT BY parentid = PRIOR artistid
b34a62e5 490 ORDER BY LEVEL ASC, name ASC
bc6ae32e 491 )',
b34a62e5 492 [ [ name => 'root' ] ],
bc6ae32e 493 );
494
495 is_deeply (
496 [ $rs->get_column ('name')->all ],
b34a62e5 497 [ qw/root child1 child2 grandchild greatgrandchild/ ],
bc6ae32e 498 'Connect By with a order_by - result name ok'
499 );
c0024355 500 }
501
bc6ae32e 502
503 # limit a connect by
c0024355 504 {
bc6ae32e 505 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 506 start_with => { name => 'root' },
507 connect_by => { parentid => { -prior => \ 'artistid' } },
508 order_by => { -asc => 'name' },
bc6ae32e 509 rows => 2,
510 });
511
512 is_same_sql_bind (
513 $rs->as_query,
d4f4f6b4 514 '(
9a5a7d7e 515 SELECT artistid, name, rank, charfield, parentid FROM (
516 SELECT artistid, name, rank, charfield, parentid, ROWNUM rownum__index FROM (
d4f4f6b4 517 SELECT
9a5a7d7e 518 me.artistid,
519 me.name,
520 me.rank,
521 me.charfield,
522 me.parentid
d4f4f6b4 523 FROM artist me
524 START WITH name = ?
1756ae89 525 CONNECT BY parentid = PRIOR artistid
9a5a7d7e 526 ORDER BY name ASC
527 ) me
528 ) me
529 WHERE rownum__index BETWEEN 1 AND 2
bc6ae32e 530 )',
b34a62e5 531 [ [ name => 'root' ] ],
bc6ae32e 532 );
533
534 is_deeply (
535 [ $rs->get_column ('name')->all ],
b34a62e5 536 [qw/child1 child2/],
bc6ae32e 537 'LIMIT a Connect By query - correct names'
538 );
539
d4f4f6b4 540 # TODO:
541 # prints "START WITH name = ?
1756ae89 542 # CONNECT BY artistid = PRIOR parentid "
d4f4f6b4 543 # after count_subq,
544 # I will fix this later...
545 #
d815b6a5 546 is_same_sql_bind (
547 $rs->count_rs->as_query,
548 '(
549 SELECT COUNT( * ) FROM (
550 SELECT artistid FROM (
551 SELECT artistid, ROWNUM rownum__index FROM (
552 SELECT
553 me.artistid
554 FROM artist me
555 START WITH name = ?
556 CONNECT BY parentid = PRIOR artistid
557 ) me
558 ) me
559 WHERE rownum__index BETWEEN 1 AND 2
560 ) me
561 )',
562 [ [ name => 'root' ] ],
563 );
564
565 is( $rs->count, 2, 'Connect By; LIMIT count ok' );
2ba03b16 566 }
567
5c810af7 568 # combine a connect_by with group_by and having
569 {
570 my $rs = $schema->resultset('Artist')->search({}, {
571 select => ['count(rank)'],
572 start_with => { name => 'root' },
573 connect_by => { parentid => { -prior => \ 'artistid' } },
574 group_by => ['rank'],
575 having => { 'count(rank)' => { '<', 2 } },
576 });
577
578 is_same_sql_bind (
579 $rs->as_query,
580 '(
581 SELECT count(rank)
582 FROM artist me
583 START WITH name = ?
584 CONNECT BY parentid = PRIOR artistid
585 GROUP BY rank HAVING count(rank) < ?
586 )',
587 [ [ name => 'root' ], [ 'count(rank)' => 2 ] ],
588 );
589
590 is_deeply (
591 [ $rs->get_column ('count(rank)')->all ],
592 [1, 1],
593 'Group By a Connect By query - correct values'
594 );
595 }
596
597
2a7879e2 598 # select the whole cycle tree without nocylce
599 {
600 my $rs = $schema->resultset('Artist')->search({}, {
601 start_with => { name => 'cycle-root' },
602 connect_by => { parentid => { -prior => \ 'artistid' } },
603 });
604 eval { $rs->get_column ('name')->all };
73d6cd33 605 if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data
2a7879e2 606 pass "connect by initify loop detection without nocycle";
607 }else{
608 fail "connect by initify loop detection without nocycle, not detected by oracle";
609 }
610 }
611
612 # select the whole cycle tree with nocylce
2ba03b16 613 {
614 my $rs = $schema->resultset('Artist')->search({}, {
2a7879e2 615 start_with => { name => 'cycle-root' },
616 '+select' => [ \ 'CONNECT_BY_ISCYCLE' ],
6b2fbbf0 617 connect_by_nocycle => { parentid => { -prior => \ 'artistid' } },
2ba03b16 618 });
619
620 is_same_sql_bind (
621 $rs->as_query,
622 '(
2a7879e2 623 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE
2ba03b16 624 FROM artist me
625 START WITH name = ?
1756ae89 626 CONNECT BY NOCYCLE parentid = PRIOR artistid
2ba03b16 627 )',
2a7879e2 628 [ [ name => 'cycle-root'] ],
2ba03b16 629 );
630 is_deeply (
631 [ $rs->get_column ('name')->all ],
2a7879e2 632 [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ],
633 'got artist tree with nocycle (name)',
634 );
635 is_deeply (
636 [ $rs->get_column ('CONNECT_BY_ISCYCLE')->all ],
637 [ qw/1 0 0 0/ ],
638 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)',
2ba03b16 639 );
640
641
bc6ae32e 642 is_same_sql_bind (
643 $rs->count_rs->as_query,
2ba03b16 644 '(
645 SELECT COUNT( * )
646 FROM artist me
647 START WITH name = ?
1756ae89 648 CONNECT BY NOCYCLE parentid = PRIOR artistid
bc6ae32e 649 )',
2a7879e2 650 [ [ name => 'cycle-root'] ],
bc6ae32e 651 );
652
2a7879e2 653 is( $rs->count, 4, 'Connect By Nocycle count ok' );
c0024355 654 }
655}
656
df6e3f5c 657my $schema2;
658
659# test sequence detection from a different schema
9d7d2f00 660SKIP: {
661 skip ((join '',
662'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
663' to run the cross-schema autoincrement test.'),
664 1) unless $dsn2 && $user2 && $user2 ne $user;
665
df6e3f5c 666 $schema2 = DBICTest::Schema->connect($dsn2, $user2, $pass2);
667
9d7d2f00 668 my $schema1_dbh = $schema->storage->dbh;
df6e3f5c 669
9d7d2f00 670 $schema1_dbh->do("GRANT INSERT ON artist TO $user2");
671 $schema1_dbh->do("GRANT SELECT ON artist_seq TO $user2");
df6e3f5c 672
72044892 673 my $rs = $schema2->resultset('ArtistFQN');
df6e3f5c 674
72044892 675 # first test with unquoted (default) sequence name in trigger body
df6e3f5c 676
677 lives_and {
9d7d2f00 678 my $row = $rs->create({ name => 'From Different Schema' });
df6e3f5c 679 ok $row->artistid;
9d7d2f00 680 } 'used autoinc sequence across schemas';
72044892 681
682 # now quote the sequence name
683
684 $schema1_dbh->do(qq{
685 CREATE OR REPLACE TRIGGER artist_insert_trg
686 BEFORE INSERT ON artist
687 FOR EACH ROW
688 BEGIN
689 IF :new.artistid IS NULL THEN
690 SELECT "ARTIST_SEQ".nextval
691 INTO :new.artistid
692 FROM DUAL;
693 END IF;
694 END;
695 });
696
697 # sequence is cached in the rsrc
698 delete $rs->result_source->column_info('artistid')->{sequence};
699
700 lives_and {
701 my $row = $rs->create({ name => 'From Different Schema With Quoted Sequence' });
702 ok $row->artistid;
703 } 'used quoted autoinc sequence across schemas';
704
705 my $schema_name = uc $user;
706
707 is $rs->result_source->column_info('artistid')->{sequence},
708 qq[${schema_name}."ARTIST_SEQ"],
709 'quoted sequence name correctly extracted';
df6e3f5c 710}
711
86cc4156 712done_testing;
713
df6e3f5c 714sub do_creates {
715 my $dbh = shift;
716
717 eval {
718 $dbh->do("DROP SEQUENCE artist_seq");
719 $dbh->do("DROP SEQUENCE cd_seq");
720 $dbh->do("DROP SEQUENCE track_seq");
721 $dbh->do("DROP SEQUENCE pkid1_seq");
722 $dbh->do("DROP SEQUENCE pkid2_seq");
723 $dbh->do("DROP SEQUENCE nonpkid_seq");
724 $dbh->do("DROP TABLE artist");
725 $dbh->do("DROP TABLE sequence_test");
726 $dbh->do("DROP TABLE track");
727 $dbh->do("DROP TABLE cd");
728 };
729 $dbh->do("CREATE SEQUENCE artist_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
730 $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
731 $dbh->do("CREATE SEQUENCE track_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
732 $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
733 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
734 $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0");
735
736 $dbh->do("CREATE TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))");
737 $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
738
739 $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
740 $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
741
742 $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))");
743 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
744
745 $dbh->do("CREATE TABLE track (trackid NUMBER(12), cd NUMBER(12) REFERENCES cd(cdid) DEFERRABLE, position NUMBER(12), title VARCHAR(255), last_updated_on DATE, last_updated_at DATE, small_dt DATE)");
746 $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))");
747
748 $dbh->do(qq{
749 CREATE OR REPLACE TRIGGER artist_insert_trg
750 BEFORE INSERT ON artist
751 FOR EACH ROW
752 BEGIN
753 IF :new.artistid IS NULL THEN
754 SELECT artist_seq.nextval
755 INTO :new.artistid
756 FROM DUAL;
757 END IF;
758 END;
759 });
760 $dbh->do(qq{
761 CREATE OR REPLACE TRIGGER cd_insert_trg
762 BEFORE INSERT OR UPDATE ON cd
763 FOR EACH ROW
764 BEGIN
765 IF :new.cdid IS NULL THEN
766 SELECT cd_seq.nextval
767 INTO :new.cdid
768 FROM DUAL;
769 END IF;
770 END;
771 });
772 $dbh->do(qq{
773 CREATE OR REPLACE TRIGGER cd_insert_trg
774 BEFORE INSERT ON cd
775 FOR EACH ROW
776 BEGIN
777 IF :new.cdid IS NULL THEN
778 SELECT cd_seq.nextval
779 INTO :new.cdid
780 FROM DUAL;
781 END IF;
782 END;
783 });
784 $dbh->do(qq{
785 CREATE OR REPLACE TRIGGER track_insert_trg
786 BEFORE INSERT ON track
787 FOR EACH ROW
788 BEGIN
789 IF :new.trackid IS NULL THEN
790 SELECT track_seq.nextval
791 INTO :new.trackid
792 FROM DUAL;
793 END IF;
794 END;
795 });
796}
797
0567538f 798# clean up our mess
3ff5b740 799END {
df6e3f5c 800 for my $dbh (map $_->storage->dbh, grep $_, ($schema, $schema2)) {
801 eval {
802 $dbh->do("DROP SEQUENCE artist_seq");
803 $dbh->do("DROP SEQUENCE cd_seq");
804 $dbh->do("DROP SEQUENCE track_seq");
805 $dbh->do("DROP SEQUENCE pkid1_seq");
806 $dbh->do("DROP SEQUENCE pkid2_seq");
807 $dbh->do("DROP SEQUENCE nonpkid_seq");
808 $dbh->do("DROP TABLE artist");
809 $dbh->do("DROP TABLE sequence_test");
810 $dbh->do("DROP TABLE track");
811 $dbh->do("DROP TABLE cd");
812 $dbh->do("DROP TABLE bindtype_test");
813 };
df6e3f5c 814 }
3ff5b740 815}