use base 'DBIx::Class::Core';
__PACKAGE__->table(
- defined $ENV{DBICTEST_ORA_USER}
- ? $ENV{DBICTEST_ORA_USER} . '.artist'
+ defined $ENV{DBICTEST_ORA_USER}
+ ? (uc $ENV{DBICTEST_ORA_USER}) . '.artist'
: 'artist'
);
__PACKAGE__->add_columns(
- 'artistid' => {
- data_type => 'integer',
- is_auto_increment => 1,
- },
- 'name' => {
- data_type => 'varchar',
- size => 100,
- is_nullable => 1,
- },
- 'autoinc_col' => {
- data_type => 'integer',
- is_auto_increment => 1,
- },
+ 'artistid' => {
+ data_type => 'integer',
+ is_auto_increment => 1,
+ },
+ 'name' => {
+ data_type => 'varchar',
+ size => 100,
+ is_nullable => 1,
+ },
+ 'autoinc_col' => {
+ data_type => 'integer',
+ is_auto_increment => 1,
+ },
);
__PACKAGE__->set_primary_key('artistid');
unless ($dsn && $user && $pass);
DBICTest::Schema->load_classes('ArtistFQN');
-my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
-note "Oracle Version: " . $schema->storage->_server_info->{dbms_version};
+# This is in Core now, but it's here just to test that it doesn't break
+DBICTest::Schema::Artist->load_components('PK::Auto');
+# These are compat shims for PK::Auto...
+DBICTest::Schema::CD->load_components('PK::Auto::Oracle');
+DBICTest::Schema::Track->load_components('PK::Auto::Oracle');
-my $dbh = $schema->storage->dbh;
-do_creates($dbh);
+##########
+# recyclebin sometimes comes in the way
+my $on_connect_sql = ["ALTER SESSION SET recyclebin = OFF"];
-# This is in Core now, but it's here just to test that it doesn't break
-$schema->class('Artist')->load_components('PK::Auto');
-# These are compat shims for PK::Auto...
-$schema->class('CD')->load_components('PK::Auto::Oracle');
-$schema->class('Track')->load_components('PK::Auto::Oracle');
+# iterate all tests on following options
+my @tryopt = (
+ { on_connect_do => $on_connect_sql },
+ { quote_char => '"', on_connect_do => $on_connect_sql, },
+);
+
+# keep a database handle open for cleanup
+my $dbh;
+for my $opt (@tryopt) {
+ # clean all cached sequences from previous run
+ for (map { values %{DBICTest::Schema->source($_)->columns_info} } (qw/Artist CD Track/) ) {
+ delete $_->{sequence};
+ }
+
+ my $schema = DBICTest::Schema->connect($dsn, $user, $pass, $opt);
+ my $q = $schema -> storage -> sql_maker -> quote_char || '';
+
+ $dbh = $schema->storage->dbh;
+
+ do_creates($dbh, $q);
# test primary key handling with multiple triggers
-my $new = $schema->resultset('Artist')->create({ name => 'foo' });
-is($new->artistid, 1, "Oracle Auto-PK worked for sqlt-like trigger");
+ my ($new, $seq);
-like ($new->result_source->column_info('artistid')->{sequence}, qr/\.artist_pk_seq$/, 'Correct PK sequence selected for sqlt-like trigger');
+ $new = $schema->resultset('Artist')->create({ name => 'foo' });
+ is($new->artistid, 1, "Oracle Auto-PK worked for standard sqlt-like trigger");
+ $seq = $new->result_source->column_info('artistid')->{sequence};
+ $seq = $$seq if ref $seq;
+ like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
-$new = $schema->resultset('CD')->create({ artist => 1, title => 'foo', year => '2003' });
-is($new->cdid, 1, "Oracle Auto-PK worked for custom trigger");
+ $new = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
+ is($new->cdid, 1, 'Oracle Auto-PK worked - using scalar ref as table name/custom weird trigger');
+ $seq = $new->result_source->column_info('cdid')->{sequence};
+ $seq = $$seq if ref $seq;
+ like ($seq, qr/\.${q}cd_seq${q}$/, 'Correct PK sequence selected for custom trigger');
-like ($new->result_source->column_info('cdid')->{sequence}, qr/\.cd_seq$/, 'Correct PK sequence selected for custom trigger');
-# test again with fully-qualified table name
-my $artistfqn_rs = $schema->resultset('ArtistFQN');
-my $artist_rsrc = $artistfqn_rs->result_source;
+# test PKs again with fully-qualified table name
+ my $artistfqn_rs = $schema->resultset('ArtistFQN');
+ my $artist_rsrc = $artistfqn_rs->result_source;
-delete $artist_rsrc->column_info('artistid')->{sequence};
+ delete $artist_rsrc->column_info('artistid')->{sequence};
+ $new = $artistfqn_rs->create( { name => 'bar' } );
-$new = $artistfqn_rs->create( { name => 'bar' } );
-is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
+ is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
-delete $artist_rsrc->column_info('artistid')->{sequence};
-$new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } );
-is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" );
-is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename");
+ delete $artist_rsrc->column_info('artistid')->{sequence};
+ $new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } );
+
+ is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" );
+ is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename");
+ $seq = $new->result_source->column_info('artistid')->{sequence};
+ $seq = $$seq if ref $seq;
+ like ($seq, qr/\.${q}artist_pk_seq${q}$/, 'Correct PK sequence selected for sqlt-like trigger');
-like ($artist_rsrc->column_info('artistid')->{sequence}, qr/\.artist_pk_seq$/, 'Still correct PK sequence');
# test LIMIT support
-for (1..6) {
+ for (1..6) {
$schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
-}
-my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' }},
- { rows => 3,
- offset => 4,
- order_by => 'artistid' }
-);
-is( $it->count, 2, "LIMIT count past end of RS ok" );
-is( $it->next->name, "Artist 5", "iterator->next ok" );
-is( $it->next->name, "Artist 6", "iterator->next ok" );
-is( $it->next, undef, "next past end of resultset ok" );
+ }
+ my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' } }, {
+ rows => 3,
+ offset => 4,
+ order_by => 'artistid'
+ });
+
+ is( $it->count, 2, "LIMIT count past end of RS ok" );
+ is( $it->next->name, "Artist 5", "iterator->next ok" );
+ is( $it->next->name, "Artist 6", "iterator->next ok" );
+ is( $it->next, undef, "next past end of resultset ok" );
+
+
+# test identifiers over the 30 char limit
+ lives_ok {
+ my @results = $schema->resultset('CD')->search(undef, {
+ prefetch => 'very_long_artist_relationship',
+ rows => 3,
+ offset => 0,
+ })->all;
+ ok( scalar @results > 0, 'limit with long identifiers returned something');
+ } 'limit with long identifiers executed successfully';
-my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
-is($cd->cdid, 2, "Oracle Auto-PK worked - using scalar ref as table name");
# test rel names over the 30 char limit
-{
my $query = $schema->resultset('Artist')->search({
artistid => 1
}, {
});
lives_and {
- is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 2
+ is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
} 'query with rel name over 30 chars survived and worked';
# rel name over 30 char limit with user condition
is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
} 'query with rel name over 30 chars and user condition survived and worked';
}
-}
+
# test join with row count ambiguity
+ my $cd = $schema->resultset('CD')->next;
+ my $track = $cd->create_related('tracks', { position => 1, title => 'Track1'} );
+ my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, {
+ join => 'cd', rows => 2
+ });
-my $track = $schema->resultset('Track')->create({ cd => $cd->cdid,
- position => 1, title => 'Track1' });
-my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
- { join => 'cd',
- rows => 2 }
-);
+ ok(my $row = $tjoin->next);
+
+ is($row->title, 'Track1', "ambiguous column ok");
-ok(my $row = $tjoin->next);
-is($row->title, 'Track1', "ambiguous column ok");
# check count distinct with multiple columns
-my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
+ my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
-my $tcount = $schema->resultset('Track')->search(
- {},
- {
- select => [ qw/position title/ ],
- distinct => 1,
- }
-);
-is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
+ my $tcount = $schema->resultset('Track')->search(
+ {},
+ {
+ select => [ qw/position title/ ],
+ distinct => 1,
+ }
+ );
+ is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
-$tcount = $schema->resultset('Track')->search(
- {},
- {
- columns => [ qw/position title/ ],
- distinct => 1,
- }
-);
-is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
+ $tcount = $schema->resultset('Track')->search(
+ {},
+ {
+ columns => [ qw/position title/ ],
+ distinct => 1,
+ }
+ );
+ is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
-$tcount = $schema->resultset('Track')->search(
- {},
- {
- group_by => [ qw/position title/ ]
- }
-);
-is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
+ $tcount = $schema->resultset('Track')->search(
+ {},
+ {
+ group_by => [ qw/position title/ ]
+ }
+ );
+ is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
-{
- my $rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset=>1 });
- my @results = $rs->all;
- is( scalar @results, 1, "Group by with limit OK" );
-}
-# test identifiers over the 30 char limit
-{
- lives_ok {
- my @results = $schema->resultset('CD')->search(undef, {
- prefetch => 'very_long_artist_relationship',
- rows => 3,
- offset => 0,
- })->all;
- ok( scalar @results > 0, 'limit with long identifiers returned something');
- } 'limit with long identifiers executed successfully';
-}
+# check group_by
+ my $g_rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset => 1 });
+ is( scalar $g_rs->all, 1, "Group by with limit OK" );
+
# test with_deferred_fk_checks
-lives_ok {
- $schema->storage->with_deferred_fk_checks(sub {
- $schema->resultset('Track')->create({
- trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
- });
- $schema->resultset('CD')->create({
- artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
+ lives_ok {
+ $schema->storage->with_deferred_fk_checks(sub {
+ $schema->resultset('Track')->create({
+ trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
+ });
+ $schema->resultset('CD')->create({
+ artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
+ });
});
- });
-} 'with_deferred_fk_checks code survived';
+ } 'with_deferred_fk_checks code survived';
-is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
- 'code in with_deferred_fk_checks worked';
+ is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
+ 'code in with_deferred_fk_checks worked';
+
+ throws_ok {
+ $schema->resultset('Track')->create({
+ trackid => 1, cd => 9999, position => 1, title => 'Track1'
+ });
+ } qr/constraint/i, 'with_deferred_fk_checks is off';
-throws_ok {
- $schema->resultset('Track')->create({
- trackid => 1, cd => 9999, position => 1, title => 'Track1'
- });
-} qr/constraint/i, 'with_deferred_fk_checks is off';
# test auto increment using sequences WITHOUT triggers
-for (1..5) {
+ for (1..5) {
my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
-}
-my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
-is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
+ }
+ my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
+ is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
+
# test BLOBs
-SKIP: {
- my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
- $binstr{'large'} = $binstr{'small'} x 1024;
+ SKIP: {
+ TODO: {
+ my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
+ $binstr{'large'} = $binstr{'small'} x 1024;
- my $maxloblen = length $binstr{'large'};
- note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
- local $dbh->{'LongReadLen'} = $maxloblen;
+ my $maxloblen = length $binstr{'large'};
+ note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
+ local $dbh->{'LongReadLen'} = $maxloblen;
- my $rs = $schema->resultset('BindType');
- my $id = 0;
+ my $rs = $schema->resultset('BindType');
+ my $id = 0;
- if ($DBD::Oracle::VERSION eq '1.23') {
- throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
- qr/broken/,
- 'throws on blob insert with DBD::Oracle == 1.23';
+ if ($DBD::Oracle::VERSION eq '1.23') {
+ throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
+ qr/broken/,
+ 'throws on blob insert with DBD::Oracle == 1.23';
- skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
- }
+ skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
+ }
- # disable BLOB mega-output
- my $orig_debug = $schema->storage->debug;
- $schema->storage->debug (0);
+ # disable BLOB mega-output
+ my $orig_debug = $schema->storage->debug;
+ $schema->storage->debug (0);
- foreach my $type (qw( blob clob )) {
- foreach my $size (qw( small large )) {
- $id++;
+ local $TODO = 'Something is confusing column bindtype assignment when quotes are active'
+ if $q;
- lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
- "inserted $size $type without dying";
+ foreach my $type (qw( blob clob )) {
+ foreach my $size (qw( small large )) {
+ $id++;
- ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
+ lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
+ "inserted $size $type without dying";
+ ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
+ }
}
- }
- $schema->storage->debug ($orig_debug);
-}
+ $schema->storage->debug ($orig_debug);
+ }}
+
# test sequence detection from a different schema
-my $schema2;
-SKIP: {
-TODO: {
- skip ((join '',
- 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
- ' to run the cross-schema autoincrement test.'
- ), 1) unless $dsn2 && $user2 && $user2 ne $user;
+ SKIP: {
+ TODO: {
+ skip ((join '',
+ 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
+ ' to run the cross-schema autoincrement test.'),
+ 1) unless $dsn2 && $user2 && $user2 ne $user;
- # Oracle8i Reference Release 2 (8.1.6)
- # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993
- # Oracle Database Reference 10g Release 2 (10.2)
- # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297
- local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..."
- if $schema->storage->_server_info->{normalized_dbms_version} < 9;
+ # Oracle8i Reference Release 2 (8.1.6)
+ # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993
+ # Oracle Database Reference 10g Release 2 (10.2)
+ # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297
+ local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..."
+ if $schema->storage->_server_info->{normalized_dbms_version} < 9;
- $schema2 = DBICTest::Schema->connect($dsn2, $user2, $pass2);
+ my $schema2 = DBICTest::Schema->connect($dsn2, $user2, $pass2, $opt);
- my $schema1_dbh = $schema->storage->dbh;
- $schema1_dbh->do("GRANT INSERT ON artist TO $user2");
- $schema1_dbh->do("GRANT SELECT ON artist_pk_seq TO $user2");
+ my $schema1_dbh = $schema->storage->dbh;
+ $schema1_dbh->do("GRANT INSERT ON ${q}artist${q} TO " . uc $user2);
+ $schema1_dbh->do("GRANT SELECT ON ${q}artist_pk_seq${q} TO " . uc $user2);
- my $rs = $schema2->resultset('ArtistFQN');
- # first test with unquoted (default) sequence name in trigger body
+ my $rs = $schema2->resultset('ArtistFQN');
+ delete $rs->result_source->column_info('artistid')->{sequence};
- lives_and {
- my $row = $rs->create({ name => 'From Different Schema' });
- ok $row->artistid;
- } 'used autoinc sequence across schemas';
-
- # now quote the sequence name
- $schema1_dbh->do(qq{
- CREATE OR REPLACE TRIGGER artist_insert_trg_pk
- BEFORE INSERT ON artist
- FOR EACH ROW
- BEGIN
- IF :new.artistid IS NULL THEN
- SELECT "ARTIST_PK_SEQ".nextval
- INTO :new.artistid
- FROM DUAL;
- END IF;
- END;
- });
+ # first test with unquoted (default) sequence name in trigger body
+ lives_and {
+ my $row = $rs->create({ name => 'From Different Schema' });
+ ok $row->artistid;
+ } 'used autoinc sequence across schemas';
+
+ # now quote the sequence name (do_creates always uses an lc name)
+ my $q_seq = $q
+ ? '"artist_pk_seq"'
+ : '"ARTIST_PK_SEQ"'
+ ;
+ delete $rs->result_source->column_info('artistid')->{sequence};
+ $schema1_dbh->do(qq{
+ CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
+ BEFORE INSERT ON ${q}artist${q}
+ FOR EACH ROW
+ BEGIN
+ IF :new.${q}artistid${q} IS NULL THEN
+ SELECT $q_seq.nextval
+ INTO :new.${q}artistid${q}
+ FROM DUAL;
+ END IF;
+ END;
+ });
- # sequence is cached in the rsrc
- delete $rs->result_source->column_info('artistid')->{sequence};
- lives_and {
- my $row = $rs->create({ name => 'From Different Schema With Quoted Sequence' });
- ok $row->artistid;
- } 'used quoted autoinc sequence across schemas';
+ lives_and {
+ my $row = $rs->create({ name => 'From Different Schema With Quoted Sequence' });
+ ok $row->artistid;
+ } 'used quoted autoinc sequence across schemas';
- my $schema_name = uc $user;
+ my $schema_name = uc $user;
- is $rs->result_source->column_info('artistid')->{sequence},
- qq[${schema_name}."ARTIST_PK_SEQ"],
- 'quoted sequence name correctly extracted';
-} }
+ is_deeply $rs->result_source->column_info('artistid')->{sequence},
+ \qq|${schema_name}.$q_seq|,
+ 'quoted sequence name correctly extracted';
+ }}
+
+ do_clean ($dbh);
+}
done_testing;
sub do_creates {
- my $dbh = shift;
-
- eval {
- $dbh->do("DROP SEQUENCE artist_autoinc_seq");
- $dbh->do("DROP SEQUENCE artist_pk_seq");
- $dbh->do("DROP SEQUENCE cd_seq");
- $dbh->do("DROP SEQUENCE track_seq");
- $dbh->do("DROP SEQUENCE pkid1_seq");
- $dbh->do("DROP SEQUENCE pkid2_seq");
- $dbh->do("DROP SEQUENCE nonpkid_seq");
- $dbh->do("DROP TABLE artist");
- $dbh->do("DROP TABLE sequence_test");
- $dbh->do("DROP TABLE track");
- $dbh->do("DROP TABLE cd");
- };
- $dbh->do("CREATE SEQUENCE artist_autoinc_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE SEQUENCE artist_pk_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE SEQUENCE track_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
+ my ($dbh, $q) = @_;
+
+ do_clean($dbh);
+
+ $dbh->do("CREATE SEQUENCE ${q}artist_autoinc_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
+ $dbh->do("CREATE SEQUENCE ${q}artist_pk_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
+ $dbh->do("CREATE SEQUENCE ${q}cd_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
+ $dbh->do("CREATE SEQUENCE ${q}track_seq${q} START WITH 1 MAXVALUE 999999 MINVALUE 0");
+
+ $dbh->do("CREATE SEQUENCE ${q}nonpkid_seq${q} START WITH 20 MAXVALUE 999999 MINVALUE 0");
+ # this one is always quoted as per manually specified sequence =>
+ $dbh->do('CREATE SEQUENCE "pkid1_seq" START WITH 1 MAXVALUE 999999 MINVALUE 0');
+ # this one is always unquoted as per manually specified sequence =>
$dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0");
- $dbh->do("CREATE TABLE artist (artistid NUMBER(12), name VARCHAR(255), autoinc_col NUMBER(12), rank NUMBER(38), charfield VARCHAR2(10))");
- $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
+ $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))");
+ $dbh->do("ALTER TABLE ${q}artist${q} ADD (CONSTRAINT ${q}artist_pk${q} PRIMARY KEY (${q}artistid${q}))");
- $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
- $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
+ $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))");
+ $dbh->do("ALTER TABLE ${q}sequence_test${q} ADD (CONSTRAINT ${q}sequence_test_constraint${q} PRIMARY KEY (${q}pkid1${q}, ${q}pkid2${q}))");
- $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))");
- $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
+ # table cd will be unquoted => Oracle will see it as uppercase
+ $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))");
+ $dbh->do("ALTER TABLE cd ADD (CONSTRAINT ${q}cd_pk${q} PRIMARY KEY (${q}cdid${q}))");
- $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)");
- $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))");
+ $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, ${q}small_dt${q} DATE)");
+ $dbh->do("ALTER TABLE ${q}track${q} ADD (CONSTRAINT ${q}track_pk${q} PRIMARY KEY (${q}trackid${q}))");
- $dbh->do("CREATE TABLE bindtype_test (id integer NOT NULL PRIMARY KEY, bytea integer NULL, blob blob NULL, clob clob NULL)");
+ $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)");
$dbh->do(qq{
- CREATE OR REPLACE TRIGGER artist_insert_trg_auto
- BEFORE INSERT ON artist
+ CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_auto${q}
+ BEFORE INSERT ON ${q}artist${q}
FOR EACH ROW
BEGIN
- IF :new.autoinc_col IS NULL THEN
- SELECT artist_autoinc_seq.nextval
- INTO :new.autoinc_col
+ IF :new.${q}autoinc_col${q} IS NULL THEN
+ SELECT ${q}artist_autoinc_seq${q}.nextval
+ INTO :new.${q}autoinc_col${q}
FROM DUAL;
END IF;
END;
});
+
$dbh->do(qq{
- CREATE OR REPLACE TRIGGER artist_insert_trg_pk
- BEFORE INSERT ON artist
+ CREATE OR REPLACE TRIGGER ${q}artist_insert_trg_pk${q}
+ BEFORE INSERT ON ${q}artist${q}
FOR EACH ROW
BEGIN
- IF :new.artistid IS NULL THEN
- SELECT artist_pk_seq.nextval
- INTO :new.artistid
+ IF :new.${q}artistid${q} IS NULL THEN
+ SELECT ${q}artist_pk_seq${q}.nextval
+ INTO :new.${q}artistid${q}
FROM DUAL;
END IF;
END;
});
+
$dbh->do(qq{
- CREATE OR REPLACE TRIGGER cd_insert_trg
+ CREATE OR REPLACE TRIGGER ${q}cd_insert_trg${q}
BEFORE INSERT OR UPDATE ON cd
FOR EACH ROW
+
DECLARE
tmpVar NUMBER;
BEGIN
tmpVar := 0;
- IF :new.cdid IS NULL THEN
- SELECT cd_seq.nextval
+ IF :new.${q}cdid${q} IS NULL THEN
+ SELECT ${q}cd_seq${q}.nextval
INTO tmpVar
FROM dual;
- :new.cdid := tmpVar;
+ :new.${q}cdid${q} := tmpVar;
END IF;
END;
});
+
$dbh->do(qq{
- CREATE OR REPLACE TRIGGER track_insert_trg
- BEFORE INSERT ON track
+ CREATE OR REPLACE TRIGGER ${q}track_insert_trg${q}
+ BEFORE INSERT ON ${q}track${q}
FOR EACH ROW
BEGIN
- IF :new.trackid IS NULL THEN
- SELECT track_seq.nextval
- INTO :new.trackid
+ IF :new.${q}trackid${q} IS NULL THEN
+ SELECT ${q}track_seq${q}.nextval
+ INTO :new.${q}trackid${q}
FROM DUAL;
END IF;
END;
}
# clean up our mess
+sub do_clean {
+
+ my $dbh = shift || return;
+
+ for my $q ('', '"') {
+ my @clean = (
+ "DROP TRIGGER ${q}track_insert_trg${q}",
+ "DROP TRIGGER ${q}cd_insert_trg${q}",
+ "DROP TRIGGER ${q}artist_insert_trg_auto${q}",
+ "DROP TRIGGER ${q}artist_insert_trg_pk${q}",
+ "DROP SEQUENCE ${q}nonpkid_seq${q}",
+ "DROP SEQUENCE ${q}pkid2_seq${q}",
+ "DROP SEQUENCE ${q}pkid1_seq${q}",
+ "DROP SEQUENCE ${q}track_seq${q}",
+ "DROP SEQUENCE ${q}cd_seq${q}",
+ "DROP SEQUENCE ${q}artist_autoinc_seq${q}",
+ "DROP SEQUENCE ${q}artist_pk_seq${q}",
+ "DROP TABLE ${q}bindtype_test${q}",
+ "DROP TABLE ${q}sequence_test${q}",
+ "DROP TABLE ${q}track${q}",
+ "DROP TABLE ${q}cd${q}",
+ "DROP TABLE ${q}artist${q}",
+ );
+ eval { $dbh -> do ($_) } for @clean;
+ }
+}
+
END {
- for my $dbh (map $_->storage->dbh, grep $_, ($schema, $schema2)) {
- eval {
- $dbh->do("DROP SEQUENCE artist_autoinc_seq");
- $dbh->do("DROP SEQUENCE artist_pk_seq");
- $dbh->do("DROP SEQUENCE cd_seq");
- $dbh->do("DROP SEQUENCE track_seq");
- $dbh->do("DROP SEQUENCE pkid1_seq");
- $dbh->do("DROP SEQUENCE pkid2_seq");
- $dbh->do("DROP SEQUENCE nonpkid_seq");
- $dbh->do("DROP TABLE artist");
- $dbh->do("DROP TABLE sequence_test");
- $dbh->do("DROP TABLE track");
- $dbh->do("DROP TABLE cd");
- $dbh->do("DROP TABLE bindtype_test");
- };
+ if ($dbh) {
+ local $SIG{__WARN__} = sub {};
+ do_clean($dbh);
+ $dbh->disconnect;
}
}