From: Peter Rabbitson Date: Thu, 19 Nov 2009 10:10:18 +0000 (+0000) Subject: Patch by kalex X-Git-Tag: v0.08122~34^2~43 X-Git-Url: http://git.shadowcat.co.uk/gitweb/gitweb.cgi?a=commitdiff_plain;h=c00243555c65c5df61de5578f3a19afb939dd212;p=dbsrgits%2FDBIx-Class.git Patch by kalex --- diff --git a/lib/DBIx/Class/SQLAHacks/Oracle.pm b/lib/DBIx/Class/SQLAHacks/Oracle.pm new file mode 100644 index 0000000..3af05ce --- /dev/null +++ b/lib/DBIx/Class/SQLAHacks/Oracle.pm @@ -0,0 +1,82 @@ +package # Hide from PAUSE + DBIx::Class::SQLAHacks::Oracle; + +use base qw( DBIx::Class::SQLAHacks ); +use Carp::Clan qw/^DBIx::Class|^SQL::Abstract/; + +sub select { + my ($self, $table, $fields, $where, $order, @rest) = @_; + + $self->{_db_specific_attrs} = pop @rest; + + my ($sql, @bind) = $self->SUPER::select($table, $fields, $where, $order, @rest); + push @bind, @{$self->{_oracle_connect_by_binds}}; + + return wantarray ? ($sql, @bind) : $sql; +} + +sub _emulate_limit { + my ( $self, $syntax, $sql, $order, $rows, $offset ) = @_; + + my ($cb_sql, @cb_bind) = $self->_connect_by(); + $sql .= $cb_sql; + $self->{_oracle_connect_by_binds} = \@cb_bind; + + return $self->SUPER::_emulate_limit($syntax, $sql, $order, $rows, $offset); +} + +sub _connect_by { + my ($self) = @_; + my $attrs = $self->{_db_specific_attrs}; + my $sql = ''; + my @bind; + + if ( ref($attrs) eq 'HASH' ) { + if ( $attrs->{'start_with'} ) { + my ($ws, @wb) = $self->_recurse_where( $attrs->{'start_with'} ); + $sql .= $self->_sqlcase(' start with ') . $ws; + push @bind, @wb; + } + if ( my $connect_by = $attrs->{'connect_by'}) { + $sql .= $self->_sqlcase(' connect by'); + foreach my $key ( keys %$connect_by ) { + $sql .= " $key = " . $connect_by->{$key}; + } + } + if ( $attrs->{'order_siblings_by'} ) { + $sql .= $self->_order_siblings_by( $attrs->{'order_siblings_by'} ); + } + } + + return wantarray ? ($sql, @bind) : $sql; +} + +sub _order_siblings_by { + my $self = shift; + my $ref = ref $_[0]; + + my @vals = $ref eq 'ARRAY' ? @{$_[0]} : + $ref eq 'SCALAR' ? ${$_[0]} : + $ref eq '' ? $_[0] : + puke( "Unsupported data struct $ref for ORDER SIBILINGS BY" ); + + my $val = join ', ', map { $self->_quote($_) } @vals; + return $val ? $self->_sqlcase(' order siblings by')." $val" : ''; +} + +1; + +__END__ + +=pod + +=head1 NAME + +DBIx::Class::SQLAHacks::Oracle - adds hierarchical query support for Oracle to SQL::Abstract + +=head1 DESCRIPTION + +See L for more informations about +how to use hierarchical queries with DBIx::Class. + +=cut diff --git a/lib/DBIx/Class/Storage/DBI/Oracle/Generic.pm b/lib/DBIx/Class/Storage/DBI/Oracle/Generic.pm index b1f3ddf..57540cb 100644 --- a/lib/DBIx/Class/Storage/DBI/Oracle/Generic.pm +++ b/lib/DBIx/Class/Storage/DBI/Oracle/Generic.pm @@ -15,9 +15,55 @@ DBIx::Class::Storage::DBI::Oracle::Generic - Oracle Support for DBIx::Class __PACKAGE__->set_primary_key('id'); __PACKAGE__->sequence('mysequence'); + # Somewhere in your Code + # add some data to a table with a hierarchical relationship + $schema->resultset('Person')->create ({ + firstname => 'foo', + lastname => 'bar', + children => [ + { + firstname => 'child1', + lastname => 'bar', + children => [ + { + firstname => 'grandchild', + lastname => 'bar', + } + ], + }, + { + firstname => 'child2', + lastname => 'bar', + }, + ], + }); + + # select from the hierarchical relationship + my $rs = $schema->resultset('Person')->search({}, + { + 'start_with' => { 'firstname' => 'foo', 'lastname' => 'bar' }, + 'connect_by' => { 'parentid' => 'prior persionid'}, + 'order_siblings_by' => 'firstname ASC', + }; + ); + + # this will select the whole tree starting from person "foo bar", creating + # following query: + # SELECT + # me.persionid me.firstname, me.lastname, me.parentid + # FROM + # person me + # START WITH + # firstname = 'foo' and lastname = 'bar' + # CONNECT BY + # parentid = prior persionid + # ORDER SIBLINGS BY + # firstname ASC + =head1 DESCRIPTION -This class implements autoincrements for Oracle. +This class implements autoincrements for Oracle and adds support for Oracle +specific hierarchical queries. =head1 METHODS @@ -26,6 +72,8 @@ This class implements autoincrements for Oracle. use base qw/DBIx::Class::Storage::DBI/; use mro 'c3'; +__PACKAGE__->sql_maker_class('DBIx::Class::SQLAHacks::Oracle'); + sub _dbh_last_insert_id { my ($self, $dbh, $source, @columns) = @_; my @ids = (); @@ -274,6 +322,94 @@ sub _svp_rollback { $self->_get_dbh->do("ROLLBACK TO SAVEPOINT $name") } +sub _select_args { + my ($self, $ident, $select, $where, $attrs) = @_; + + my $connect_by_args = {}; + if ( $attrs->{connect_by} || $attrs->{start_with} || $attrs->{order_siblings_by} ) { + $connect_by_args = { + connect_by => $attrs->{connect_by}, + start_with => $attrs->{start_with}, + order_siblings_by => $attrs->{order_siblings_by}, + } + } + + my @rv = $self->next::method($ident, $select, $where, $attrs); + + return (@rv, $connect_by_args); +} + +=head1 ATTRIBUTES + +Following additional attributes can be used in resultsets. + +=head2 connect_by + +=over 4 + +=item Value: \%connect_by + +=back + +A hashref of conditions used to specify the relationship between parent rows +and child rows of the hierarchy. + + connect_by => { parentid => 'prior personid' } + + # adds a connect by statement to the query: + # SELECT + # me.persionid me.firstname, me.lastname, me.parentid + # FROM + # person me + # CONNECT BY + # parentid = prior persionid + +=head2 start_with + +=over 4 + +=item Value: \%condition + +=back + +A hashref of conditions which specify the root row(s) of the hierarchy. + +It uses the same syntax as L + + start_with => { firstname => 'Foo', lastname => 'Bar' } + + # SELECT + # me.persionid me.firstname, me.lastname, me.parentid + # FROM + # person me + # START WITH + # firstname = 'foo' and lastname = 'bar' + # CONNECT BY + # parentid = prior persionid + +=head2 order_siblings_by + +=over 4 + +=item Value: ($order_siblings_by | \@order_siblings_by) + +=back + +Which column(s) to order the siblings by. + +It uses the same syntax as L + + 'order_siblings_by' => 'firstname ASC' + + # SELECT + # me.persionid me.firstname, me.lastname, me.parentid + # FROM + # person me + # CONNECT BY + # parentid = prior persionid + # ORDER SIBLINGS BY + # firstname ASC + =head1 AUTHOR See L. diff --git a/t/73oracle.t b/t/73oracle.t index bb5a86e..90698ea 100644 --- a/t/73oracle.t +++ b/t/73oracle.t @@ -40,16 +40,23 @@ 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 => 36; - DBICTest::Schema->load_classes('ArtistFQN'); my $schema = DBICTest::Schema->connect($dsn, $user, $pass); my $dbh = $schema->storage->dbh; +if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) { + plan tests => 46; +} +else { + plan tests => 36; +} + + 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"); @@ -60,16 +67,18 @@ 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("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 cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), single_track NUMBER(12), genreid NUMBER(12))"); $dbh->do("CREATE TABLE track (trackid NUMBER(12), cd NUMBER(12), position NUMBER(12), title VARCHAR(255), last_updated_on DATE, last_updated_at DATE, small_dt DATE)"); $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))"); $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))"); +$dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))"); $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))"); $dbh->do(qq{ CREATE OR REPLACE TRIGGER artist_insert_trg @@ -95,6 +104,30 @@ $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 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. @@ -132,7 +165,7 @@ is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" ); # 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', @@ -144,7 +177,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( {}, @@ -228,11 +261,312 @@ SKIP: { } } +# test hierarchical querys +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' => { 'prior parentid' => 'artistid'}, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + WHERE + ( parentid IS NULL ) + START WITH + name = ? + CONNECT BY + prior parentid = artistid + + 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' => { 'prior parentid' => 'artistid'}, + '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 + prior parentid = artistid + 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' => { 'prior parentid' => 'artistid'}, + 'order_by' => 'name ASC', + 'rows' => 2, + 'page' => 1, + }); +=pod + SELECT + COUNT( * ) + FROM + artist me + START WITH + name = ? + CONNECT BY + prior parentid = artistid + + 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'); + } +} + # clean up our mess 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");