failing test
[dbsrgits/DBIx-Class.git] / t / 73oracle.t
CommitLineData
cb464582 1{
2 package # hide from PAUSE
3 DBICTest::Schema::ArtistFQN;
4
5 use base 'DBIx::Class::Core';
6
7 __PACKAGE__->table(
8 defined $ENV{DBICTEST_ORA_USER}
9 ? $ENV{DBICTEST_ORA_USER} . '.artist'
10 : 'artist'
11 );
12 __PACKAGE__->add_columns(
13 'artistid' => {
14 data_type => 'integer',
15 is_auto_increment => 1,
16 },
17 'name' => {
18 data_type => 'varchar',
19 size => 100,
20 is_nullable => 1,
21 },
22 );
23 __PACKAGE__->set_primary_key('artistid');
24
25 1;
26}
27
70350518 28use strict;
e6dd7b42 29use warnings;
70350518 30
5db2758d 31use Test::Exception;
70350518 32use Test::More;
33use lib qw(t/lib);
34use DBICTest;
0567538f 35
36my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
37
70350518 38plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' .
39b8d119 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\''
0567538f 41 unless ($dsn && $user && $pass);
42
e6dd7b42 43plan tests => 36;
0567538f 44
cb464582 45DBICTest::Schema->load_classes('ArtistFQN');
9900b569 46my $schema = DBICTest::Schema->connect($dsn, $user, $pass);
0567538f 47
3ff5b740 48my $dbh = $schema->storage->dbh;
0567538f 49
50eval {
51 $dbh->do("DROP SEQUENCE artist_seq");
e6dd7b42 52 $dbh->do("DROP SEQUENCE cd_seq");
39b8d119 53 $dbh->do("DROP SEQUENCE pkid1_seq");
54 $dbh->do("DROP SEQUENCE pkid2_seq");
55 $dbh->do("DROP SEQUENCE nonpkid_seq");
0567538f 56 $dbh->do("DROP TABLE artist");
39b8d119 57 $dbh->do("DROP TABLE sequence_test");
2660b14e 58 $dbh->do("DROP TABLE cd");
59 $dbh->do("DROP TABLE track");
0567538f 60};
61$dbh->do("CREATE SEQUENCE artist_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
e6dd7b42 62$dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0");
39b8d119 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");
7c4ead2d 66$dbh->do("CREATE TABLE artist (artistid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))");
39b8d119 67$dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))");
2660b14e 68$dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4))");
2d124f01 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)");
2660b14e 70
0567538f 71$dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");
e6dd7b42 72$dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");
39b8d119 73$dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))");
0567538f 74$dbh->do(qq{
75 CREATE OR REPLACE TRIGGER artist_insert_trg
76 BEFORE INSERT ON artist
77 FOR EACH ROW
78 BEGIN
79 IF :new.artistid IS NULL THEN
80 SELECT artist_seq.nextval
81 INTO :new.artistid
82 FROM DUAL;
83 END IF;
84 END;
85});
e6dd7b42 86$dbh->do(qq{
87 CREATE OR REPLACE TRIGGER cd_insert_trg
88 BEFORE INSERT ON cd
89 FOR EACH ROW
90 BEGIN
91 IF :new.cdid IS NULL THEN
92 SELECT cd_seq.nextval
93 INTO :new.cdid
94 FROM DUAL;
95 END IF;
96 END;
97});
0567538f 98
5db2758d 99{
100 # Swiped from t/bindtype_columns.t to avoid creating my own Resultset.
101
102 local $SIG{__WARN__} = sub {};
103 eval { $dbh->do('DROP TABLE bindtype_test') };
104
105 $dbh->do(qq[
e6dd7b42 106 CREATE TABLE bindtype_test
5db2758d 107 (
108 id integer NOT NULL PRIMARY KEY,
109 bytea integer NULL,
110 blob blob NULL,
111 clob clob NULL
112 )
113 ],{ RaiseError => 1, PrintError => 1 });
114}
115
3ff5b740 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');
0567538f 121
122# test primary key handling
3ff5b740 123my $new = $schema->resultset('Artist')->create({ name => 'foo' });
c8f4b52b 124is($new->artistid, 1, "Oracle Auto-PK worked");
0567538f 125
e6dd7b42 126my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
62d4dbae 127is($cd->cdid, 1, "Oracle Auto-PK worked - using scalar ref as table name");
e6dd7b42 128
cb464582 129# test again with fully-qualified table name
130$new = $schema->resultset('ArtistFQN')->create( { name => 'bar' } );
131is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
132
62d4dbae 133# test rel names over the 30 char limit
134my $query = $schema->resultset('Artist')->search({
135 'cds_very_very_very_long_relationship_name.title' => 'EP C'
136}, {
137 prefetch => 'cds_very_very_very_long_relationship_name'
138});
139
140lives_and {
141 is $query->first->cds_very_very_very_long_relationship_name->cdid, 1
142} 'query with rel name over 30 chars survived and worked';
143
9900b569 144# test join with row count ambiguity
d2a3958e 145
d2a3958e 146my $track = $schema->resultset('Track')->create({ trackid => 1, cd => 1,
9900b569 147 position => 1, title => 'Track1' });
3ff5b740 148my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
2660b14e 149 { join => 'cd',
150 rows => 2 }
151);
152
d2a3958e 153ok(my $row = $tjoin->next);
154
155is($row->title, 'Track1', "ambiguous column ok");
2660b14e 156
286f32b3 157# check count distinct with multiple columns
3ff5b740 158my $other_track = $schema->resultset('Track')->create({ trackid => 2, cd => 1, position => 1, title => 'Track2' });
11d68671 159
3ff5b740 160my $tcount = $schema->resultset('Track')->search(
11d68671 161 {},
162 {
163 select => [ qw/position title/ ],
164 distinct => 1,
165 }
166);
f12f0d97 167is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
11d68671 168
169$tcount = $schema->resultset('Track')->search(
170 {},
171 {
172 columns => [ qw/position title/ ],
173 distinct => 1,
174 }
175);
f12f0d97 176is($tcount->count, 2, 'multiple column COUNT DISTINCT ok');
286f32b3 177
11d68671 178$tcount = $schema->resultset('Track')->search(
179 {},
e6dd7b42 180 {
11d68671 181 group_by => [ qw/position title/ ]
182 }
183);
f12f0d97 184is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
2660b14e 185
0567538f 186# test LIMIT support
187for (1..6) {
3ff5b740 188 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
0567538f 189}
3ff5b740 190my $it = $schema->resultset('Artist')->search( {},
0567538f 191 { rows => 3,
cb464582 192 offset => 3,
0567538f 193 order_by => 'artistid' }
194);
195is( $it->count, 3, "LIMIT count ok" );
196is( $it->next->name, "Artist 2", "iterator->next ok" );
197$it->next;
198$it->next;
199is( $it->next, undef, "next past end of resultset ok" );
200
e8e971f2 201{
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" );
205}
206
ccd6f984 207# test auto increment using sequences WITHOUT triggers
39b8d119 208for (1..5) {
209 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
210 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
211 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
212 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
213}
214my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
215is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
ccd6f984 216
8068691e 217SKIP: {
218 skip 'buggy BLOB support in DBD::Oracle 1.23', 8
219 if $DBD::Oracle::VERSION == 1.23;
220
5db2758d 221 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
222 $binstr{'large'} = $binstr{'small'} x 1024;
223
224 my $maxloblen = length $binstr{'large'};
225 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
226 local $dbh->{'LongReadLen'} = $maxloblen;
227
228 my $rs = $schema->resultset('BindType');
229 my $id = 0;
230
231 foreach my $type (qw( blob clob )) {
232 foreach my $size (qw( small large )) {
233 $id++;
234
0821ae59 235 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
5db2758d 236 "inserted $size $type without dying";
0821ae59 237 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
5db2758d 238 }
239 }
240}
241
0567538f 242# clean up our mess
3ff5b740 243END {
fe0d48d3 244 if($schema && ($dbh = $schema->storage->dbh)) {
3ff5b740 245 $dbh->do("DROP SEQUENCE artist_seq");
e6dd7b42 246 $dbh->do("DROP SEQUENCE cd_seq");
39b8d119 247 $dbh->do("DROP SEQUENCE pkid1_seq");
248 $dbh->do("DROP SEQUENCE pkid2_seq");
249 $dbh->do("DROP SEQUENCE nonpkid_seq");
3ff5b740 250 $dbh->do("DROP TABLE artist");
39b8d119 251 $dbh->do("DROP TABLE sequence_test");
3ff5b740 252 $dbh->do("DROP TABLE cd");
253 $dbh->do("DROP TABLE track");
5db2758d 254 $dbh->do("DROP TABLE bindtype_test");
3ff5b740 255 }
256}
0567538f 257