8 use DBIx::Class::Optional::Dependencies ();
12 use DBIC::SqlMakerTest;
14 my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
17 my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_ORA_EXTRAUSER_${_}" } qw/DSN USER PASS/};
19 plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test.'
20 unless ($dsn && $user && $pass);
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');
25 $ENV{NLS_SORT} = "BINARY";
26 $ENV{NLS_COMP} = "BINARY";
27 $ENV{NLS_LANG} = "AMERICAN";
30 package # hide from PAUSE
31 DBICTest::Schema::ArtistFQN;
33 use base 'DBIx::Class::Core';
36 $ENV{DBICTEST_ORA_USER}
37 ? (uc $ENV{DBICTEST_ORA_USER}) . '.artist'
40 __PACKAGE__->add_columns(
42 data_type => 'integer',
43 is_auto_increment => 1,
46 data_type => 'varchar',
51 data_type => 'integer',
52 is_auto_increment => 1,
54 'default_value_col' => {
55 data_type => 'varchar',
58 retrieve_on_insert => 1,
61 __PACKAGE__->set_primary_key(qw/ artistid autoinc_col /);
66 DBICTest::Schema->load_classes('ArtistFQN');
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');
75 # check if we indeed do support stuff
77 my $si = DBICTest::Schema->connect($dsn, $user, $pass)->storage->_server_info;
78 $si->{normalized_dbms_version}
79 or die "Unparseable Oracle server version: $si->{dbms_version}\n";
82 my $test_server_supports_only_orajoins = $v < 9;
84 # TODO find out which version supports the RETURNING syntax
85 # 8i (8.1) has it and earlier docs are a 404 on oracle.com
86 my $test_server_supports_insert_returning = $v >= 8.001;
89 DBICTest::Schema->connect($dsn, $user, $pass)->storage->_use_insert_returning,
90 $test_server_supports_insert_returning,
91 'insert returning capability guessed correctly'
95 # the recyclebin (new for 10g) sometimes comes in the way
96 my $on_connect_sql = $v >= 10 ? ["ALTER SESSION SET recyclebin = OFF"] : [];
98 # iterate all tests on following options
100 { on_connect_do => $on_connect_sql },
101 { quote_char => '"', on_connect_do => $on_connect_sql },
104 # keep a database handle open for cleanup
108 for my $use_insert_returning ($test_server_supports_insert_returning ? (1,0) : (0) ) {
109 for my $force_ora_joins ($test_server_supports_only_orajoins ? (0) : (0,1) ) {
111 no warnings qw/once redefine/;
112 my $old_connection = DBICTest::Schema->can('connection');
113 local *DBICTest::Schema::connection = subname 'DBICTest::Schema::connection' => sub {
114 my $s = shift->$old_connection (@_);
115 $s->storage->_use_insert_returning ($use_insert_returning);
116 $s->storage->sql_maker_class('DBIx::Class::SQLMaker::OracleJoins') if $force_ora_joins;
120 for my $opt (@tryopt) {
121 # clean all cached sequences from previous run
122 for (map { values %{DBICTest::Schema->source($_)->columns_info} } (qw/Artist CD Track/) ) {
123 delete $_->{sequence};
126 my $schema = DBICTest::Schema->connect($dsn, $user, $pass, $opt);
128 $dbh = $schema->storage->dbh;
129 my $q = $schema->storage->sql_maker->quote_char || '';
131 do_creates($dbh, $q);
133 _run_tests($schema, $opt);
139 my ($schema, $opt) = @_;
141 my $q = $schema->storage->sql_maker->quote_char || '';
143 # test primary key handling with multiple triggers
146 my $new_artist = $schema->resultset('Artist')->create({ name => 'foo' });
147 my $new_cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
150 skip 'not detecting sequences when using INSERT ... RETURNING', 4
151 if $schema->storage->_use_insert_returning;
153 is($new_artist->artistid, 1, "Oracle Auto-PK worked for standard sqlt-like trigger");
154 $seq = $new_artist->result_source->column_info('artistid')->{sequence};
155 $seq = $$seq if ref $seq;
156 like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
158 is($new_cd->cdid, 1, 'Oracle Auto-PK worked - using scalar ref as table name/custom weird trigger');
159 $seq = $new_cd->result_source->column_info('cdid')->{sequence};
160 $seq = $$seq if ref $seq;
161 like ($seq, qr/\.${q}cd_seq${q}$/, 'Correct PK sequence selected for custom trigger');
164 # test PKs again with fully-qualified table name
165 my $artistfqn_rs = $schema->resultset('ArtistFQN');
166 my $artist_rsrc = $artistfqn_rs->result_source;
168 delete $artist_rsrc->column_info('artistid')->{sequence};
169 $new = $artistfqn_rs->create( { name => 'bar' } );
171 is_deeply( {map { $_ => $new->$_ } $artist_rsrc->primary_columns},
172 { artistid => 2, autoinc_col => 2},
173 "Oracle Multi-Auto-PK worked with fully-qualified tablename" );
176 delete $artist_rsrc->column_info('artistid')->{sequence};
177 $new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } );
179 is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" );
180 is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename");
183 is( $new->default_value_col, 'default_value', $schema->storage->_use_insert_returning
184 ? 'Check retrieve_on_insert on default_value_col with INSERT ... RETURNING'
185 : 'Check retrieve_on_insert on default_value_col without INSERT ... RETURNING'
189 skip 'not detecting sequences when using INSERT ... RETURNING', 1
190 if $schema->storage->_use_insert_returning;
192 $seq = $new->result_source->column_info('artistid')->{sequence};
193 $seq = $$seq if ref $seq;
194 like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
200 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
202 my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' } }, {
205 order_by => 'artistid'
208 is( $it->count, 2, "LIMIT count past end of RS ok" );
209 is( $it->next->name, "Artist 5", "iterator->next ok" );
210 is( $it->next->name, "Artist 6", "iterator->next ok" );
211 is( $it->next, undef, "next past end of resultset ok" );
213 # test identifiers over the 30 char limit
215 my @results = $schema->resultset('CD')->search(undef, {
216 prefetch => 'very_long_artist_relationship',
220 ok( scalar @results > 0, 'limit with long identifiers returned something');
221 } 'limit with long identifiers executed successfully';
224 # test rel names over the 30 char limit
225 my $query = $schema->resultset('Artist')->search({
228 prefetch => 'cds_very_very_very_long_relationship_name'
232 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
233 } 'query with rel name over 30 chars survived and worked';
235 # test rel names over the 30 char limit using group_by and join
237 my @group_cols = ( 'me.name' );
238 my $query = $schema->resultset('Artist')->search({
241 select => \@group_cols,
242 as => [map { /^\w+\.(\w+)$/ } @group_cols],
243 join => [qw( cds_very_very_very_long_relationship_name )],
244 group_by => \@group_cols,
248 my @got = $query->get_column('name')->all();
249 is_deeply \@got, [$new_artist->name];
250 } 'query with rel name over 30 chars worked on join, group_by for me col';
253 is $query->count(), 1
254 } 'query with rel name over 30 chars worked on join, group_by, count for me col';
257 my @group_cols = ( 'cds_very_very_very_long_relationship_name.title' );
258 my $query = $schema->resultset('Artist')->search({
261 select => \@group_cols,
262 as => [map { /^\w+\.(\w+)$/ } @group_cols],
263 join => [qw( cds_very_very_very_long_relationship_name )],
264 group_by => \@group_cols,
268 my @got = $query->get_column('title')->all();
269 is_deeply \@got, [$new_cd->title];
270 } 'query with rel name over 30 chars worked on join, group_by for long rel col';
273 is $query->count(), 1
274 } 'query with rel name over 30 chars worked on join, group_by, count for long rel col';
277 # rel name over 30 char limit with user condition
278 # This requires walking the SQLA data structure.
280 $query = $schema->resultset('Artist')->search({
281 'cds_very_very_very_long_relationship_name.title' => 'EP C'
283 prefetch => 'cds_very_very_very_long_relationship_name'
287 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
288 } 'query with rel name over 30 chars and user condition survived and worked';
292 # test join with row count ambiguity
293 my $cd = $schema->resultset('CD')->next;
294 my $track = $cd->create_related('tracks', { position => 1, title => 'Track1'} );
295 my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, {
296 join => 'cd', rows => 2
299 ok(my $row = $tjoin->next);
301 is($row->title, 'Track1', "ambiguous column ok");
305 # check count distinct with multiple columns
306 my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
308 my $tcount = $schema->resultset('Track')->search(
311 select => [ qw/position title/ ],
315 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
317 $tcount = $schema->resultset('Track')->search(
320 columns => [ qw/position title/ ],
324 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
326 $tcount = $schema->resultset('Track')->search(
329 group_by => [ qw/position title/ ]
332 is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
336 my $g_rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset => 1 });
337 is( scalar $g_rs->all, 1, "Group by with limit OK" );
340 # test with_deferred_fk_checks
342 $schema->storage->with_deferred_fk_checks(sub {
343 $schema->resultset('Track')->create({
344 trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
346 $schema->resultset('CD')->create({
347 artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
350 } 'with_deferred_fk_checks code survived';
352 is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
353 'code in with_deferred_fk_checks worked';
356 $schema->resultset('Track')->create({
357 trackid => 1, cd => 9999, position => 1, title => 'Track1'
359 } qr/constraint/i, 'with_deferred_fk_checks is off';
362 # test auto increment using sequences WITHOUT triggers
364 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
365 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
366 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
367 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
369 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
370 is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
373 # test populate (identity, success and error handling)
374 my $art_rs = $schema->resultset('Artist');
376 my $seq_pos = $art_rs->get_column('artistid')->max;
377 ok($seq_pos, 'Starting with something in the artist table');
380 my $pop_rs = $schema->resultset('Artist')->search(
381 { name => { -like => 'pop_art_%' } },
382 { order_by => 'artistid' }
388 map { +{ name => "pop_art_$_" } }
393 [ $pop_rs->get_column('artistid')->all ],
394 [ map { $seq_pos + $_ } (1,2,3) ],
395 'Sequence works after empty-table insertion'
397 } 'Populate without identity does not throw';
401 map { +{ artistid => $_, name => "pop_art_$_" } }
406 [ $pop_rs->get_column('artistid')->all ],
407 [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ],
408 'Explicit id population works'
410 } 'Populate with identity does not throw';
414 map { +{ artistid => $_, name => "pop_art_$_" } }
417 } qr/unique constraint.+populate slice.+name => "pop_art_1"/s, 'Partially failed populate throws';
420 [ $pop_rs->get_column('artistid')->all ],
421 [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ],
422 'Partially failed populate did not alter table contents'
425 # test complex join (exercise orajoins)
426 lives_ok { is_deeply (
427 $schema->resultset('CD')->search(
428 { 'artist.name' => 'pop_art_1', 'me.cdid' => { '!=', 999} },
429 { join => 'artist', prefetch => 'tracks', rows => 4, order_by => 'tracks.trackid' }
435 single_track => undef,
440 last_updated_at => undef,
441 last_updated_on => undef,
448 last_updated_at => undef,
449 last_updated_on => undef,
457 'Correct set of data prefetched',
458 ) } 'complex prefetch ok';
460 # test sequence detection from a different schema
464 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
465 ' to run the cross-schema sequence detection test.'),
466 1) unless $dsn2 && $user2 && $user2 ne $user;
468 skip 'not detecting cross-schema sequence name when using INSERT ... RETURNING', 1
469 if $schema->storage->_use_insert_returning;
471 # Oracle8i Reference Release 2 (8.1.6)
472 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993
473 # Oracle Database Reference 10g Release 2 (10.2)
474 # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297
475 local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..."
476 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
478 my $schema2 = $schema->connect($dsn2, $user2, $pass2, $opt);
479 my $dbh2 = $schema2->storage->dbh;
481 # create identically named tables/sequences in the other schema
482 do_creates($dbh2, $q);
484 # grand select privileges to the 2nd user
485 $dbh->do("GRANT INSERT ON ${q}artist${q} TO " . uc $user2);
486 $dbh->do("GRANT SELECT ON ${q}artist${q} TO " . uc $user2);
487 $dbh->do("GRANT SELECT ON ${q}artist_pk_seq${q} TO " . uc $user2);
488 $dbh->do("GRANT SELECT ON ${q}artist_autoinc_seq${q} TO " . uc $user2);
490 # test with a fully qualified table (user1/schema prepended)
491 my $rs2 = $schema2->resultset('ArtistFQN');
492 delete $rs2->result_source->column_info('artistid')->{sequence};
495 my $row = $rs2->create({ name => 'From Different Schema' });
497 } 'used autoinc sequence across schemas';
499 # now quote the sequence name (do_creates always uses an lc name)
504 delete $rs2->result_source->column_info('artistid')->{sequence};
506 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
507 BEFORE INSERT ON ${q}artist${q}
510 IF :new.${q}artistid${q} IS NULL THEN
511 SELECT $q_seq.nextval
512 INTO :new.${q}artistid${q}
520 my $row = $rs2->create({ name => 'From Different Schema With Quoted Sequence' });
522 } 'used quoted autoinc sequence across schemas';
524 is_deeply $rs2->result_source->column_info('artistid')->{sequence},
525 \( (uc $user) . ".$q_seq"),
526 'quoted sequence name correctly extracted';
528 # try an insert operation on the default user2 artist
529 my $art1 = $schema->resultset('Artist');
530 my $art2 = $schema2->resultset('Artist');
531 my $art1_count = $art1->count || 0;
532 my $art2_count = $art2->count;
534 is( $art2_count, 0, 'No artists created yet in second schema' );
536 delete $art2->result_source->column_info('artistid')->{sequence};
537 my $new_art = $art2->create({ name => '2nd best' });
539 is ($art1->count, $art1_count, 'No new rows in main schema');
540 is ($art2->count, 1, 'One artist create in 2nd schema');
542 is( $new_art->artistid, 1, 'Expected first PK' );
557 $dbh->do("CREATE SEQUENCE ${q}artist_autoinc_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
558 $dbh->do("CREATE SEQUENCE ${q}artist_pk_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
559 $dbh->do("CREATE SEQUENCE ${q}cd_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
560 $dbh->do("CREATE SEQUENCE ${q}track_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
562 $dbh->do("CREATE SEQUENCE ${q}nonpkid_seq${q} START WITH 20 MAXVALUE 999999 MINVALUE 0");
563 # this one is always quoted as per manually specified sequence =>
564 $dbh->do('CREATE SEQUENCE "pkid1_seq" START WITH 1 MAXVALUE 999999 MINVALUE 0');
565 # this one is always unquoted as per manually specified sequence =>
566 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
568 $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))");
569 $dbh->do("ALTER TABLE ${q}artist${q} ADD (CONSTRAINT ${q}artist_pk${q} PRIMARY KEY (${q}artistid${q}))");
571 $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))");
572 $dbh->do("ALTER TABLE ${q}sequence_test${q} ADD (CONSTRAINT ${q}sequence_test_constraint${q} PRIMARY KEY (${q}pkid1${q}, ${q}pkid2${q}))");
574 # table cd will be unquoted => Oracle will see it as uppercase
575 $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))");
576 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT ${q}cd_pk${q} PRIMARY KEY (${q}cdid${q}))");
578 $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)");
579 $dbh->do("ALTER TABLE ${q}track${q} ADD (CONSTRAINT ${q}track_pk${q} PRIMARY KEY (${q}trackid${q}))");
582 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_auto${q}
583 BEFORE INSERT ON ${q}artist${q}
586 IF :new.${q}autoinc_col${q} IS NULL THEN
587 SELECT ${q}artist_autoinc_seq${q}.nextval
588 INTO :new.${q}autoinc_col${q}
595 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
596 BEFORE INSERT ON ${q}artist${q}
599 IF :new.${q}artistid${q} IS NULL THEN
600 SELECT ${q}artist_pk_seq${q}.nextval
601 INTO :new.${q}artistid${q}
608 CREATE OR REPLACE TRIGGER ${q}cd_insert_trg${q}
609 BEFORE INSERT OR UPDATE ON cd
618 IF :new.${q}cdid${q} IS NULL THEN
619 SELECT ${q}cd_seq${q}.nextval
623 :new.${q}cdid${q} := tmpVar;
629 CREATE OR REPLACE TRIGGER ${q}track_insert_trg${q}
630 BEFORE INSERT ON ${q}track${q}
633 IF :new.${q}trackid${q} IS NULL THEN
634 SELECT ${q}track_seq${q}.nextval
635 INTO :new.${q}trackid${q}
645 my $dbh = shift || return;
647 for my $q ('', '"') {
649 "DROP TRIGGER ${q}track_insert_trg${q}",
650 "DROP TRIGGER ${q}cd_insert_trg${q}",
651 "DROP TRIGGER ${q}artist_insert_trg_auto${q}",
652 "DROP TRIGGER ${q}artist_insert_trg_pk${q}",
653 "DROP SEQUENCE ${q}nonpkid_seq${q}",
654 "DROP SEQUENCE ${q}pkid2_seq${q}",
655 "DROP SEQUENCE ${q}pkid1_seq${q}",
656 "DROP SEQUENCE ${q}track_seq${q}",
657 "DROP SEQUENCE ${q}cd_seq${q}",
658 "DROP SEQUENCE ${q}artist_autoinc_seq${q}",
659 "DROP SEQUENCE ${q}artist_pk_seq${q}",
660 "DROP TABLE ${q}bindtype_test${q}",
661 "DROP TABLE ${q}sequence_test${q}",
662 "DROP TABLE ${q}track${q}",
663 "DROP TABLE ${q}cd${q}",
664 "DROP TABLE ${q}artist${q}",
666 eval { $dbh -> do ($_) } for @clean;
673 local $SIG{__WARN__} = sub {};