X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=blobdiff_plain;f=t%2F73oracle.t;h=99e12eb88c225adf947e7a65777112ce36548dc6;hb=184005983ab22b5cf557191542d8d18c114176aa;hp=ee00ed5829eb7e322bbdac3cf43c9712c5c5ffd3;hpb=c2481821ea4d4e988a3586a126a103aa676bec47;p=dbsrgits%2FDBIx-Class.git diff --git a/t/73oracle.t b/t/73oracle.t index ee00ed5..99e12eb 100644 --- a/t/73oracle.t +++ b/t/73oracle.t @@ -26,8 +26,9 @@ } use strict; -use warnings; +use warnings; +use Test::Exception; use Test::More; use lib qw(t/lib); use DBICTest; @@ -39,8 +40,6 @@ plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' as well as following sequences: \'pkid1_seq\', \'pkid2_seq\' and \'nonpkid_seq\'' unless ($dsn && $user && $pass); -plan tests => 24; - DBICTest::Schema->load_classes('ArtistFQN'); my $schema = DBICTest::Schema->connect($dsn, $user, $pass); @@ -48,25 +47,35 @@ my $dbh = $schema->storage->dbh; eval { $dbh->do("DROP SEQUENCE artist_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 cd"); $dbh->do("DROP TABLE track"); + $dbh->do("DROP TABLE cd"); }; $dbh->do("CREATE SEQUENCE artist_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"); $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), rank NUMBER(38), charfield VARCHAR2(10))"); -$dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))"); -$dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4))"); -$dbh->do("CREATE TABLE track (trackid NUMBER(12), cd NUMBER(12), position NUMBER(12), title VARCHAR(255), last_updated_on DATE)"); +$dbh->do("CREATE TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))"); $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))"); + +$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 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))"); + +$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(qq{ CREATE OR REPLACE TRIGGER artist_insert_trg BEFORE INSERT ON artist @@ -79,6 +88,59 @@ $dbh->do(qq{ END IF; END; }); +$dbh->do(qq{ + CREATE OR REPLACE TRIGGER cd_insert_trg + BEFORE INSERT ON cd + FOR EACH ROW + BEGIN + IF :new.cdid IS NULL THEN + SELECT cd_seq.nextval + INTO :new.cdid + FROM DUAL; + END IF; + END; +}); +$dbh->do(qq{ + CREATE OR REPLACE TRIGGER cd_insert_trg + BEFORE INSERT ON cd + FOR EACH ROW + BEGIN + IF :new.cdid IS NULL THEN + SELECT cd_seq.nextval + INTO :new.cdid + FROM DUAL; + END IF; + END; +}); +$dbh->do(qq{ + CREATE OR REPLACE TRIGGER track_insert_trg + BEFORE INSERT ON track + FOR EACH ROW + BEGIN + IF :new.trackid IS NULL THEN + SELECT track_seq.nextval + INTO :new.trackid + FROM DUAL; + END IF; + END; +}); + +{ + # Swiped from t/bindtype_columns.t to avoid creating my own Resultset. + + local $SIG{__WARN__} = sub {}; + eval { $dbh->do('DROP TABLE bindtype_test') }; + + $dbh->do(qq[ + CREATE TABLE bindtype_test + ( + id integer NOT NULL PRIMARY KEY, + bytea integer NULL, + blob blob NULL, + clob clob NULL + ) + ],{ RaiseError => 1, PrintError => 1 }); +} # This is in Core now, but it's here just to test that it doesn't break $schema->class('Artist')->load_components('PK::Auto'); @@ -90,31 +152,81 @@ $schema->class('Track')->load_components('PK::Auto::Oracle'); my $new = $schema->resultset('Artist')->create({ name => 'foo' }); is($new->artistid, 1, "Oracle Auto-PK worked"); +my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' }); +is($cd->cdid, 1, "Oracle Auto-PK worked - using scalar ref as table name"); + # test again with fully-qualified table name $new = $schema->resultset('ArtistFQN')->create( { name => 'bar' } ); is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" ); +# test rel names over the 30 char limit +my $query = $schema->resultset('Artist')->search({ + artistid => 1 +}, { + prefetch => 'cds_very_very_very_long_relationship_name' +}); + +lives_and { + 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 +# This requires walking the SQLA data structure. +{ + local $TODO = 'user condition on rel longer than 30 chars'; + + $query = $schema->resultset('Artist')->search({ + 'cds_very_very_very_long_relationship_name.title' => 'EP C' + }, { + prefetch => 'cds_very_very_very_long_relationship_name' + }); + + lives_and { + 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')->create({ cdid => 1, artist => 1, title => 'EP C', year => '2003' }); -my $track = $schema->resultset('Track')->create({ trackid => 1, cd => 1, position => 1, title => 'Track1' }); + +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 } ); -is($tjoin->next->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({ trackid => 2, cd => 1, 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 => [{count => {distinct => ['position', 'title']}}], - as => ['count'] - } - ); + {}, + { + select => [ qw/position title/ ], + distinct => 1, + } +); +is($tcount->count, 2, 'multiple column COUNT DISTINCT ok'); -is($tcount->next->get_column('count'), 2, "multiple column select 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'); # test LIMIT support for (1..6) { @@ -137,6 +249,27 @@ is( $it->next, undef, "next past end of resultset ok" ); is( scalar @results, 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' + }); + }); +} 'with_deferred_fk_checks code survived'; + +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'; + # test auto increment using sequences WITHOUT triggers for (1..5) { my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' }); @@ -147,17 +280,353 @@ for (1..5) { my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 }); is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually"); +SKIP: { + 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 $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'; + + skip 'buggy BLOB support in DBD::Oracle 1.23', 7; + } + + foreach my $type (qw( blob clob )) { + foreach my $size (qw( small large )) { + $id++; + + 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" ); + } + } +} + +# test hierarchical queries +if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) { + my $source = $schema->source('Artist'); + + $source->add_column( 'parentid' ); + + $source->add_relationship('children', 'DBICTest::Schema::Artist', + { 'foreign.parentid' => 'self.artistid' }, + { + accessor => 'multi', + join_type => 'LEFT', + cascade_delete => 1, + cascade_copy => 1, + } ); + $source->add_relationship('parent', 'DBICTest::Schema::Artist', + { 'foreign.artistid' => 'self.parentid' }, + { accessor => 'single' } ); + DBICTest::Schema::Artist->add_column( 'parentid' ); + DBICTest::Schema::Artist->has_many( + children => 'DBICTest::Schema::Artist', + { 'foreign.parentid' => 'self.artistid' } + ); + DBICTest::Schema::Artist->belongs_to( + parent => 'DBICTest::Schema::Artist', + { 'foreign.artistid' => 'self.parentid' } + ); + + $schema->resultset('Artist')->create ({ + name => 'root', + cds => [], + children => [ + { + name => 'child1', + children => [ + { + name => 'grandchild', + cds => [ + { + title => "grandchilds's cd" , + year => '2008', + tracks => [ + { + position => 1, + title => 'Track 1 grandchild', + } + ], + } + ], + children => [ + { + name => 'greatgrandchild', + } + ], + } + ], + }, + { + name => 'child2', + }, + ], + }); + + { + # select the whole tree + my $rs = $schema->resultset('Artist')->search({}, + { + 'start_with' => { 'name' => 'root' }, + 'connect_by' => { 'parentid' => { '-prior' => \'artistid' } }, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + START WITH + name = ? + CONNECT BY + parentid = prior artistid + + Parameters: 'root' +=cut + is( $rs->count, 5, 'Connect By count ok' ); + my $ok = 1; +=pod + SELECT + me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM + artist me + START WITH + name = ? + CONNECT BY + parentid = prior artistid + + Parameters: 'root' +=cut + foreach my $node_name (qw(root child1 grandchild greatgrandchild child2)) { + $ok = 0 if $rs->next->name ne $node_name; + } + ok( $ok, 'got artist tree'); + } + + { + # use order siblings by statement + my $rs = $schema->resultset('Artist')->search({}, + { + 'start_with' => { 'name' => 'root' }, + 'connect_by' => { 'parentid' => { '-prior' => \'artistid' } }, + 'order_siblings_by' => 'name DESC', + }); + my $ok = 1; +=pod + SELECT + me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM + artist me + START WITH + name = ? + CONNECT BY + parentid = PRIOR( artistid ) + ORDER SIBLINGS BY + name DESC + + Parameters: 'root' +=cut + foreach my $node_name (qw(root child2 child1 grandchild greatgrandchild)) { + $ok = 0 if $rs->next->name ne $node_name; + } + ok( $ok, 'Order Siblings By ok'); + } + + { + # get the root node + my $rs = $schema->resultset('Artist')->search({ parentid => undef }, + { + 'start_with' => { 'name' => 'greatgrandchild' }, + 'connect_by' => { 'artistid' => { '-prior' => \'parentid' } }, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + WHERE + ( parentid IS NULL ) + START WITH + name = ? + CONNECT BY + artistid = PRIOR( parentid ) + + Parameters: 'greatgrandchild' +=cut + is( $rs->count, 1, 'root node count ok' ); +=pod + SELECT + me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM + artist me + WHERE + ( parentid IS NULL ) + START WITH + name = ? + CONNECT BY + prior parentid = artistid + + Parameters: 'greatgrandchild' +=cut + ok( $rs->next->name eq 'root', 'found root node'); + } + + { + # combine a connect by with a join + my $rs = $schema->resultset('Artist')->search({'cds.title' => { 'like' => '%cd'}}, + { + 'join' => 'cds', + 'start_with' => { 'name' => 'root' }, + 'connect_by' => { 'parentid' => { '-prior' => \'artistid' } }, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + LEFT JOIN + cd cds ON cds.artist = me.artistid + WHERE + ( cds.title LIKE ? ) + START WITH + name = ? + CONNECT BY + parentid = prior artistid + + Parameters: '%cd', 'root' +=cut + is( $rs->count, 1, 'Connect By with a join; count ok' ); +=pod + SELECT + me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM + artist me + LEFT JOIN + cd cds ON cds.artist = me.artistid + WHERE + ( cds.title LIKE ? ) + START WITH + name = ? + CONNECT BY + parentid = prior artistid + + Parameters: '%cd', 'root' +=cut + ok( $rs->next->name eq 'grandchild', 'Connect By with a join; result name ok') + } + + { + # combine a connect by with order_by + my $rs = $schema->resultset('Artist')->search({}, + { + 'start_with' => { 'name' => 'greatgrandchild' }, + 'connect_by' => { artistid => { '-prior' => \'parentid' } }, + 'order_by' => 'name ASC', + }); + my $ok = 1; +=pod + SELECT + me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM + artist me + START WITH + name = ? + CONNECT BY + artistid = PRIOR( parentid ) + ORDER BY + name ASC + + Parameters: 'greatgrandchild' +=cut + foreach my $node_name (qw(child1 grandchild greatgrandchild root)) { + $ok = 0 if $rs->next->name ne $node_name; + } + ok( $ok, 'Connect By with a order_by; result name ok'); + } + + { + # limit a connect by + my $rs = $schema->resultset('Artist')->search({}, + { + 'start_with' => { 'name' => 'greatgrandchild' }, + 'connect_by' => { 'artistid' => { '-prior' => \'parentid' } }, + 'order_by' => 'name ASC', + 'rows' => 2, + 'page' => 1, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + START WITH + name = ? + CONNECT BY + artistid = PRIOR( parentid ) + + Parameters: 'greatgrandchild' +=cut + is( $rs->count(), 2, 'Connect By; LIMIT count ok' ); + my $ok = 1; +=pod + SELECT + * + FROM + ( + SELECT + A.*,ROWNUM r + FROM + ( + SELECT + me.artistid AS col1, me.name AS col2, me.rank AS col3, me.charfield AS col4, me.parentid AS col5 + FROM + artist me + START WITH + name = ? + CONNECT BY + prior parentid = artistid + ORDER BY + name ASC + ) A + WHERE + ROWNUM < 3 + ) B + WHERE + r >= 1 + Parameters: 'greatgrandchild' +=cut + foreach my $node_name (qw(child1 grandchild)) { + $ok = 0 if $rs->next->name ne $node_name; + } + ok( $ok, 'LIMIT a Connect By query ok'); + } +} + +done_testing; + # clean up our mess END { - if($dbh = $schema->storage->dbh) { + if($schema && ($dbh = $schema->storage->dbh)) { $dbh->do("DROP SEQUENCE artist_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 cd"); $dbh->do("DROP TABLE track"); + $dbh->do("DROP TABLE cd"); + $dbh->do("DROP TABLE bindtype_test"); } }