Optimize RowNum limit dialect as per suggestion in RT#61277
[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
f3f6c13a 241 # disable BLOB mega-output
242 my $orig_debug = $schema->storage->debug;
243 $schema->storage->debug (0);
244
d7f20fdf 245 foreach my $type (qw( blob clob )) {
246 foreach my $size (qw( small large )) {
247 $id++;
5db2758d 248
d7f20fdf 249 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
250 "inserted $size $type without dying";
251
252 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
253 }
254 }
f3f6c13a 255
256 $schema->storage->debug ($orig_debug);
5db2758d 257}
258
bc6ae32e 259
260### test hierarchical queries
c0024355 261if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) {
262 my $source = $schema->source('Artist');
263
264 $source->add_column( 'parentid' );
265
266 $source->add_relationship('children', 'DBICTest::Schema::Artist',
267 { 'foreign.parentid' => 'self.artistid' },
268 {
269 accessor => 'multi',
270 join_type => 'LEFT',
271 cascade_delete => 1,
272 cascade_copy => 1,
273 } );
274 $source->add_relationship('parent', 'DBICTest::Schema::Artist',
275 { 'foreign.artistid' => 'self.parentid' },
276 { accessor => 'single' } );
277 DBICTest::Schema::Artist->add_column( 'parentid' );
278 DBICTest::Schema::Artist->has_many(
279 children => 'DBICTest::Schema::Artist',
280 { 'foreign.parentid' => 'self.artistid' }
281 );
282 DBICTest::Schema::Artist->belongs_to(
283 parent => 'DBICTest::Schema::Artist',
284 { 'foreign.artistid' => 'self.parentid' }
285 );
286
287 $schema->resultset('Artist')->create ({
288 name => 'root',
5c810af7 289 rank => 1,
c0024355 290 cds => [],
291 children => [
292 {
293 name => 'child1',
5c810af7 294 rank => 2,
c0024355 295 children => [
296 {
297 name => 'grandchild',
5c810af7 298 rank => 3,
c0024355 299 cds => [
300 {
301 title => "grandchilds's cd" ,
302 year => '2008',
303 tracks => [
304 {
305 position => 1,
306 title => 'Track 1 grandchild',
307 }
308 ],
309 }
310 ],
311 children => [
312 {
313 name => 'greatgrandchild',
5c810af7 314 rank => 3,
c0024355 315 }
316 ],
317 }
318 ],
319 },
320 {
321 name => 'child2',
5c810af7 322 rank => 3,
c0024355 323 },
324 ],
325 });
326
2a7879e2 327 $schema->resultset('Artist')->create(
328 {
329 name => 'cycle-root',
330 children => [
331 {
332 name => 'cycle-child1',
333 children => [ { name => 'cycle-grandchild' } ],
334 },
335 { name => 'cycle-child2' },
336 ],
337 }
338 );
339
340 $schema->resultset('Artist')->find({ name => 'cycle-root' })
341 ->update({ parentid => \'artistid' });
342
bc6ae32e 343 # select the whole tree
c0024355 344 {
bc6ae32e 345 my $rs = $schema->resultset('Artist')->search({}, {
346 start_with => { name => 'root' },
347 connect_by => { parentid => { -prior => \ 'artistid' } },
348 });
349
350 is_same_sql_bind (
351 $rs->as_query,
352 '(
353 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
354 FROM artist me
355 START WITH name = ?
1756ae89 356 CONNECT BY parentid = PRIOR artistid
bc6ae32e 357 )',
358 [ [ name => 'root'] ],
359 );
360 is_deeply (
361 [ $rs->get_column ('name')->all ],
362 [ qw/root child1 grandchild greatgrandchild child2/ ],
363 'got artist tree',
364 );
365
366
367 is_same_sql_bind (
368 $rs->count_rs->as_query,
369 '(
370 SELECT COUNT( * )
371 FROM artist me
372 START WITH name = ?
1756ae89 373 CONNECT BY parentid = PRIOR artistid
bc6ae32e 374 )',
375 [ [ name => 'root'] ],
376 );
377
c0024355 378 is( $rs->count, 5, 'Connect By count ok' );
c0024355 379 }
380
bc6ae32e 381 # use order siblings by statement
c0024355 382 {
bc6ae32e 383 my $rs = $schema->resultset('Artist')->search({}, {
384 start_with => { name => 'root' },
385 connect_by => { parentid => { -prior => \ 'artistid' } },
386 order_siblings_by => { -desc => 'name' },
387 });
388
389 is_same_sql_bind (
390 $rs->as_query,
391 '(
392 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
393 FROM artist me
394 START WITH name = ?
1756ae89 395 CONNECT BY parentid = PRIOR artistid
bc6ae32e 396 ORDER SIBLINGS BY name DESC
397 )',
398 [ [ name => 'root'] ],
399 );
400
401 is_deeply (
402 [ $rs->get_column ('name')->all ],
403 [ qw/root child2 child1 grandchild greatgrandchild/ ],
404 'Order Siblings By ok',
405 );
c0024355 406 }
407
bc6ae32e 408 # get the root node
c0024355 409 {
bc6ae32e 410 my $rs = $schema->resultset('Artist')->search({ parentid => undef }, {
b34a62e5 411 start_with => { name => 'root' },
412 connect_by => { parentid => { -prior => \ 'artistid' } },
bc6ae32e 413 });
414
415 is_same_sql_bind (
416 $rs->as_query,
417 '(
418 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
419 FROM artist me
420 WHERE ( parentid IS NULL )
421 START WITH name = ?
1756ae89 422 CONNECT BY parentid = PRIOR artistid
bc6ae32e 423 )',
b34a62e5 424 [ [ name => 'root'] ],
bc6ae32e 425 );
426
427 is_deeply(
428 [ $rs->get_column('name')->all ],
429 [ 'root' ],
430 'found root node',
431 );
c0024355 432 }
433
bc6ae32e 434 # combine a connect by with a join
c0024355 435 {
bc6ae32e 436 my $rs = $schema->resultset('Artist')->search(
437 {'cds.title' => { -like => '%cd'} },
438 {
439 join => 'cds',
440 start_with => { 'me.name' => 'root' },
441 connect_by => { parentid => { -prior => \ 'artistid' } },
442 }
443 );
444
445 is_same_sql_bind (
446 $rs->as_query,
447 '(
448 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
449 FROM artist me
450 LEFT JOIN cd cds ON cds.artist = me.artistid
451 WHERE ( cds.title LIKE ? )
452 START WITH me.name = ?
1756ae89 453 CONNECT BY parentid = PRIOR artistid
bc6ae32e 454 )',
455 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
456 );
457
458 is_deeply(
459 [ $rs->get_column('name')->all ],
460 [ 'grandchild' ],
461 'Connect By with a join result name ok'
462 );
463
464
465 is_same_sql_bind (
466 $rs->count_rs->as_query,
467 '(
468 SELECT COUNT( * )
469 FROM artist me
470 LEFT JOIN cd cds ON cds.artist = me.artistid
471 WHERE ( cds.title LIKE ? )
472 START WITH me.name = ?
1756ae89 473 CONNECT BY parentid = PRIOR artistid
bc6ae32e 474 )',
475 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
476 );
477
c0024355 478 is( $rs->count, 1, 'Connect By with a join; count ok' );
c0024355 479 }
480
bc6ae32e 481 # combine a connect by with order_by
c0024355 482 {
bc6ae32e 483 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 484 start_with => { name => 'root' },
485 connect_by => { parentid => { -prior => \ 'artistid' } },
486 order_by => { -asc => [ 'LEVEL', 'name' ] },
bc6ae32e 487 });
488
489 is_same_sql_bind (
490 $rs->as_query,
491 '(
492 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
493 FROM artist me
494 START WITH name = ?
1756ae89 495 CONNECT BY parentid = PRIOR artistid
b34a62e5 496 ORDER BY LEVEL ASC, name ASC
bc6ae32e 497 )',
b34a62e5 498 [ [ name => 'root' ] ],
bc6ae32e 499 );
500
501 is_deeply (
502 [ $rs->get_column ('name')->all ],
b34a62e5 503 [ qw/root child1 child2 grandchild greatgrandchild/ ],
bc6ae32e 504 'Connect By with a order_by - result name ok'
505 );
c0024355 506 }
507
bc6ae32e 508
509 # limit a connect by
c0024355 510 {
bc6ae32e 511 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 512 start_with => { name => 'root' },
513 connect_by => { parentid => { -prior => \ 'artistid' } },
514 order_by => { -asc => 'name' },
bc6ae32e 515 rows => 2,
516 });
517
518 is_same_sql_bind (
519 $rs->as_query,
d9672fb9 520 '(
9a5a7d7e 521 SELECT artistid, name, rank, charfield, parentid FROM (
d9672fb9 522 SELECT
523 me.artistid,
524 me.name,
525 me.rank,
526 me.charfield,
527 me.parentid
528 FROM artist me
529 START WITH name = ?
530 CONNECT BY parentid = PRIOR artistid
531 ORDER BY name ASC
9a5a7d7e 532 ) me
d9672fb9 533 WHERE ROWNUM <= 2
bc6ae32e 534 )',
b34a62e5 535 [ [ name => 'root' ] ],
bc6ae32e 536 );
537
538 is_deeply (
539 [ $rs->get_column ('name')->all ],
b34a62e5 540 [qw/child1 child2/],
bc6ae32e 541 'LIMIT a Connect By query - correct names'
542 );
543
d4f4f6b4 544 # TODO:
545 # prints "START WITH name = ?
1756ae89 546 # CONNECT BY artistid = PRIOR parentid "
d4f4f6b4 547 # after count_subq,
548 # I will fix this later...
549 #
d815b6a5 550 is_same_sql_bind (
551 $rs->count_rs->as_query,
d9672fb9 552 '(
553 SELECT COUNT( * ) FROM (
554 SELECT artistid
555 FROM (
556 SELECT
557 me.artistid
558 FROM artist me
559 START WITH name = ?
560 CONNECT BY parentid = PRIOR artistid
561 ) me
562 WHERE ROWNUM <= 2
563 ) me
d815b6a5 564 )',
565 [ [ name => 'root' ] ],
566 );
567
568 is( $rs->count, 2, 'Connect By; LIMIT count ok' );
2ba03b16 569 }
570
5c810af7 571 # combine a connect_by with group_by and having
572 {
573 my $rs = $schema->resultset('Artist')->search({}, {
574 select => ['count(rank)'],
575 start_with => { name => 'root' },
576 connect_by => { parentid => { -prior => \ 'artistid' } },
577 group_by => ['rank'],
578 having => { 'count(rank)' => { '<', 2 } },
579 });
580
581 is_same_sql_bind (
582 $rs->as_query,
583 '(
584 SELECT count(rank)
585 FROM artist me
586 START WITH name = ?
587 CONNECT BY parentid = PRIOR artistid
588 GROUP BY rank HAVING count(rank) < ?
589 )',
590 [ [ name => 'root' ], [ 'count(rank)' => 2 ] ],
591 );
592
593 is_deeply (
594 [ $rs->get_column ('count(rank)')->all ],
595 [1, 1],
596 'Group By a Connect By query - correct values'
597 );
598 }
599
600
2a7879e2 601 # select the whole cycle tree without nocylce
602 {
603 my $rs = $schema->resultset('Artist')->search({}, {
604 start_with => { name => 'cycle-root' },
605 connect_by => { parentid => { -prior => \ 'artistid' } },
606 });
607 eval { $rs->get_column ('name')->all };
73d6cd33 608 if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data
2a7879e2 609 pass "connect by initify loop detection without nocycle";
610 }else{
611 fail "connect by initify loop detection without nocycle, not detected by oracle";
612 }
613 }
614
615 # select the whole cycle tree with nocylce
2ba03b16 616 {
617 my $rs = $schema->resultset('Artist')->search({}, {
2a7879e2 618 start_with => { name => 'cycle-root' },
619 '+select' => [ \ 'CONNECT_BY_ISCYCLE' ],
6b2fbbf0 620 connect_by_nocycle => { parentid => { -prior => \ 'artistid' } },
2ba03b16 621 });
622
623 is_same_sql_bind (
624 $rs->as_query,
625 '(
2a7879e2 626 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE
2ba03b16 627 FROM artist me
628 START WITH name = ?
1756ae89 629 CONNECT BY NOCYCLE parentid = PRIOR artistid
2ba03b16 630 )',
2a7879e2 631 [ [ name => 'cycle-root'] ],
2ba03b16 632 );
633 is_deeply (
634 [ $rs->get_column ('name')->all ],
2a7879e2 635 [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ],
636 'got artist tree with nocycle (name)',
637 );
638 is_deeply (
639 [ $rs->get_column ('CONNECT_BY_ISCYCLE')->all ],
640 [ qw/1 0 0 0/ ],
641 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)',
2ba03b16 642 );
643
644
bc6ae32e 645 is_same_sql_bind (
646 $rs->count_rs->as_query,
2ba03b16 647 '(
648 SELECT COUNT( * )
649 FROM artist me
650 START WITH name = ?
1756ae89 651 CONNECT BY NOCYCLE parentid = PRIOR artistid
bc6ae32e 652 )',
2a7879e2 653 [ [ name => 'cycle-root'] ],
bc6ae32e 654 );
655
2a7879e2 656 is( $rs->count, 4, 'Connect By Nocycle count ok' );
c0024355 657 }
658}
659
df6e3f5c 660my $schema2;
661
662# test sequence detection from a different schema
9d7d2f00 663SKIP: {
664 skip ((join '',
665'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
666' to run the cross-schema autoincrement test.'),
667 1) unless $dsn2 && $user2 && $user2 ne $user;
668
df6e3f5c 669 $schema2 = DBICTest::Schema->connect($dsn2, $user2, $pass2);
670
9d7d2f00 671 my $schema1_dbh = $schema->storage->dbh;
df6e3f5c 672
9d7d2f00 673 $schema1_dbh->do("GRANT INSERT ON artist TO $user2");
674 $schema1_dbh->do("GRANT SELECT ON artist_seq TO $user2");
df6e3f5c 675
72044892 676 my $rs = $schema2->resultset('ArtistFQN');
df6e3f5c 677
72044892 678 # first test with unquoted (default) sequence name in trigger body
df6e3f5c 679
680 lives_and {
9d7d2f00 681 my $row = $rs->create({ name => 'From Different Schema' });
df6e3f5c 682 ok $row->artistid;
9d7d2f00 683 } 'used autoinc sequence across schemas';
72044892 684
685 # now quote the sequence name
686
687 $schema1_dbh->do(qq{
688 CREATE OR REPLACE TRIGGER artist_insert_trg
689 BEFORE INSERT ON artist
690 FOR EACH ROW
691 BEGIN
692 IF :new.artistid IS NULL THEN
693 SELECT "ARTIST_SEQ".nextval
694 INTO :new.artistid
695 FROM DUAL;
696 END IF;
697 END;
698 });
699
700 # sequence is cached in the rsrc
701 delete $rs->result_source->column_info('artistid')->{sequence};
702
703 lives_and {
704 my $row = $rs->create({ name => 'From Different Schema With Quoted Sequence' });
705 ok $row->artistid;
706 } 'used quoted autoinc sequence across schemas';
707
708 my $schema_name = uc $user;
709
710 is $rs->result_source->column_info('artistid')->{sequence},
711 qq[${schema_name}."ARTIST_SEQ"],
712 'quoted sequence name correctly extracted';
df6e3f5c 713}
714
86cc4156 715done_testing;
716
df6e3f5c 717sub do_creates {
718 my $dbh = shift;
719
720 eval {
721 $dbh->do("DROP SEQUENCE artist_seq");
722 $dbh->do("DROP SEQUENCE cd_seq");
723 $dbh->do("DROP SEQUENCE track_seq");
724 $dbh->do("DROP SEQUENCE pkid1_seq");
725 $dbh->do("DROP SEQUENCE pkid2_seq");
726 $dbh->do("DROP SEQUENCE nonpkid_seq");
727 $dbh->do("DROP TABLE artist");
728 $dbh->do("DROP TABLE sequence_test");
729 $dbh->do("DROP TABLE track");
730 $dbh->do("DROP TABLE cd");
731 };
732 $dbh->do("CREATE SEQUENCE artist_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
733 $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
734 $dbh->do("CREATE SEQUENCE track_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
735 $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
736 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
737 $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0");
738
739 $dbh->do("CREATE TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))");
740 $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
741
742 $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
743 $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
744
745 $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))");
746 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
747
748 $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)");
749 $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))");
750
751 $dbh->do(qq{
752 CREATE OR REPLACE TRIGGER artist_insert_trg
753 BEFORE INSERT ON artist
754 FOR EACH ROW
755 BEGIN
756 IF :new.artistid IS NULL THEN
757 SELECT artist_seq.nextval
758 INTO :new.artistid
759 FROM DUAL;
760 END IF;
761 END;
762 });
763 $dbh->do(qq{
764 CREATE OR REPLACE TRIGGER cd_insert_trg
765 BEFORE INSERT OR UPDATE ON cd
766 FOR EACH ROW
767 BEGIN
768 IF :new.cdid IS NULL THEN
769 SELECT cd_seq.nextval
770 INTO :new.cdid
771 FROM DUAL;
772 END IF;
773 END;
774 });
775 $dbh->do(qq{
776 CREATE OR REPLACE TRIGGER cd_insert_trg
777 BEFORE INSERT ON cd
778 FOR EACH ROW
779 BEGIN
780 IF :new.cdid IS NULL THEN
781 SELECT cd_seq.nextval
782 INTO :new.cdid
783 FROM DUAL;
784 END IF;
785 END;
786 });
787 $dbh->do(qq{
788 CREATE OR REPLACE TRIGGER track_insert_trg
789 BEFORE INSERT ON track
790 FOR EACH ROW
791 BEGIN
792 IF :new.trackid IS NULL THEN
793 SELECT track_seq.nextval
794 INTO :new.trackid
795 FROM DUAL;
796 END IF;
797 END;
798 });
799}
800
0567538f 801# clean up our mess
3ff5b740 802END {
df6e3f5c 803 for my $dbh (map $_->storage->dbh, grep $_, ($schema, $schema2)) {
804 eval {
805 $dbh->do("DROP SEQUENCE artist_seq");
806 $dbh->do("DROP SEQUENCE cd_seq");
807 $dbh->do("DROP SEQUENCE track_seq");
808 $dbh->do("DROP SEQUENCE pkid1_seq");
809 $dbh->do("DROP SEQUENCE pkid2_seq");
810 $dbh->do("DROP SEQUENCE nonpkid_seq");
811 $dbh->do("DROP TABLE artist");
812 $dbh->do("DROP TABLE sequence_test");
813 $dbh->do("DROP TABLE track");
814 $dbh->do("DROP TABLE cd");
815 $dbh->do("DROP TABLE bindtype_test");
816 };
df6e3f5c 817 }
3ff5b740 818}