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