2 package # hide from PAUSE
3 DBICTest::Schema::ArtistFQN;
5 use base 'DBIx::Class::Core';
8 defined $ENV{DBICTEST_ORA_USER}
9 ? $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('artistid');
40 use DBIC::SqlMakerTest;
42 my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
45 my ($dsn2, $user2, $pass2) = @ENV{map { "DBICTEST_ORA_EXTRAUSER_${_}" } qw/DSN USER PASS/};
47 plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' .
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\''
50 unless ($dsn && $user && $pass);
52 DBICTest::Schema->load_classes('ArtistFQN');
53 my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
55 note "Oracle Version: " . $schema->storage->_server_info->{dbms_version};
57 my $dbh = $schema->storage->dbh;
62 # Swiped from t/bindtype_columns.t to avoid creating my own Resultset.
64 local $SIG{__WARN__} = sub {};
65 eval { $dbh->do('DROP TABLE bindtype_test') };
68 CREATE TABLE bindtype_test
70 id integer NOT NULL PRIMARY KEY,
75 ],{ RaiseError => 1, PrintError => 1 });
78 # This is in Core now, but it's here just to test that it doesn't break
79 $schema->class('Artist')->load_components('PK::Auto');
80 # These are compat shims for PK::Auto...
81 $schema->class('CD')->load_components('PK::Auto::Oracle');
82 $schema->class('Track')->load_components('PK::Auto::Oracle');
85 # test primary key handling with multiple triggers
86 my $new = $schema->resultset('Artist')->create({ name => 'foo' });
87 is($new->artistid, 1, "Oracle Auto-PK worked for sqlt-like trigger");
89 like ($new->result_source->column_info('artistid')->{sequence}, qr/\.artist_pk_seq$/, 'Correct PK sequence selected for sqlt-like trigger');
91 $new = $schema->resultset('CD')->create({ artist => 1, title => 'foo', year => '2003' });
92 is($new->cdid, 1, "Oracle Auto-PK worked for custom trigger");
94 like ($new->result_source->column_info('cdid')->{sequence}, qr/\.cd_seq$/, 'Correct PK sequence selected for custom trigger');
96 # test again with fully-qualified table name
97 my $artistfqn_rs = $schema->resultset('ArtistFQN');
98 my $artist_rsrc = $artistfqn_rs->result_source;
100 delete $artist_rsrc->column_info('artistid')->{sequence};
102 $new = $artistfqn_rs->create( { name => 'bar' } );
103 is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
105 delete $artist_rsrc->column_info('artistid')->{sequence};
107 $new = $artistfqn_rs->create( { name => 'bar', autoinc_col => 1000 } );
108 is( $new->artistid, 3, "Oracle Auto-PK worked with fully-qualified tablename" );
109 is( $new->autoinc_col, 1000, "Oracle Auto-Inc overruled with fully-qualified tablename");
111 like ($artist_rsrc->column_info('artistid')->{sequence}, qr/\.artist_pk_seq$/, 'Still correct PK sequence');
115 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
117 my $it = $schema->resultset('Artist')->search( { name => { -like => 'Artist %' }},
120 order_by => 'artistid' }
122 is( $it->count, 2, "LIMIT count past end of RS ok" );
123 is( $it->next->name, "Artist 5", "iterator->next ok" );
124 is( $it->next->name, "Artist 6", "iterator->next ok" );
125 is( $it->next, undef, "next past end of resultset ok" );
127 my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
128 is($cd->cdid, 2, "Oracle Auto-PK worked - using scalar ref as table name");
130 # test rel names over the 30 char limit
132 my $query = $schema->resultset('Artist')->search({
135 prefetch => 'cds_very_very_very_long_relationship_name'
139 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 2
140 } 'query with rel name over 30 chars survived and worked';
142 # rel name over 30 char limit with user condition
143 # This requires walking the SQLA data structure.
145 local $TODO = 'user condition on rel longer than 30 chars';
147 $query = $schema->resultset('Artist')->search({
148 'cds_very_very_very_long_relationship_name.title' => 'EP C'
150 prefetch => 'cds_very_very_very_long_relationship_name'
154 is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1
155 } 'query with rel name over 30 chars and user condition survived and worked';
159 # test join with row count ambiguity
161 my $track = $schema->resultset('Track')->create({ cd => $cd->cdid,
162 position => 1, title => 'Track1' });
163 my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
168 ok(my $row = $tjoin->next);
170 is($row->title, 'Track1', "ambiguous column ok");
172 # check count distinct with multiple columns
173 my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
175 my $tcount = $schema->resultset('Track')->search(
178 select => [ qw/position title/ ],
182 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
184 $tcount = $schema->resultset('Track')->search(
187 columns => [ qw/position title/ ],
191 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
193 $tcount = $schema->resultset('Track')->search(
196 group_by => [ qw/position title/ ]
199 is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
202 my $rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset=>1 });
203 my @results = $rs->all;
204 is( scalar @results, 1, "Group by with limit OK" );
207 # test identifiers over the 30 char limit
210 my @results = $schema->resultset('CD')->search(undef, {
211 prefetch => 'very_long_artist_relationship',
215 ok( scalar @results > 0, 'limit with long identifiers returned something');
216 } 'limit with long identifiers executed successfully';
219 # test with_deferred_fk_checks
221 $schema->storage->with_deferred_fk_checks(sub {
222 $schema->resultset('Track')->create({
223 trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
225 $schema->resultset('CD')->create({
226 artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
229 } 'with_deferred_fk_checks code survived';
231 is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
232 'code in with_deferred_fk_checks worked';
235 $schema->resultset('Track')->create({
236 trackid => 1, cd => 9999, position => 1, title => 'Track1'
238 } qr/constraint/i, 'with_deferred_fk_checks is off';
240 # test auto increment using sequences WITHOUT triggers
242 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
243 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
244 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
245 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
247 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
248 is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
251 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
252 $binstr{'large'} = $binstr{'small'} x 1024;
254 my $maxloblen = length $binstr{'large'};
255 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
256 local $dbh->{'LongReadLen'} = $maxloblen;
258 my $rs = $schema->resultset('BindType');
261 if ($DBD::Oracle::VERSION eq '1.23') {
262 throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
264 'throws on blob insert with DBD::Oracle == 1.23';
266 skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
269 # disable BLOB mega-output
270 my $orig_debug = $schema->storage->debug;
271 $schema->storage->debug (0);
273 foreach my $type (qw( blob clob )) {
274 foreach my $size (qw( small large )) {
277 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
278 "inserted $size $type without dying";
280 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
284 $schema->storage->debug ($orig_debug);
288 ### test hierarchical queries
289 if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) {
290 my $source = $schema->source('Artist');
292 $source->add_column( 'parentid' );
294 $source->add_relationship('children', 'DBICTest::Schema::Artist',
295 { 'foreign.parentid' => 'self.artistid' },
302 $source->add_relationship('parent', 'DBICTest::Schema::Artist',
303 { 'foreign.artistid' => 'self.parentid' },
304 { accessor => 'single' } );
305 DBICTest::Schema::Artist->add_column( 'parentid' );
306 DBICTest::Schema::Artist->has_many(
307 children => 'DBICTest::Schema::Artist',
308 { 'foreign.parentid' => 'self.artistid' }
310 DBICTest::Schema::Artist->belongs_to(
311 parent => 'DBICTest::Schema::Artist',
312 { 'foreign.artistid' => 'self.parentid' }
315 $schema->resultset('Artist')->create ({
325 name => 'grandchild',
329 title => "grandchilds's cd" ,
334 title => 'Track 1 grandchild',
341 name => 'greatgrandchild',
355 $schema->resultset('Artist')->create(
357 name => 'cycle-root',
360 name => 'cycle-child1',
361 children => [ { name => 'cycle-grandchild' } ],
363 { name => 'cycle-child2' },
368 $schema->resultset('Artist')->find({ name => 'cycle-root' })
369 ->update({ parentid => { -ident => 'artistid' } });
371 # select the whole tree
373 my $rs = $schema->resultset('Artist')->search({}, {
374 start_with => { name => 'root' },
375 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
381 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
384 CONNECT BY parentid = PRIOR artistid
386 [ [ name => 'root'] ],
389 [ $rs->get_column ('name')->all ],
390 [ qw/root child1 grandchild greatgrandchild child2/ ],
396 $rs->count_rs->as_query,
401 CONNECT BY parentid = PRIOR artistid
403 [ [ name => 'root'] ],
406 is( $rs->count, 5, 'Connect By count ok' );
409 # use order siblings by statement
411 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/state21b.htm#2066123
412 skip q{Oracle8i doesn't support ORDER SIBLINGS BY}, 1
413 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
415 my $rs = $schema->resultset('Artist')->search({}, {
416 start_with => { name => 'root' },
417 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
418 order_siblings_by => { -desc => 'name' },
424 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
427 CONNECT BY parentid = PRIOR artistid
428 ORDER SIBLINGS BY name DESC
430 [ [ name => 'root'] ],
434 [ $rs->get_column ('name')->all ],
435 [ qw/root child2 child1 grandchild greatgrandchild/ ],
436 'Order Siblings By ok',
442 my $rs = $schema->resultset('Artist')->search({ parentid => undef }, {
443 start_with => { name => 'root' },
444 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
450 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
452 WHERE ( parentid IS NULL )
454 CONNECT BY parentid = PRIOR artistid
456 [ [ name => 'root'] ],
460 [ $rs->get_column('name')->all ],
466 # combine a connect by with a join
468 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/state21b.htm#2066123
469 skip q{Oracle8i doesn't support connect by with join}, 1
470 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
472 my $rs = $schema->resultset('Artist')->search(
473 {'cds.title' => { -like => '%cd'} },
476 start_with => { 'me.name' => 'root' },
477 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
484 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
486 LEFT JOIN cd cds ON cds.artist = me.artistid
487 WHERE ( cds.title LIKE ? )
488 START WITH me.name = ?
489 CONNECT BY parentid = PRIOR artistid
491 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
495 [ $rs->get_column('name')->all ],
497 'Connect By with a join result name ok'
502 $rs->count_rs->as_query,
506 LEFT JOIN cd cds ON cds.artist = me.artistid
507 WHERE ( cds.title LIKE ? )
508 START WITH me.name = ?
509 CONNECT BY parentid = PRIOR artistid
511 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
514 is( $rs->count, 1, 'Connect By with a join; count ok' );
517 # combine a connect by with order_by
519 my $rs = $schema->resultset('Artist')->search({}, {
520 start_with => { name => 'root' },
521 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
522 order_by => { -asc => [ 'LEVEL', 'name' ] },
528 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
531 CONNECT BY parentid = PRIOR artistid
532 ORDER BY LEVEL ASC, name ASC
534 [ [ name => 'root' ] ],
538 # Don't use "$rs->get_column ('name')->all" they build a query arround the $rs.
539 # If $rs has a order by, the order by is in the subquery and this doesn't work with Oracle 8i.
540 # TODO: write extra test and fix order by handling on Oracle 8i
542 [ map { $_->[1] } $rs->cursor->all ],
543 [ qw/root child1 child2 grandchild greatgrandchild/ ],
544 'Connect By with a order_by - result name ok (without get_column)'
548 skip q{Connect By with a order_by - result name ok (with get_column), Oracle8i doesn't support order by in a subquery},1
549 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
551 [ $rs->get_column ('name')->all ],
552 [ qw/root child1 child2 grandchild greatgrandchild/ ],
553 'Connect By with a order_by - result name ok (with get_column)'
561 skip q{Oracle8i doesn't support order by in a subquery}, 1
562 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
564 my $rs = $schema->resultset('Artist')->search({}, {
565 start_with => { name => 'root' },
566 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
567 order_by => { -asc => 'name' },
574 SELECT artistid, name, rank, charfield, parentid FROM (
583 CONNECT BY parentid = PRIOR artistid
588 [ [ name => 'root' ] ],
592 [ $rs->get_column ('name')->all ],
594 'LIMIT a Connect By query - correct names'
598 $rs->count_rs->as_query,
600 SELECT COUNT( * ) FROM (
607 CONNECT BY parentid = PRIOR artistid
612 [ [ name => 'root' ] ],
615 is( $rs->count, 2, 'Connect By; LIMIT count ok' );
618 # combine a connect_by with group_by and having
620 my $rs = $schema->resultset('Artist')->search({}, {
621 select => { count => 'rank', -as => 'cnt' },
622 start_with => { name => 'root' },
623 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
624 group_by => ['rank'],
625 having => \[ 'count(rank) < ?', [ cnt => 2 ] ],
631 SELECT COUNT(rank) AS cnt
634 CONNECT BY parentid = PRIOR artistid
635 GROUP BY rank HAVING count(rank) < ?
637 [ [ name => 'root' ], [ cnt => 2 ] ],
641 [ $rs->get_column ('cnt')->all ],
643 'Group By a Connect By query - correct values'
648 # select the whole cycle tree without nocylce
650 my $rs = $schema->resultset('Artist')->search({}, {
651 start_with => { name => 'cycle-root' },
652 connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
654 eval { $rs->get_column ('name')->all };
655 if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data
656 pass "connect by initify loop detection without nocycle";
658 fail "connect by initify loop detection without nocycle, not detected by oracle";
662 # select the whole cycle tree with nocylce
664 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/expressi.htm#1023748
665 skip q{Oracle8i doesn't support connect by nocycle}, 1
666 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
668 my $rs = $schema->resultset('Artist')->search({}, {
669 start_with => { name => 'cycle-root' },
670 '+select' => \ 'CONNECT_BY_ISCYCLE',
671 '+as' => [ 'connector' ],
672 connect_by_nocycle => { parentid => { -prior => { -ident => 'artistid' } } },
678 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE
681 CONNECT BY NOCYCLE parentid = PRIOR artistid
683 [ [ name => 'cycle-root'] ],
686 [ $rs->get_column ('name')->all ],
687 [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ],
688 'got artist tree with nocycle (name)',
691 [ $rs->get_column ('connector')->all ],
693 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)',
698 $rs->count_rs->as_query,
703 CONNECT BY NOCYCLE parentid = PRIOR artistid
705 [ [ name => 'cycle-root'] ],
708 is( $rs->count, 4, 'Connect By Nocycle count ok' );
714 # test sequence detection from a different schema
718 'Set DBICTEST_ORA_EXTRAUSER_DSN, _USER and _PASS to a *DIFFERENT* Oracle user',
719 ' to run the cross-schema autoincrement test.'),
720 1) unless $dsn2 && $user2 && $user2 ne $user;
722 # Oracle8i Reference Release 2 (8.1.6)
723 # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a76961/ch294.htm#993
724 # Oracle Database Reference 10g Release 2 (10.2)
725 # http://download.oracle.com/docs/cd/B19306_01/server.102/b14237/statviews_2107.htm#sthref1297
726 local $TODO = "On Oracle8i all_triggers view is empty, i don't yet know why..."
727 if $schema->storage->_server_info->{normalized_dbms_version} < 9;
729 $schema2 = DBICTest::Schema->connect($dsn2, $user2, $pass2);
731 my $schema1_dbh = $schema->storage->dbh;
733 $schema1_dbh->do("GRANT INSERT ON artist TO $user2");
734 $schema1_dbh->do("GRANT SELECT ON artist_pk_seq TO $user2");
736 my $rs = $schema2->resultset('ArtistFQN');
738 # first test with unquoted (default) sequence name in trigger body
741 my $row = $rs->create({ name => 'From Different Schema' });
743 } 'used autoinc sequence across schemas';
745 # now quote the sequence name
747 CREATE OR REPLACE TRIGGER artist_insert_trg_pk
748 BEFORE INSERT ON artist
751 IF :new.artistid IS NULL THEN
752 SELECT "ARTIST_PK_SEQ".nextval
759 # sequence is cached in the rsrc
760 delete $rs->result_source->column_info('artistid')->{sequence};
763 my $row = $rs->create({ name => 'From Different Schema With Quoted Sequence' });
765 } 'used quoted autoinc sequence across schemas';
767 my $schema_name = uc $user;
769 is $rs->result_source->column_info('artistid')->{sequence},
770 qq[${schema_name}."ARTIST_PK_SEQ"],
771 'quoted sequence name correctly extracted';
780 $dbh->do("DROP SEQUENCE artist_autoinc_seq");
781 $dbh->do("DROP SEQUENCE artist_pk_seq");
782 $dbh->do("DROP SEQUENCE cd_seq");
783 $dbh->do("DROP SEQUENCE track_seq");
784 $dbh->do("DROP SEQUENCE pkid1_seq");
785 $dbh->do("DROP SEQUENCE pkid2_seq");
786 $dbh->do("DROP SEQUENCE nonpkid_seq");
787 $dbh->do("DROP TABLE artist");
788 $dbh->do("DROP TABLE sequence_test");
789 $dbh->do("DROP TABLE track");
790 $dbh->do("DROP TABLE cd");
792 $dbh->do("CREATE SEQUENCE artist_autoinc_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
793 $dbh->do("CREATE SEQUENCE artist_pk_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
794 $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
795 $dbh->do("CREATE SEQUENCE track_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
796 $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
797 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
798 $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0");
800 $dbh->do("CREATE TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), autoinc_col NUMBER(12), rank NUMBER(38), charfield VARCHAR2(10))");
801 $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
803 $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
804 $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
806 $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))");
807 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
809 $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)");
810 $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))");
813 CREATE OR REPLACE TRIGGER artist_insert_trg_auto
814 BEFORE INSERT ON artist
817 IF :new.autoinc_col IS NULL THEN
818 SELECT artist_autoinc_seq.nextval
819 INTO :new.autoinc_col
825 CREATE OR REPLACE TRIGGER artist_insert_trg_pk
826 BEFORE INSERT ON artist
829 IF :new.artistid IS NULL THEN
830 SELECT artist_pk_seq.nextval
837 CREATE OR REPLACE TRIGGER cd_insert_trg
838 BEFORE INSERT OR UPDATE ON cd
846 IF :new.cdid IS NULL THEN
847 SELECT cd_seq.nextval
856 CREATE OR REPLACE TRIGGER track_insert_trg
857 BEFORE INSERT ON track
860 IF :new.trackid IS NULL THEN
861 SELECT track_seq.nextval
871 for my $dbh (map $_->storage->dbh, grep $_, ($schema, $schema2)) {
873 $dbh->do("DROP SEQUENCE artist_autoinc_seq");
874 $dbh->do("DROP SEQUENCE artist_pk_seq");
875 $dbh->do("DROP SEQUENCE cd_seq");
876 $dbh->do("DROP SEQUENCE track_seq");
877 $dbh->do("DROP SEQUENCE pkid1_seq");
878 $dbh->do("DROP SEQUENCE pkid2_seq");
879 $dbh->do("DROP SEQUENCE nonpkid_seq");
880 $dbh->do("DROP TABLE artist");
881 $dbh->do("DROP TABLE sequence_test");
882 $dbh->do("DROP TABLE track");
883 $dbh->do("DROP TABLE cd");
884 $dbh->do("DROP TABLE bindtype_test");