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 __PACKAGE__->set_primary_key('artistid');
36 my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
38 plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' .
39 'Warning: This test drops and creates tables called \'artist\', \'cd\', \'track\' and \'sequence_test\''.
40 ' as well as following sequences: \'pkid1_seq\', \'pkid2_seq\' and \'nonpkid_seq\''
41 unless ($dsn && $user && $pass);
45 DBICTest::Schema->load_classes('ArtistFQN');
46 my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
48 my $dbh = $schema->storage->dbh;
51 $dbh->do("DROP SEQUENCE artist_seq");
52 $dbh->do("DROP SEQUENCE cd_seq");
53 $dbh->do("DROP SEQUENCE pkid1_seq");
54 $dbh->do("DROP SEQUENCE pkid2_seq");
55 $dbh->do("DROP SEQUENCE nonpkid_seq");
56 $dbh->do("DROP TABLE artist");
57 $dbh->do("DROP TABLE sequence_test");
58 $dbh->do("DROP TABLE cd");
59 $dbh->do("DROP TABLE track");
61 $dbh->do("CREATE SEQUENCE artist_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
62 $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
63 $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
64 $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0");
65 $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0");
66 $dbh->do("CREATE TABLE artist (artistid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))");
67 $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
68 $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4))");
69 $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)");
71 $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
72 $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
73 $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
75 CREATE OR REPLACE TRIGGER artist_insert_trg
76 BEFORE INSERT ON artist
79 IF :new.artistid IS NULL THEN
80 SELECT artist_seq.nextval
87 CREATE OR REPLACE TRIGGER cd_insert_trg
91 IF :new.cdid IS NULL THEN
100 # Swiped from t/bindtype_columns.t to avoid creating my own Resultset.
102 local $SIG{__WARN__} = sub {};
103 eval { $dbh->do('DROP TABLE bindtype_test') };
106 CREATE TABLE bindtype_test
108 id integer NOT NULL PRIMARY KEY,
113 ],{ RaiseError => 1, PrintError => 1 });
116 # This is in Core now, but it's here just to test that it doesn't break
117 $schema->class('Artist')->load_components('PK::Auto');
118 # These are compat shims for PK::Auto...
119 $schema->class('CD')->load_components('PK::Auto::Oracle');
120 $schema->class('Track')->load_components('PK::Auto::Oracle');
122 # test primary key handling
123 my $new = $schema->resultset('Artist')->create({ name => 'foo' });
124 is($new->artistid, 1, "Oracle Auto-PK worked");
126 my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
127 is($new->artistid, 1, "Oracle Auto-PK worked - using scalar ref as table name");
129 # test again with fully-qualified table name
130 $new = $schema->resultset('ArtistFQN')->create( { name => 'bar' } );
131 is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
133 # test join with row count ambiguity
135 my $track = $schema->resultset('Track')->create({ trackid => 1, cd => 1,
136 position => 1, title => 'Track1' });
137 my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
142 ok(my $row = $tjoin->next);
144 is($row->title, 'Track1', "ambiguous column ok");
146 # check count distinct with multiple columns
147 my $other_track = $schema->resultset('Track')->create({ trackid => 2, cd => 1, position => 1, title => 'Track2' });
149 my $tcount = $schema->resultset('Track')->search(
152 select => [ qw/position title/ ],
156 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
158 $tcount = $schema->resultset('Track')->search(
161 columns => [ qw/position title/ ],
165 is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
167 $tcount = $schema->resultset('Track')->search(
170 group_by => [ qw/position title/ ]
173 is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
177 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
179 my $it = $schema->resultset('Artist')->search( {},
182 order_by => 'artistid' }
184 is( $it->count, 3, "LIMIT count ok" );
185 is( $it->next->name, "Artist 2", "iterator->next ok" );
188 is( $it->next, undef, "next past end of resultset ok" );
191 my $rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset=>1 });
192 my @results = $rs->all;
193 is( scalar @results, 1, "Group by with limit OK" );
196 # test auto increment using sequences WITHOUT triggers
198 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
199 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
200 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
201 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
203 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
204 is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
207 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
208 $binstr{'large'} = $binstr{'small'} x 1024;
210 my $maxloblen = length $binstr{'large'};
211 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
212 local $dbh->{'LongReadLen'} = $maxloblen;
214 my $rs = $schema->resultset('BindType');
217 foreach my $type (qw( blob clob )) {
218 foreach my $size (qw( small large )) {
221 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
222 "inserted $size $type without dying";
223 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
230 if($schema && ($dbh = $schema->storage->dbh)) {
231 $dbh->do("DROP SEQUENCE artist_seq");
232 $dbh->do("DROP SEQUENCE cd_seq");
233 $dbh->do("DROP SEQUENCE pkid1_seq");
234 $dbh->do("DROP SEQUENCE pkid2_seq");
235 $dbh->do("DROP SEQUENCE nonpkid_seq");
236 $dbh->do("DROP TABLE artist");
237 $dbh->do("DROP TABLE sequence_test");
238 $dbh->do("DROP TABLE cd");
239 $dbh->do("DROP TABLE track");
240 $dbh->do("DROP TABLE bindtype_test");