X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=blobdiff_plain;f=t%2F73oracle.t;h=c13dfaa0ac7733b390330525647f9543d97d6765;hb=1c4391f30e1dce6caf9f9037ff8b4e59fb23fb38;hp=0aa3ee7a920e0770757416d62ccbf346a6fd8301;hpb=b7b18f328d214290d4ae84dd94125d72db88db38;p=dbsrgits%2FDBIx-Class.git diff --git a/t/73oracle.t b/t/73oracle.t index 0aa3ee7..c13dfaa 100644 --- a/t/73oracle.t +++ b/t/73oracle.t @@ -30,8 +30,10 @@ use warnings; use Test::Exception; use Test::More; + use lib qw(t/lib); use DBICTest; +use DBIC::SqlMakerTest; my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/}; @@ -48,6 +50,7 @@ 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"); @@ -58,11 +61,12 @@ eval { }; $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 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))"); @@ -72,6 +76,7 @@ $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255 $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 @@ -87,6 +92,18 @@ $dbh->do(qq{ }); $dbh->do(qq{ CREATE OR REPLACE TRIGGER cd_insert_trg + BEFORE INSERT OR UPDATE 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 @@ -97,6 +114,18 @@ $dbh->do(qq{ 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. @@ -161,7 +190,7 @@ lives_and { # test join with row count ambiguity -my $track = $schema->resultset('Track')->create({ trackid => 1, cd => 1, +my $track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track1' }); my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, { join => 'cd', @@ -173,7 +202,7 @@ 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( {}, @@ -284,6 +313,410 @@ SKIP: { } } + +### 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', + rank => 1, + cds => [], + children => [ + { + name => 'child1', + rank => 2, + children => [ + { + name => 'grandchild', + rank => 3, + cds => [ + { + title => "grandchilds's cd" , + year => '2008', + tracks => [ + { + position => 1, + title => 'Track 1 grandchild', + } + ], + } + ], + children => [ + { + name => 'greatgrandchild', + rank => 3, + } + ], + } + ], + }, + { + name => 'child2', + rank => 3, + }, + ], + }); + + $schema->resultset('Artist')->create( + { + name => 'cycle-root', + children => [ + { + name => 'cycle-child1', + children => [ { name => 'cycle-grandchild' } ], + }, + { name => 'cycle-child2' }, + ], + } + ); + + $schema->resultset('Artist')->find({ name => 'cycle-root' }) + ->update({ parentid => \'artistid' }); + + # select the whole tree + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + )', + [ [ name => 'root'] ], + ); + is_deeply ( + [ $rs->get_column ('name')->all ], + [ qw/root child1 grandchild greatgrandchild child2/ ], + 'got artist tree', + ); + + + is_same_sql_bind ( + $rs->count_rs->as_query, + '( + SELECT COUNT( * ) + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + )', + [ [ name => 'root'] ], + ); + + is( $rs->count, 5, 'Connect By count ok' ); + } + + # use order siblings by statement + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + order_siblings_by => { -desc => 'name' }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + 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 + )', + [ [ name => 'root'] ], + ); + + is_deeply ( + [ $rs->get_column ('name')->all ], + [ qw/root child2 child1 grandchild greatgrandchild/ ], + 'Order Siblings By ok', + ); + } + + # get the root node + { + my $rs = $schema->resultset('Artist')->search({ parentid => undef }, { + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM artist me + WHERE ( parentid IS NULL ) + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + )', + [ [ name => 'root'] ], + ); + + is_deeply( + [ $rs->get_column('name')->all ], + [ '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 => { 'me.name' => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + } + ); + + is_same_sql_bind ( + $rs->as_query, + '( + 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 me.name = ? + CONNECT BY parentid = PRIOR artistid + )', + [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ], + ); + + is_deeply( + [ $rs->get_column('name')->all ], + [ 'grandchild' ], + 'Connect By with a join result name ok' + ); + + + is_same_sql_bind ( + $rs->count_rs->as_query, + '( + SELECT COUNT( * ) + FROM artist me + LEFT JOIN cd cds ON cds.artist = me.artistid + WHERE ( cds.title LIKE ? ) + START WITH me.name = ? + CONNECT BY parentid = PRIOR artistid + )', + [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ], + ); + + is( $rs->count, 1, 'Connect By with a join; count ok' ); + } + + # combine a connect by with order_by + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + order_by => { -asc => [ 'LEVEL', 'name' ] }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + ORDER BY LEVEL ASC, name ASC + )', + [ [ name => 'root' ] ], + ); + + is_deeply ( + [ $rs->get_column ('name')->all ], + [ qw/root child1 child2 grandchild greatgrandchild/ ], + 'Connect By with a order_by - result name ok' + ); + } + + + # limit a connect by + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + order_by => { -asc => 'name' }, + rows => 2, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT artistid, name, rank, charfield, parentid FROM ( + SELECT artistid, name, rank, charfield, parentid, ROWNUM rownum__index FROM ( + SELECT + me.artistid, + me.name, + me.rank, + me.charfield, + me.parentid + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + ORDER BY name ASC + ) me + ) me + WHERE rownum__index BETWEEN 1 AND 2 + )', + [ [ name => 'root' ] ], + ); + + is_deeply ( + [ $rs->get_column ('name')->all ], + [qw/child1 child2/], + 'LIMIT a Connect By query - correct names' + ); + + # TODO: + # prints "START WITH name = ? + # CONNECT BY artistid = PRIOR parentid " + # after count_subq, + # I will fix this later... + # + is_same_sql_bind ( + $rs->count_rs->as_query, + '( + SELECT COUNT( * ) FROM ( + SELECT artistid FROM ( + SELECT artistid, ROWNUM rownum__index FROM ( + SELECT + me.artistid + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + ) me + ) me + WHERE rownum__index BETWEEN 1 AND 2 + ) me + )', + [ [ name => 'root' ] ], + ); + + is( $rs->count, 2, 'Connect By; LIMIT count ok' ); + } + + # combine a connect_by with group_by and having + { + my $rs = $schema->resultset('Artist')->search({}, { + select => ['count(rank)'], + start_with => { name => 'root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + group_by => ['rank'], + having => { 'count(rank)' => { '<', 2 } }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT count(rank) + FROM artist me + START WITH name = ? + CONNECT BY parentid = PRIOR artistid + GROUP BY rank HAVING count(rank) < ? + )', + [ [ name => 'root' ], [ 'count(rank)' => 2 ] ], + ); + + is_deeply ( + [ $rs->get_column ('count(rank)')->all ], + [1, 1], + 'Group By a Connect By query - correct values' + ); + } + + + # select the whole cycle tree without nocylce + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'cycle-root' }, + connect_by => { parentid => { -prior => \ 'artistid' } }, + }); + eval { $rs->get_column ('name')->all }; + if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data + pass "connect by initify loop detection without nocycle"; + }else{ + fail "connect by initify loop detection without nocycle, not detected by oracle"; + } + } + + # select the whole cycle tree with nocylce + { + my $rs = $schema->resultset('Artist')->search({}, { + start_with => { name => 'cycle-root' }, + '+select' => [ \ 'CONNECT_BY_ISCYCLE' ], + connect_by_nocycle => { parentid => { -prior => \ 'artistid' } }, + }); + + is_same_sql_bind ( + $rs->as_query, + '( + SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE + FROM artist me + START WITH name = ? + CONNECT BY NOCYCLE parentid = PRIOR artistid + )', + [ [ name => 'cycle-root'] ], + ); + is_deeply ( + [ $rs->get_column ('name')->all ], + [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ], + 'got artist tree with nocycle (name)', + ); + is_deeply ( + [ $rs->get_column ('CONNECT_BY_ISCYCLE')->all ], + [ qw/1 0 0 0/ ], + 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)', + ); + + + is_same_sql_bind ( + $rs->count_rs->as_query, + '( + SELECT COUNT( * ) + FROM artist me + START WITH name = ? + CONNECT BY NOCYCLE parentid = PRIOR artistid + )', + [ [ name => 'cycle-root'] ], + ); + + is( $rs->count, 4, 'Connect By Nocycle count ok' ); + } +} + done_testing; # clean up our mess @@ -291,6 +724,7 @@ END { 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");