Commit | Line | Data |
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 |
28 | use strict; |
e6dd7b42 |
29 | use warnings; |
70350518 |
30 | |
5db2758d |
31 | use Test::Exception; |
70350518 |
32 | use Test::More; |
ab6e0924 |
33 | |
70350518 |
34 | use lib qw(t/lib); |
35 | use DBICTest; |
8ce8340f |
36 | use DBIC::SqlMakerTest; |
0567538f |
37 | |
38 | my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/}; |
39 | |
70350518 |
40 | plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test. ' . |
39b8d119 |
41 | 'Warning: This test drops and creates tables called \'artist\', \'cd\', \'track\' and \'sequence_test\''. |
42 | ' as well as following sequences: \'pkid1_seq\', \'pkid2_seq\' and \'nonpkid_seq\'' |
0567538f |
43 | unless ($dsn && $user && $pass); |
44 | |
cb464582 |
45 | DBICTest::Schema->load_classes('ArtistFQN'); |
9900b569 |
46 | my $schema = DBICTest::Schema->connect($dsn, $user, $pass); |
0567538f |
47 | |
3ff5b740 |
48 | my $dbh = $schema->storage->dbh; |
0567538f |
49 | |
50 | eval { |
51 | $dbh->do("DROP SEQUENCE artist_seq"); |
e6dd7b42 |
52 | $dbh->do("DROP SEQUENCE cd_seq"); |
c0024355 |
53 | $dbh->do("DROP SEQUENCE track_seq"); |
39b8d119 |
54 | $dbh->do("DROP SEQUENCE pkid1_seq"); |
55 | $dbh->do("DROP SEQUENCE pkid2_seq"); |
56 | $dbh->do("DROP SEQUENCE nonpkid_seq"); |
0567538f |
57 | $dbh->do("DROP TABLE artist"); |
39b8d119 |
58 | $dbh->do("DROP TABLE sequence_test"); |
2660b14e |
59 | $dbh->do("DROP TABLE track"); |
b7b18f32 |
60 | $dbh->do("DROP TABLE cd"); |
0567538f |
61 | }; |
62 | $dbh->do("CREATE SEQUENCE artist_seq START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
e6dd7b42 |
63 | $dbh->do("CREATE SEQUENCE cd_seq START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
c0024355 |
64 | $dbh->do("CREATE SEQUENCE track_seq START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
39b8d119 |
65 | $dbh->do("CREATE SEQUENCE pkid1_seq START WITH 1 MAXVALUE 999999 MINVALUE 0"); |
66 | $dbh->do("CREATE SEQUENCE pkid2_seq START WITH 10 MAXVALUE 999999 MINVALUE 0"); |
67 | $dbh->do("CREATE SEQUENCE nonpkid_seq START WITH 20 MAXVALUE 999999 MINVALUE 0"); |
b7b18f32 |
68 | |
c0024355 |
69 | $dbh->do("CREATE TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), rank NUMBER(38), charfield VARCHAR2(10))"); |
b7b18f32 |
70 | $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))"); |
71 | |
39b8d119 |
72 | $dbh->do("CREATE TABLE sequence_test (pkid1 NUMBER(12), pkid2 NUMBER(12), nonpkid NUMBER(12), name VARCHAR(255))"); |
b7b18f32 |
73 | $dbh->do("ALTER TABLE sequence_test ADD (CONSTRAINT sequence_test_constraint PRIMARY KEY (pkid1, pkid2))"); |
2660b14e |
74 | |
b7b18f32 |
75 | $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))"); |
e6dd7b42 |
76 | $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))"); |
b7b18f32 |
77 | |
78 | $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)"); |
c0024355 |
79 | $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))"); |
b7b18f32 |
80 | |
0567538f |
81 | $dbh->do(qq{ |
82 | CREATE OR REPLACE TRIGGER artist_insert_trg |
83 | BEFORE INSERT ON artist |
84 | FOR EACH ROW |
85 | BEGIN |
86 | IF :new.artistid IS NULL THEN |
87 | SELECT artist_seq.nextval |
88 | INTO :new.artistid |
89 | FROM DUAL; |
90 | END IF; |
91 | END; |
92 | }); |
e6dd7b42 |
93 | $dbh->do(qq{ |
94 | CREATE OR REPLACE TRIGGER cd_insert_trg |
cc42fa9a |
95 | BEFORE INSERT OR UPDATE ON cd |
e6dd7b42 |
96 | FOR EACH ROW |
97 | BEGIN |
98 | IF :new.cdid IS NULL THEN |
99 | SELECT cd_seq.nextval |
100 | INTO :new.cdid |
101 | FROM DUAL; |
102 | END IF; |
103 | END; |
104 | }); |
c0024355 |
105 | $dbh->do(qq{ |
106 | CREATE OR REPLACE TRIGGER cd_insert_trg |
107 | BEFORE INSERT ON cd |
108 | FOR EACH ROW |
109 | BEGIN |
110 | IF :new.cdid IS NULL THEN |
111 | SELECT cd_seq.nextval |
112 | INTO :new.cdid |
113 | FROM DUAL; |
114 | END IF; |
115 | END; |
116 | }); |
117 | $dbh->do(qq{ |
118 | CREATE OR REPLACE TRIGGER track_insert_trg |
119 | BEFORE INSERT ON track |
120 | FOR EACH ROW |
121 | BEGIN |
122 | IF :new.trackid IS NULL THEN |
123 | SELECT track_seq.nextval |
124 | INTO :new.trackid |
125 | FROM DUAL; |
126 | END IF; |
127 | END; |
128 | }); |
0567538f |
129 | |
5db2758d |
130 | { |
131 | # Swiped from t/bindtype_columns.t to avoid creating my own Resultset. |
132 | |
133 | local $SIG{__WARN__} = sub {}; |
134 | eval { $dbh->do('DROP TABLE bindtype_test') }; |
135 | |
136 | $dbh->do(qq[ |
e6dd7b42 |
137 | CREATE TABLE bindtype_test |
5db2758d |
138 | ( |
139 | id integer NOT NULL PRIMARY KEY, |
140 | bytea integer NULL, |
141 | blob blob NULL, |
142 | clob clob NULL |
143 | ) |
144 | ],{ RaiseError => 1, PrintError => 1 }); |
145 | } |
146 | |
3ff5b740 |
147 | # This is in Core now, but it's here just to test that it doesn't break |
148 | $schema->class('Artist')->load_components('PK::Auto'); |
149 | # These are compat shims for PK::Auto... |
150 | $schema->class('CD')->load_components('PK::Auto::Oracle'); |
151 | $schema->class('Track')->load_components('PK::Auto::Oracle'); |
0567538f |
152 | |
153 | # test primary key handling |
3ff5b740 |
154 | my $new = $schema->resultset('Artist')->create({ name => 'foo' }); |
c8f4b52b |
155 | is($new->artistid, 1, "Oracle Auto-PK worked"); |
0567538f |
156 | |
e6dd7b42 |
157 | my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' }); |
62d4dbae |
158 | is($cd->cdid, 1, "Oracle Auto-PK worked - using scalar ref as table name"); |
e6dd7b42 |
159 | |
cb464582 |
160 | # test again with fully-qualified table name |
161 | $new = $schema->resultset('ArtistFQN')->create( { name => 'bar' } ); |
162 | is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" ); |
163 | |
62d4dbae |
164 | # test rel names over the 30 char limit |
165 | my $query = $schema->resultset('Artist')->search({ |
6c0230de |
166 | artistid => 1 |
62d4dbae |
167 | }, { |
168 | prefetch => 'cds_very_very_very_long_relationship_name' |
169 | }); |
170 | |
171 | lives_and { |
6c0230de |
172 | is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1 |
62d4dbae |
173 | } 'query with rel name over 30 chars survived and worked'; |
174 | |
6c0230de |
175 | # rel name over 30 char limit with user condition |
176 | # This requires walking the SQLA data structure. |
177 | { |
178 | local $TODO = 'user condition on rel longer than 30 chars'; |
179 | |
180 | $query = $schema->resultset('Artist')->search({ |
181 | 'cds_very_very_very_long_relationship_name.title' => 'EP C' |
182 | }, { |
183 | prefetch => 'cds_very_very_very_long_relationship_name' |
184 | }); |
185 | |
186 | lives_and { |
187 | is $query->first->cds_very_very_very_long_relationship_name->first->cdid, 1 |
188 | } 'query with rel name over 30 chars and user condition survived and worked'; |
189 | } |
190 | |
9900b569 |
191 | # test join with row count ambiguity |
d2a3958e |
192 | |
c0024355 |
193 | my $track = $schema->resultset('Track')->create({ cd => $cd->cdid, |
9900b569 |
194 | position => 1, title => 'Track1' }); |
3ff5b740 |
195 | my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'}, |
2660b14e |
196 | { join => 'cd', |
197 | rows => 2 } |
198 | ); |
199 | |
d2a3958e |
200 | ok(my $row = $tjoin->next); |
201 | |
202 | is($row->title, 'Track1', "ambiguous column ok"); |
2660b14e |
203 | |
286f32b3 |
204 | # check count distinct with multiple columns |
c0024355 |
205 | my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' }); |
11d68671 |
206 | |
3ff5b740 |
207 | my $tcount = $schema->resultset('Track')->search( |
11d68671 |
208 | {}, |
209 | { |
210 | select => [ qw/position title/ ], |
211 | distinct => 1, |
212 | } |
213 | ); |
f12f0d97 |
214 | is($tcount->count, 2, 'multiple column COUNT DISTINCT ok'); |
11d68671 |
215 | |
216 | $tcount = $schema->resultset('Track')->search( |
217 | {}, |
218 | { |
219 | columns => [ qw/position title/ ], |
220 | distinct => 1, |
221 | } |
222 | ); |
f12f0d97 |
223 | is($tcount->count, 2, 'multiple column COUNT DISTINCT ok'); |
286f32b3 |
224 | |
11d68671 |
225 | $tcount = $schema->resultset('Track')->search( |
226 | {}, |
e6dd7b42 |
227 | { |
11d68671 |
228 | group_by => [ qw/position title/ ] |
229 | } |
230 | ); |
f12f0d97 |
231 | is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok'); |
2660b14e |
232 | |
0567538f |
233 | # test LIMIT support |
234 | for (1..6) { |
3ff5b740 |
235 | $schema->resultset('Artist')->create({ name => 'Artist ' . $_ }); |
0567538f |
236 | } |
3ff5b740 |
237 | my $it = $schema->resultset('Artist')->search( {}, |
0567538f |
238 | { rows => 3, |
cb464582 |
239 | offset => 3, |
0567538f |
240 | order_by => 'artistid' } |
241 | ); |
242 | is( $it->count, 3, "LIMIT count ok" ); |
243 | is( $it->next->name, "Artist 2", "iterator->next ok" ); |
244 | $it->next; |
245 | $it->next; |
246 | is( $it->next, undef, "next past end of resultset ok" ); |
247 | |
e8e971f2 |
248 | { |
249 | my $rs = $schema->resultset('Track')->search( undef, { columns=>[qw/trackid position/], group_by=> [ qw/trackid position/ ] , rows => 2, offset=>1 }); |
250 | my @results = $rs->all; |
251 | is( scalar @results, 1, "Group by with limit OK" ); |
252 | } |
253 | |
b7b18f32 |
254 | # test with_deferred_fk_checks |
255 | lives_ok { |
256 | $schema->storage->with_deferred_fk_checks(sub { |
257 | $schema->resultset('Track')->create({ |
258 | trackid => 999, cd => 999, position => 1, title => 'deferred FK track' |
259 | }); |
260 | $schema->resultset('CD')->create({ |
261 | artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd' |
262 | }); |
263 | }); |
264 | } 'with_deferred_fk_checks code survived'; |
265 | |
266 | is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track', |
267 | 'code in with_deferred_fk_checks worked'; |
268 | |
269 | throws_ok { |
270 | $schema->resultset('Track')->create({ |
271 | trackid => 1, cd => 9999, position => 1, title => 'Track1' |
272 | }); |
273 | } qr/constraint/i, 'with_deferred_fk_checks is off'; |
274 | |
ccd6f984 |
275 | # test auto increment using sequences WITHOUT triggers |
39b8d119 |
276 | for (1..5) { |
277 | my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' }); |
278 | is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key"); |
279 | is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key"); |
280 | is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key"); |
281 | } |
282 | my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 }); |
283 | is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually"); |
ccd6f984 |
284 | |
8068691e |
285 | SKIP: { |
d7f20fdf |
286 | my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) ); |
287 | $binstr{'large'} = $binstr{'small'} x 1024; |
8068691e |
288 | |
d7f20fdf |
289 | my $maxloblen = length $binstr{'large'}; |
290 | note "Localizing LongReadLen to $maxloblen to avoid truncation of test data"; |
291 | local $dbh->{'LongReadLen'} = $maxloblen; |
5db2758d |
292 | |
d7f20fdf |
293 | my $rs = $schema->resultset('BindType'); |
294 | my $id = 0; |
5db2758d |
295 | |
931e5d43 |
296 | if ($DBD::Oracle::VERSION eq '1.23') { |
297 | throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) } |
298 | qr/broken/, |
299 | 'throws on blob insert with DBD::Oracle == 1.23'; |
5db2758d |
300 | |
931e5d43 |
301 | skip 'buggy BLOB support in DBD::Oracle 1.23', 7; |
302 | } |
5db2758d |
303 | |
d7f20fdf |
304 | foreach my $type (qw( blob clob )) { |
305 | foreach my $size (qw( small large )) { |
306 | $id++; |
5db2758d |
307 | |
d7f20fdf |
308 | lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) } |
309 | "inserted $size $type without dying"; |
310 | |
311 | ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" ); |
312 | } |
313 | } |
5db2758d |
314 | } |
315 | |
bc6ae32e |
316 | |
317 | ### test hierarchical queries |
c0024355 |
318 | if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) { |
319 | my $source = $schema->source('Artist'); |
320 | |
321 | $source->add_column( 'parentid' ); |
322 | |
323 | $source->add_relationship('children', 'DBICTest::Schema::Artist', |
324 | { 'foreign.parentid' => 'self.artistid' }, |
325 | { |
326 | accessor => 'multi', |
327 | join_type => 'LEFT', |
328 | cascade_delete => 1, |
329 | cascade_copy => 1, |
330 | } ); |
331 | $source->add_relationship('parent', 'DBICTest::Schema::Artist', |
332 | { 'foreign.artistid' => 'self.parentid' }, |
333 | { accessor => 'single' } ); |
334 | DBICTest::Schema::Artist->add_column( 'parentid' ); |
335 | DBICTest::Schema::Artist->has_many( |
336 | children => 'DBICTest::Schema::Artist', |
337 | { 'foreign.parentid' => 'self.artistid' } |
338 | ); |
339 | DBICTest::Schema::Artist->belongs_to( |
340 | parent => 'DBICTest::Schema::Artist', |
341 | { 'foreign.artistid' => 'self.parentid' } |
342 | ); |
343 | |
344 | $schema->resultset('Artist')->create ({ |
345 | name => 'root', |
5c810af7 |
346 | rank => 1, |
c0024355 |
347 | cds => [], |
348 | children => [ |
349 | { |
350 | name => 'child1', |
5c810af7 |
351 | rank => 2, |
c0024355 |
352 | children => [ |
353 | { |
354 | name => 'grandchild', |
5c810af7 |
355 | rank => 3, |
c0024355 |
356 | cds => [ |
357 | { |
358 | title => "grandchilds's cd" , |
359 | year => '2008', |
360 | tracks => [ |
361 | { |
362 | position => 1, |
363 | title => 'Track 1 grandchild', |
364 | } |
365 | ], |
366 | } |
367 | ], |
368 | children => [ |
369 | { |
370 | name => 'greatgrandchild', |
5c810af7 |
371 | rank => 3, |
c0024355 |
372 | } |
373 | ], |
374 | } |
375 | ], |
376 | }, |
377 | { |
378 | name => 'child2', |
5c810af7 |
379 | rank => 3, |
c0024355 |
380 | }, |
381 | ], |
382 | }); |
383 | |
2a7879e2 |
384 | $schema->resultset('Artist')->create( |
385 | { |
386 | name => 'cycle-root', |
387 | children => [ |
388 | { |
389 | name => 'cycle-child1', |
390 | children => [ { name => 'cycle-grandchild' } ], |
391 | }, |
392 | { name => 'cycle-child2' }, |
393 | ], |
394 | } |
395 | ); |
396 | |
397 | $schema->resultset('Artist')->find({ name => 'cycle-root' }) |
398 | ->update({ parentid => \'artistid' }); |
399 | |
bc6ae32e |
400 | # select the whole tree |
c0024355 |
401 | { |
bc6ae32e |
402 | my $rs = $schema->resultset('Artist')->search({}, { |
403 | start_with => { name => 'root' }, |
404 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
405 | }); |
406 | |
407 | is_same_sql_bind ( |
408 | $rs->as_query, |
409 | '( |
410 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid |
411 | FROM artist me |
412 | START WITH name = ? |
1756ae89 |
413 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
414 | )', |
415 | [ [ name => 'root'] ], |
416 | ); |
417 | is_deeply ( |
418 | [ $rs->get_column ('name')->all ], |
419 | [ qw/root child1 grandchild greatgrandchild child2/ ], |
420 | 'got artist tree', |
421 | ); |
422 | |
423 | |
424 | is_same_sql_bind ( |
425 | $rs->count_rs->as_query, |
426 | '( |
427 | SELECT COUNT( * ) |
428 | FROM artist me |
429 | START WITH name = ? |
1756ae89 |
430 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
431 | )', |
432 | [ [ name => 'root'] ], |
433 | ); |
434 | |
c0024355 |
435 | is( $rs->count, 5, 'Connect By count ok' ); |
c0024355 |
436 | } |
437 | |
bc6ae32e |
438 | # use order siblings by statement |
c0024355 |
439 | { |
bc6ae32e |
440 | my $rs = $schema->resultset('Artist')->search({}, { |
441 | start_with => { name => 'root' }, |
442 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
443 | order_siblings_by => { -desc => 'name' }, |
444 | }); |
445 | |
446 | is_same_sql_bind ( |
447 | $rs->as_query, |
448 | '( |
449 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid |
450 | FROM artist me |
451 | START WITH name = ? |
1756ae89 |
452 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
453 | ORDER SIBLINGS BY name DESC |
454 | )', |
455 | [ [ name => 'root'] ], |
456 | ); |
457 | |
458 | is_deeply ( |
459 | [ $rs->get_column ('name')->all ], |
460 | [ qw/root child2 child1 grandchild greatgrandchild/ ], |
461 | 'Order Siblings By ok', |
462 | ); |
c0024355 |
463 | } |
464 | |
bc6ae32e |
465 | # get the root node |
c0024355 |
466 | { |
bc6ae32e |
467 | my $rs = $schema->resultset('Artist')->search({ parentid => undef }, { |
b34a62e5 |
468 | start_with => { name => 'root' }, |
469 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
bc6ae32e |
470 | }); |
471 | |
472 | is_same_sql_bind ( |
473 | $rs->as_query, |
474 | '( |
475 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid |
476 | FROM artist me |
477 | WHERE ( parentid IS NULL ) |
478 | START WITH name = ? |
1756ae89 |
479 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
480 | )', |
b34a62e5 |
481 | [ [ name => 'root'] ], |
bc6ae32e |
482 | ); |
483 | |
484 | is_deeply( |
485 | [ $rs->get_column('name')->all ], |
486 | [ 'root' ], |
487 | 'found root node', |
488 | ); |
c0024355 |
489 | } |
490 | |
bc6ae32e |
491 | # combine a connect by with a join |
c0024355 |
492 | { |
bc6ae32e |
493 | my $rs = $schema->resultset('Artist')->search( |
494 | {'cds.title' => { -like => '%cd'} }, |
495 | { |
496 | join => 'cds', |
497 | start_with => { 'me.name' => 'root' }, |
498 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
499 | } |
500 | ); |
501 | |
502 | is_same_sql_bind ( |
503 | $rs->as_query, |
504 | '( |
505 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid |
506 | FROM artist me |
507 | LEFT JOIN cd cds ON cds.artist = me.artistid |
508 | WHERE ( cds.title LIKE ? ) |
509 | START WITH me.name = ? |
1756ae89 |
510 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
511 | )', |
512 | [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ], |
513 | ); |
514 | |
515 | is_deeply( |
516 | [ $rs->get_column('name')->all ], |
517 | [ 'grandchild' ], |
518 | 'Connect By with a join result name ok' |
519 | ); |
520 | |
521 | |
522 | is_same_sql_bind ( |
523 | $rs->count_rs->as_query, |
524 | '( |
525 | SELECT COUNT( * ) |
526 | FROM artist me |
527 | LEFT JOIN cd cds ON cds.artist = me.artistid |
528 | WHERE ( cds.title LIKE ? ) |
529 | START WITH me.name = ? |
1756ae89 |
530 | CONNECT BY parentid = PRIOR artistid |
bc6ae32e |
531 | )', |
532 | [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ], |
533 | ); |
534 | |
c0024355 |
535 | is( $rs->count, 1, 'Connect By with a join; count ok' ); |
c0024355 |
536 | } |
537 | |
bc6ae32e |
538 | # combine a connect by with order_by |
c0024355 |
539 | { |
bc6ae32e |
540 | my $rs = $schema->resultset('Artist')->search({}, { |
b34a62e5 |
541 | start_with => { name => 'root' }, |
542 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
543 | order_by => { -asc => [ 'LEVEL', 'name' ] }, |
bc6ae32e |
544 | }); |
545 | |
546 | is_same_sql_bind ( |
547 | $rs->as_query, |
548 | '( |
549 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid |
550 | FROM artist me |
551 | START WITH name = ? |
1756ae89 |
552 | CONNECT BY parentid = PRIOR artistid |
b34a62e5 |
553 | ORDER BY LEVEL ASC, name ASC |
bc6ae32e |
554 | )', |
b34a62e5 |
555 | [ [ name => 'root' ] ], |
bc6ae32e |
556 | ); |
557 | |
558 | is_deeply ( |
559 | [ $rs->get_column ('name')->all ], |
b34a62e5 |
560 | [ qw/root child1 child2 grandchild greatgrandchild/ ], |
bc6ae32e |
561 | 'Connect By with a order_by - result name ok' |
562 | ); |
c0024355 |
563 | } |
564 | |
bc6ae32e |
565 | |
566 | # limit a connect by |
c0024355 |
567 | { |
bc6ae32e |
568 | my $rs = $schema->resultset('Artist')->search({}, { |
b34a62e5 |
569 | start_with => { name => 'root' }, |
570 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
571 | order_by => { -asc => 'name' }, |
bc6ae32e |
572 | rows => 2, |
573 | }); |
574 | |
575 | is_same_sql_bind ( |
576 | $rs->as_query, |
d4f4f6b4 |
577 | '( |
9a5a7d7e |
578 | SELECT artistid, name, rank, charfield, parentid FROM ( |
579 | SELECT artistid, name, rank, charfield, parentid, ROWNUM rownum__index FROM ( |
d4f4f6b4 |
580 | SELECT |
9a5a7d7e |
581 | me.artistid, |
582 | me.name, |
583 | me.rank, |
584 | me.charfield, |
585 | me.parentid |
d4f4f6b4 |
586 | FROM artist me |
587 | START WITH name = ? |
1756ae89 |
588 | CONNECT BY parentid = PRIOR artistid |
9a5a7d7e |
589 | ORDER BY name ASC |
590 | ) me |
591 | ) me |
592 | WHERE rownum__index BETWEEN 1 AND 2 |
bc6ae32e |
593 | )', |
b34a62e5 |
594 | [ [ name => 'root' ] ], |
bc6ae32e |
595 | ); |
596 | |
597 | is_deeply ( |
598 | [ $rs->get_column ('name')->all ], |
b34a62e5 |
599 | [qw/child1 child2/], |
bc6ae32e |
600 | 'LIMIT a Connect By query - correct names' |
601 | ); |
602 | |
d4f4f6b4 |
603 | # TODO: |
604 | # prints "START WITH name = ? |
1756ae89 |
605 | # CONNECT BY artistid = PRIOR parentid " |
d4f4f6b4 |
606 | # after count_subq, |
607 | # I will fix this later... |
608 | # |
d815b6a5 |
609 | is_same_sql_bind ( |
610 | $rs->count_rs->as_query, |
611 | '( |
612 | SELECT COUNT( * ) FROM ( |
613 | SELECT artistid FROM ( |
614 | SELECT artistid, ROWNUM rownum__index FROM ( |
615 | SELECT |
616 | me.artistid |
617 | FROM artist me |
618 | START WITH name = ? |
619 | CONNECT BY parentid = PRIOR artistid |
620 | ) me |
621 | ) me |
622 | WHERE rownum__index BETWEEN 1 AND 2 |
623 | ) me |
624 | )', |
625 | [ [ name => 'root' ] ], |
626 | ); |
627 | |
628 | is( $rs->count, 2, 'Connect By; LIMIT count ok' ); |
2ba03b16 |
629 | } |
630 | |
5c810af7 |
631 | # combine a connect_by with group_by and having |
632 | { |
633 | my $rs = $schema->resultset('Artist')->search({}, { |
634 | select => ['count(rank)'], |
635 | start_with => { name => 'root' }, |
636 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
637 | group_by => ['rank'], |
638 | having => { 'count(rank)' => { '<', 2 } }, |
639 | }); |
640 | |
641 | is_same_sql_bind ( |
642 | $rs->as_query, |
643 | '( |
644 | SELECT count(rank) |
645 | FROM artist me |
646 | START WITH name = ? |
647 | CONNECT BY parentid = PRIOR artistid |
648 | GROUP BY rank HAVING count(rank) < ? |
649 | )', |
650 | [ [ name => 'root' ], [ 'count(rank)' => 2 ] ], |
651 | ); |
652 | |
653 | is_deeply ( |
654 | [ $rs->get_column ('count(rank)')->all ], |
655 | [1, 1], |
656 | 'Group By a Connect By query - correct values' |
657 | ); |
658 | } |
659 | |
660 | |
2a7879e2 |
661 | # select the whole cycle tree without nocylce |
662 | { |
663 | my $rs = $schema->resultset('Artist')->search({}, { |
664 | start_with => { name => 'cycle-root' }, |
665 | connect_by => { parentid => { -prior => \ 'artistid' } }, |
666 | }); |
667 | eval { $rs->get_column ('name')->all }; |
73d6cd33 |
668 | if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data |
2a7879e2 |
669 | pass "connect by initify loop detection without nocycle"; |
670 | }else{ |
671 | fail "connect by initify loop detection without nocycle, not detected by oracle"; |
672 | } |
673 | } |
674 | |
675 | # select the whole cycle tree with nocylce |
2ba03b16 |
676 | { |
677 | my $rs = $schema->resultset('Artist')->search({}, { |
2a7879e2 |
678 | start_with => { name => 'cycle-root' }, |
679 | '+select' => [ \ 'CONNECT_BY_ISCYCLE' ], |
6b2fbbf0 |
680 | connect_by_nocycle => { parentid => { -prior => \ 'artistid' } }, |
2ba03b16 |
681 | }); |
682 | |
683 | is_same_sql_bind ( |
684 | $rs->as_query, |
685 | '( |
2a7879e2 |
686 | SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE |
2ba03b16 |
687 | FROM artist me |
688 | START WITH name = ? |
1756ae89 |
689 | CONNECT BY NOCYCLE parentid = PRIOR artistid |
2ba03b16 |
690 | )', |
2a7879e2 |
691 | [ [ name => 'cycle-root'] ], |
2ba03b16 |
692 | ); |
693 | is_deeply ( |
694 | [ $rs->get_column ('name')->all ], |
2a7879e2 |
695 | [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ], |
696 | 'got artist tree with nocycle (name)', |
697 | ); |
698 | is_deeply ( |
699 | [ $rs->get_column ('CONNECT_BY_ISCYCLE')->all ], |
700 | [ qw/1 0 0 0/ ], |
701 | 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)', |
2ba03b16 |
702 | ); |
703 | |
704 | |
bc6ae32e |
705 | is_same_sql_bind ( |
706 | $rs->count_rs->as_query, |
2ba03b16 |
707 | '( |
708 | SELECT COUNT( * ) |
709 | FROM artist me |
710 | START WITH name = ? |
1756ae89 |
711 | CONNECT BY NOCYCLE parentid = PRIOR artistid |
bc6ae32e |
712 | )', |
2a7879e2 |
713 | [ [ name => 'cycle-root'] ], |
bc6ae32e |
714 | ); |
715 | |
2a7879e2 |
716 | is( $rs->count, 4, 'Connect By Nocycle count ok' ); |
c0024355 |
717 | } |
718 | } |
719 | |
86cc4156 |
720 | done_testing; |
721 | |
0567538f |
722 | # clean up our mess |
3ff5b740 |
723 | END { |
fe0d48d3 |
724 | if($schema && ($dbh = $schema->storage->dbh)) { |
3ff5b740 |
725 | $dbh->do("DROP SEQUENCE artist_seq"); |
e6dd7b42 |
726 | $dbh->do("DROP SEQUENCE cd_seq"); |
c0024355 |
727 | $dbh->do("DROP SEQUENCE track_seq"); |
39b8d119 |
728 | $dbh->do("DROP SEQUENCE pkid1_seq"); |
729 | $dbh->do("DROP SEQUENCE pkid2_seq"); |
730 | $dbh->do("DROP SEQUENCE nonpkid_seq"); |
3ff5b740 |
731 | $dbh->do("DROP TABLE artist"); |
39b8d119 |
732 | $dbh->do("DROP TABLE sequence_test"); |
3ff5b740 |
733 | $dbh->do("DROP TABLE track"); |
b7b18f32 |
734 | $dbh->do("DROP TABLE cd"); |
5db2758d |
735 | $dbh->do("DROP TABLE bindtype_test"); |
3ff5b740 |
736 | } |
737 | } |
0567538f |
738 | |