2 package # hide from PAUSE
3 DBICTest::Schema::ArtistFQN;
5 use base 'DBIx::Class::Core';
8 $ENV{DBICTEST_ORA_USER}
9 ? (uc $ENV{DBICTEST_ORA_USER}) . '.artist'
12 __PACKAGE__->add_columns(
14 data_type => 'integer',
15 is_auto_increment => 1,
18 data_type => 'varchar',
23 data_type => 'integer',
24 is_auto_increment => 1,
27 __PACKAGE__->set_primary_key(qw/ artistid autoinc_col /);
41 use DBIC::SqlMakerTest;
43 plan skip_all => 'Test needs ' . DBIx::Class::Optional::Dependencies->req_missing_for ('test_rdbms_oracle')
44 unless DBIx::Class::Optional::Dependencies->req_ok_for ('test_rdbms_oracle');
46 $ENV{NLS_SORT} = "BINARY";
47 $ENV{NLS_COMP} = "BINARY";
48 $ENV{NLS_LANG} = "AMERICAN";
50 my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
53 my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_ORA_EXTRAUSER_${_}" } qw/DSN USER PASS/};
55 plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test.'
56 unless ($dsn && $user && $pass);
58 DBICTest::Schema->load_classes('ArtistFQN');
60 # This is in Core now, but it's here just to test that it doesn't break
61 DBICTest::Schema::Artist->load_components('PK::Auto');
62 # These are compat shims for PK::Auto...
63 DBICTest::Schema::CD->load_components('PK::Auto::Oracle');
64 DBICTest::Schema::Track->load_components('PK::Auto::Oracle');
68 # recyclebin sometimes comes in the way
69 my $on_connect_sql = ["ALTER SESSION SET recyclebin = OFF"];
71 # iterate all tests on following options
73 { on_connect_do => $on_connect_sql },
74 { quote_char => '"', on_connect_do => $on_connect_sql, },
77 # keep a database handle open for cleanup
80 # test insert returning
82 # check if we indeed do support stuff
83 my $test_server_supports_insert_returning = do {
84 my $v = DBICTest::Schema->connect($dsn, $user, $pass)
89 or die "Unparseable Oracle server version: $v\n";
91 # TODO find out which version supports the RETURNING syntax
92 # 8i has it and earlier docs are a 404 on oracle.com
93 ( $1 > 8 || ($1 == 8 && $2 >= 1) ) ? 1 : 0;
96 DBICTest::Schema->connect($dsn, $user, $pass)->storage->_use_insert_returning,
97 $test_server_supports_insert_returning,
98 'insert returning capability guessed correctly'
102 for my $use_insert_returning ($test_server_supports_insert_returning
107 no warnings qw/once/;
108 local *DBICTest::Schema::connection = subname 'DBICTest::Schema::connection' => sub {
109 my $s = shift->next::method (@_);
110 $s->storage->_use_insert_returning ($use_insert_returning);
114 for my $opt (@tryopt) {
115 # clean all cached sequences from previous run
116 for (map { values %{DBICTest::Schema->source($_)->columns_info} } (qw/Artist CD Track/) ) {
117 delete $_->{sequence};
120 my $schema = DBICTest::Schema->connect($dsn, $user, $pass, $opt);
122 $dbh = $schema->storage->dbh;
123 my $q = $schema->storage->sql_maker->quote_char || '';
125 do_creates($dbh, $q);
127 _run_tests($schema, $opt);
132 my ($schema, $opt) = @_;
134 my $q = $schema->storage->sql_maker->quote_char || '';
136 # test primary key handling with multiple triggers
139 my $new_artist = $schema->resultset('Artist')->create({ name => 'foo' });
140 my $new_cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
143 skip 'not detecting sequences when using INSERT ... RETURNING', 4
144 if $schema->storage->_use_insert_returning;
146 is($new_artist->artistid, 1, "Oracle Auto-PK worked for standard sqlt-like trigger");
147 $seq = $new_artist->result_source->column_info('artistid')->{sequence};
148 $seq = $$seq if ref $seq;
149 like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
151 is($new_cd->cdid, 1, 'Oracle Auto-PK worked - using scalar ref as table name/custom weird trigger');
152 $seq = $new_cd->result_source->column_info('cdid')->{sequence};
153 $seq = $$seq if ref $seq;
154 like ($seq, qr/\.${q}cd_seq${q}$/, 'Correct PK sequence selected for custom trigger');
157 # test PKs again with fully-qualified table name
158 my $artistfqn_rs = $schema->resultset('ArtistFQN');
159 my $artist_rsrc = $artistfqn_rs->result_source;
161 delete $artist_rsrc->column_info('artistid')->{sequence};
162 $new = $artistfqn_rs->create( { name => 'bar' } );
164 is_deeply( {map { $_ => $new->$_ } $artist_rsrc->primary_columns},
165 { artistid => 2, autoinc_col => 2},
166 "Oracle Multi-Auto-PK worked with fully-qualified tablename" );
169 delete $artist_rsrc->column_info('artistid')->{sequence};
170 $new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } );
172 is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" );
173 is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename");
176 skip 'not detecting sequences when using INSERT ... RETURNING', 1
177 if $schema->storage->_use_insert_returning;
179 $seq = $new->result_source->column_info('artistid')->{sequence};
180 $seq = $$seq if ref $seq;
181 like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
187 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
189 my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' } }, {
192 order_by => 'artistid'
195 is( $it->count, 2, "LIMIT count past end of RS ok" );
196 is( $it->next->name, "Artist 5", "iterator->next ok" );
197 is( $it->next->name, "Artist 6", "iterator->next ok" );
198 is( $it->next, undef, "next past end of resultset ok" );
201 # test identifiers over the 30 char limit
203 my @results = $schema->resultset('CD')->search(undef, {
204 prefetch => 'very_long_artist_relationship',
208 ok( scalar @results > 0, 'limit with long identifiers returned something');
209 } 'limit with long identifiers executed successfully';
212 # test rel names over the 30 char limit
213 my $query = $schema->resultset('Artist')->search({
216 prefetch => 'cds_very_very_very_long_relationship_name'
220 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
221 } 'query with rel name over 30 chars survived and worked';
223 # rel name over 30 char limit with user condition
224 # This requires walking the SQLA data structure.
226 local $TODO = 'user condition on rel longer than 30 chars';
228 $query = $schema->resultset('Artist')->search({
229 'cds_very_very_very_long_relationship_name.title' => 'EP C'
231 prefetch => 'cds_very_very_very_long_relationship_name'
235 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
236 } 'query with rel name over 30 chars and user condition survived and worked';
240 # test join with row count ambiguity
241 my $cd = $schema->resultset('CD')->next;
242 my $track = $cd->create_related('tracks', { position => 1, title => 'Track1'} );
243 my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, {
244 join => 'cd', rows => 2
247 ok(my $row = $tjoin->next);
249 is($row->title, 'Track1', "ambiguous column ok");
253 # check count distinct with multiple columns
254 my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
256 my $tcount = $schema->resultset('Track')->search(
259 select => [ qw/position title/ ],
263 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
265 $tcount = $schema->resultset('Track')->search(
268 columns => [ qw/position title/ ],
272 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
274 $tcount = $schema->resultset('Track')->search(
277 group_by => [ qw/position title/ ]
280 is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
284 my $g_rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset => 1 });
285 is( scalar $g_rs->all, 1, "Group by with limit OK" );
288 # test with_deferred_fk_checks
290 $schema->storage->with_deferred_fk_checks(sub {
291 $schema->resultset('Track')->create({
292 trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
294 $schema->resultset('CD')->create({
295 artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
298 } 'with_deferred_fk_checks code survived';
300 is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
301 'code in with_deferred_fk_checks worked';
304 $schema->resultset('Track')->create({
305 trackid => 1, cd => 9999, position => 1, title => 'Track1'
307 } qr/constraint/i, 'with_deferred_fk_checks is off';
310 # test auto increment using sequences WITHOUT triggers
312 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
313 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
314 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
315 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
317 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
318 is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
324 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
325 $binstr{'large'} = $binstr{'small'} x 1024;
327 my $maxloblen = length $binstr{'large'};
328 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
329 local $dbh->{'LongReadLen'} = $maxloblen;
331 my $rs = $schema->resultset('BindType');
334 if ($DBD::Oracle::VERSION eq '1.23') {
335 throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
337 'throws on blob insert with DBD::Oracle == 1.23';
339 skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
342 # disable BLOB mega-output
343 my $orig_debug = $schema->storage->debug;
344 $schema->storage->debug (0);
346 local $TODO = 'Something is confusing column bindtype assignment when quotes are active'
349 foreach my $type (qw( blob clob )) {
350 foreach my $size (qw( small large )) {
353 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
354 "inserted $size $type without dying";
355 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
359 $schema->storage->debug ($orig_debug);
362 # test populate (identity, success and error handling)
363 my $art_rs = $schema->resultset('Artist');
365 my $seq_pos = $art_rs->get_column('artistid')->max;
366 ok($seq_pos, 'Starting with something in the artist table');
369 my $pop_rs = $schema->resultset('Artist')->search(
370 { name => { -like => 'pop_art_%' } },
371 { order_by => 'artistid' }
377 map { +{ name => "pop_art_$_" } }
382 [ $pop_rs->get_column('artistid')->all ],
383 [ map { $seq_pos + $_ } (1,2,3) ],
384 'Sequence works after empty-table insertion'
386 } 'Populate without identity does not throw';
390 map { +{ artistid => $_, name => "pop_art_$_" } }
395 [ $pop_rs->get_column('artistid')->all ],
396 [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ],
397 'Explicit id population works'
399 } 'Populate with identity does not throw';
403 map { +{ artistid => $_, name => "pop_art_$_" } }
406 } qr/unique constraint.+populate slice.+name => "pop_art_1"/s, 'Partially failed populate throws';
409 [ $pop_rs->get_column('artistid')->all ],
410 [ 1,2,3, map { $seq_pos + $_ } (1,2,3) ],
411 'Partially failed populate did not alter table contents'
414 # test sequence detection from a different schema
418 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
419 ' to run the cross-schema sequence detection test.'),
420 1) unless $dsn2 && $user2 && $user2 ne $user;
422 skip 'not detecting cross-schema sequence name when using INSERT ... RETURNING', 1
423 if $schema->storage->_use_insert_returning;
425 # Oracle8i Reference Release 2 (8.1.6)
426 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993
427 # Oracle Database Reference 10g Release 2 (10.2)
428 # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297
429 local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..."
430 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
432 my $schema2 = $schema->connect($dsn2, $user2, $pass2, $opt);
433 my $dbh2 = $schema2->storage->dbh;
435 # create identically named tables/sequences in the other schema
436 do_creates($dbh2, $q);
438 # grand select privileges to the 2nd user
439 $dbh->do("GRANT INSERT ON ${q}artist${q} TO " . uc $user2);
440 $dbh->do("GRANT SELECT ON ${q}artist_pk_seq${q} TO " . uc $user2);
441 $dbh->do("GRANT SELECT ON ${q}artist_autoinc_seq${q} TO " . uc $user2);
443 # test with a fully qualified table (user1/schema prepended)
444 my $rs2 = $schema2->resultset('ArtistFQN');
445 delete $rs2->result_source->column_info('artistid')->{sequence};
448 my $row = $rs2->create({ name => 'From Different Schema' });
450 } 'used autoinc sequence across schemas';
452 # now quote the sequence name (do_creates always uses an lc name)
457 delete $rs2->result_source->column_info('artistid')->{sequence};
459 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
460 BEFORE INSERT ON ${q}artist${q}
463 IF :new.${q}artistid${q} IS NULL THEN
464 SELECT $q_seq.nextval
465 INTO :new.${q}artistid${q}
473 my $row = $rs2->create({ name => 'From Different Schema With Quoted Sequence' });
475 } 'used quoted autoinc sequence across schemas';
477 is_deeply $rs2->result_source->column_info('artistid')->{sequence},
478 \( (uc $user) . ".$q_seq"),
479 'quoted sequence name correctly extracted';
481 # try an insert operation on the default user2 artist
482 my $art1 = $schema->resultset('Artist');
483 my $art2 = $schema2->resultset('Artist');
484 my $art1_count = $art1->count || 0;
485 my $art2_count = $art2->count;
487 is( $art2_count, 0, 'No artists created yet in second schema' );
489 delete $art2->result_source->column_info('artistid')->{sequence};
490 my $new_art = $art2->create({ name => '2nd best' });
492 is ($art1->count, $art1_count, 'No new rows in main schema');
493 is ($art2->count, 1, 'One artist create in 2nd schema');
495 is( $new_art->artistid, 1, 'Expected first PK' );
510 $dbh->do("CREATE SEQUENCE ${q}artist_autoinc_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
511 $dbh->do("CREATE SEQUENCE ${q}artist_pk_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
512 $dbh->do("CREATE SEQUENCE ${q}cd_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
513 $dbh->do("CREATE SEQUENCE ${q}track_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
515 $dbh->do("CREATE SEQUENCE ${q}nonpkid_seq${q} START WITH 20 MAXVALUE 999999 MINVALUE 0");
516 # this one is always quoted as per manually specified sequence =>
517 $dbh->do('CREATE SEQUENCE "pkid1_seq" START WITH 1 MAXVALUE 999999 MINVALUE 0');
518 # this one is always unquoted as per manually specified sequence =>
519 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
521 $dbh->do("CREATE TABLE ${q}artist${q} (${q}artistid${q} NUMBER(12), ${q}name${q} VARCHAR(255), ${q}autoinc_col${q} NUMBER(12), ${q}rank${q} NUMBER(38), ${q}charfield${q} VARCHAR2(10))");
522 $dbh->do("ALTER TABLE ${q}artist${q} ADD (CONSTRAINT ${q}artist_pk${q} PRIMARY KEY (${q}artistid${q}))");
524 $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))");
525 $dbh->do("ALTER TABLE ${q}sequence_test${q} ADD (CONSTRAINT ${q}sequence_test_constraint${q} PRIMARY KEY (${q}pkid1${q}, ${q}pkid2${q}))");
527 # table cd will be unquoted => Oracle will see it as uppercase
528 $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))");
529 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT ${q}cd_pk${q} PRIMARY KEY (${q}cdid${q}))");
531 $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)");
532 $dbh->do("ALTER TABLE ${q}track${q} ADD (CONSTRAINT ${q}track_pk${q} PRIMARY KEY (${q}trackid${q}))");
534 $dbh->do("CREATE TABLE ${q}bindtype_test${q} (${q}id${q} integer NOT NULL PRIMARY KEY, ${q}bytea${q} integer NULL, ${q}blob${q} blob NULL, ${q}clob${q} clob NULL)");
537 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_auto${q}
538 BEFORE INSERT ON ${q}artist${q}
541 IF :new.${q}autoinc_col${q} IS NULL THEN
542 SELECT ${q}artist_autoinc_seq${q}.nextval
543 INTO :new.${q}autoinc_col${q}
550 CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
551 BEFORE INSERT ON ${q}artist${q}
554 IF :new.${q}artistid${q} IS NULL THEN
555 SELECT ${q}artist_pk_seq${q}.nextval
556 INTO :new.${q}artistid${q}
563 CREATE OR REPLACE TRIGGER ${q}cd_insert_trg${q}
564 BEFORE INSERT OR UPDATE ON cd
573 IF :new.${q}cdid${q} IS NULL THEN
574 SELECT ${q}cd_seq${q}.nextval
578 :new.${q}cdid${q} := tmpVar;
584 CREATE OR REPLACE TRIGGER ${q}track_insert_trg${q}
585 BEFORE INSERT ON ${q}track${q}
588 IF :new.${q}trackid${q} IS NULL THEN
589 SELECT ${q}track_seq${q}.nextval
590 INTO :new.${q}trackid${q}
600 my $dbh = shift || return;
602 for my $q ('', '"') {
604 "DROP TRIGGER ${q}track_insert_trg${q}",
605 "DROP TRIGGER ${q}cd_insert_trg${q}",
606 "DROP TRIGGER ${q}artist_insert_trg_auto${q}",
607 "DROP TRIGGER ${q}artist_insert_trg_pk${q}",
608 "DROP SEQUENCE ${q}nonpkid_seq${q}",
609 "DROP SEQUENCE ${q}pkid2_seq${q}",
610 "DROP SEQUENCE ${q}pkid1_seq${q}",
611 "DROP SEQUENCE ${q}track_seq${q}",
612 "DROP SEQUENCE ${q}cd_seq${q}",
613 "DROP SEQUENCE ${q}artist_autoinc_seq${q}",
614 "DROP SEQUENCE ${q}artist_pk_seq${q}",
615 "DROP TABLE ${q}bindtype_test${q}",
616 "DROP TABLE ${q}sequence_test${q}",
617 "DROP TABLE ${q}track${q}",
618 "DROP TABLE ${q}cd${q}",
619 "DROP TABLE ${q}artist${q}",
621 eval { $dbh -> do ($_) } for @clean;
628 local $SIG{__WARN__} = sub {};