POD fixes (RT#58247)
[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;
ab6e0924 33
70350518 34use lib qw(t/lib);
35use DBICTest;
8ce8340f 36use DBIC::SqlMakerTest;
0567538f 37
38my ($dsn, $user, $pass) = @ENV{map { "DBICTEST_ORA_${_}" } qw/DSN USER PASS/};
39
70350518 40plan 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 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");
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 154my $new = $schema->resultset('Artist')->create({ name => 'foo' });
c8f4b52b 155is($new->artistid, 1, "Oracle Auto-PK worked");
0567538f 156
e6dd7b42 157my $cd = $schema->resultset('CD')->create({ artist => 1, title => 'EP C', year => '2003' });
62d4dbae 158is($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' } );
162is( $new->artistid, 2, "Oracle Auto-PK worked with fully-qualified tablename" );
163
62d4dbae 164# test rel names over the 30 char limit
165my $query = $schema->resultset('Artist')->search({
6c0230de 166 artistid => 1
62d4dbae 167}, {
168 prefetch => 'cds_very_very_very_long_relationship_name'
169});
170
171lives_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 193my $track = $schema->resultset('Track')->create({ cd => $cd->cdid,
9900b569 194 position => 1, title => 'Track1' });
3ff5b740 195my $tjoin = $schema->resultset('Track')->search({ 'me.title' => 'Track1'},
2660b14e 196 { join => 'cd',
197 rows => 2 }
198);
199
d2a3958e 200ok(my $row = $tjoin->next);
201
202is($row->title, 'Track1', "ambiguous column ok");
2660b14e 203
286f32b3 204# check count distinct with multiple columns
c0024355 205my $other_track = $schema->resultset('Track')->create({ cd => $cd->cdid, position => 1, title => 'Track2' });
11d68671 206
3ff5b740 207my $tcount = $schema->resultset('Track')->search(
11d68671 208 {},
209 {
210 select => [ qw/position title/ ],
211 distinct => 1,
212 }
213);
f12f0d97 214is($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 223is($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 231is($tcount->count, 2, 'multiple column COUNT DISTINCT using column syntax ok');
2660b14e 232
0567538f 233# test LIMIT support
234for (1..6) {
3ff5b740 235 $schema->resultset('Artist')->create({ name => 'Artist ' . $_ });
0567538f 236}
3ff5b740 237my $it = $schema->resultset('Artist')->search( {},
0567538f 238 { rows => 3,
cb464582 239 offset => 3,
0567538f 240 order_by => 'artistid' }
241);
242is( $it->count, 3, "LIMIT count ok" );
243is( $it->next->name, "Artist 2", "iterator->next ok" );
244$it->next;
245$it->next;
246is( $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
bd691933 254# test identifiers over the 30 char limit
255{
256 lives_ok {
257 my @results = $schema->resultset('CD')->search(undef, {
258 prefetch => 'very_long_artist_relationship',
259 rows => 3,
260 offset => 0,
261 })->all;
262 ok( scalar @results > 0, 'limit with long identifiers returned something');
263 } 'limit with long identifiers executed successfully';
264}
265
b7b18f32 266# test with_deferred_fk_checks
267lives_ok {
268 $schema->storage->with_deferred_fk_checks(sub {
269 $schema->resultset('Track')->create({
270 trackid => 999, cd => 999, position => 1, title => 'deferred FK track'
271 });
272 $schema->resultset('CD')->create({
273 artist => 1, cdid => 999, year => '2003', title => 'deferred FK cd'
274 });
275 });
276} 'with_deferred_fk_checks code survived';
277
278is eval { $schema->resultset('Track')->find(999)->title }, 'deferred FK track',
279 'code in with_deferred_fk_checks worked';
280
281throws_ok {
282 $schema->resultset('Track')->create({
283 trackid => 1, cd => 9999, position => 1, title => 'Track1'
284 });
285} qr/constraint/i, 'with_deferred_fk_checks is off';
286
ccd6f984 287# test auto increment using sequences WITHOUT triggers
39b8d119 288for (1..5) {
289 my $st = $schema->resultset('SequenceTest')->create({ name => 'foo' });
290 is($st->pkid1, $_, "Oracle Auto-PK without trigger: First primary key");
291 is($st->pkid2, $_ + 9, "Oracle Auto-PK without trigger: Second primary key");
292 is($st->nonpkid, $_ + 19, "Oracle Auto-PK without trigger: Non-primary key");
293}
294my $st = $schema->resultset('SequenceTest')->create({ name => 'foo', pkid1 => 55 });
295is($st->pkid1, 55, "Oracle Auto-PK without trigger: First primary key set manually");
ccd6f984 296
8068691e 297SKIP: {
d7f20fdf 298 my %binstr = ( 'small' => join('', map { chr($_) } ( 1 .. 127 )) );
299 $binstr{'large'} = $binstr{'small'} x 1024;
8068691e 300
d7f20fdf 301 my $maxloblen = length $binstr{'large'};
302 note "Localizing LongReadLen to $maxloblen to avoid truncation of test data";
303 local $dbh->{'LongReadLen'} = $maxloblen;
5db2758d 304
d7f20fdf 305 my $rs = $schema->resultset('BindType');
306 my $id = 0;
5db2758d 307
931e5d43 308 if ($DBD::Oracle::VERSION eq '1.23') {
309 throws_ok { $rs->create({ id => 1, blob => $binstr{large} }) }
310 qr/broken/,
311 'throws on blob insert with DBD::Oracle == 1.23';
5db2758d 312
931e5d43 313 skip 'buggy BLOB support in DBD::Oracle 1.23', 7;
314 }
5db2758d 315
d7f20fdf 316 foreach my $type (qw( blob clob )) {
317 foreach my $size (qw( small large )) {
318 $id++;
5db2758d 319
d7f20fdf 320 lives_ok { $rs->create( { 'id' => $id, $type => $binstr{$size} } ) }
321 "inserted $size $type without dying";
322
323 ok($rs->find($id)->$type eq $binstr{$size}, "verified inserted $size $type" );
324 }
325 }
5db2758d 326}
327
bc6ae32e 328
329### test hierarchical queries
c0024355 330if ( $schema->storage->isa('DBIx::Class::Storage::DBI::Oracle::Generic') ) {
331 my $source = $schema->source('Artist');
332
333 $source->add_column( 'parentid' );
334
335 $source->add_relationship('children', 'DBICTest::Schema::Artist',
336 { 'foreign.parentid' => 'self.artistid' },
337 {
338 accessor => 'multi',
339 join_type => 'LEFT',
340 cascade_delete => 1,
341 cascade_copy => 1,
342 } );
343 $source->add_relationship('parent', 'DBICTest::Schema::Artist',
344 { 'foreign.artistid' => 'self.parentid' },
345 { accessor => 'single' } );
346 DBICTest::Schema::Artist->add_column( 'parentid' );
347 DBICTest::Schema::Artist->has_many(
348 children => 'DBICTest::Schema::Artist',
349 { 'foreign.parentid' => 'self.artistid' }
350 );
351 DBICTest::Schema::Artist->belongs_to(
352 parent => 'DBICTest::Schema::Artist',
353 { 'foreign.artistid' => 'self.parentid' }
354 );
355
356 $schema->resultset('Artist')->create ({
357 name => 'root',
5c810af7 358 rank => 1,
c0024355 359 cds => [],
360 children => [
361 {
362 name => 'child1',
5c810af7 363 rank => 2,
c0024355 364 children => [
365 {
366 name => 'grandchild',
5c810af7 367 rank => 3,
c0024355 368 cds => [
369 {
370 title => "grandchilds's cd" ,
371 year => '2008',
372 tracks => [
373 {
374 position => 1,
375 title => 'Track 1 grandchild',
376 }
377 ],
378 }
379 ],
380 children => [
381 {
382 name => 'greatgrandchild',
5c810af7 383 rank => 3,
c0024355 384 }
385 ],
386 }
387 ],
388 },
389 {
390 name => 'child2',
5c810af7 391 rank => 3,
c0024355 392 },
393 ],
394 });
395
2a7879e2 396 $schema->resultset('Artist')->create(
397 {
398 name => 'cycle-root',
399 children => [
400 {
401 name => 'cycle-child1',
402 children => [ { name => 'cycle-grandchild' } ],
403 },
404 { name => 'cycle-child2' },
405 ],
406 }
407 );
408
409 $schema->resultset('Artist')->find({ name => 'cycle-root' })
410 ->update({ parentid => \'artistid' });
411
bc6ae32e 412 # select the whole tree
c0024355 413 {
bc6ae32e 414 my $rs = $schema->resultset('Artist')->search({}, {
415 start_with => { name => 'root' },
416 connect_by => { parentid => { -prior => \ 'artistid' } },
417 });
418
419 is_same_sql_bind (
420 $rs->as_query,
421 '(
422 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
423 FROM artist me
424 START WITH name = ?
1756ae89 425 CONNECT BY parentid = PRIOR artistid
bc6ae32e 426 )',
427 [ [ name => 'root'] ],
428 );
429 is_deeply (
430 [ $rs->get_column ('name')->all ],
431 [ qw/root child1 grandchild greatgrandchild child2/ ],
432 'got artist tree',
433 );
434
435
436 is_same_sql_bind (
437 $rs->count_rs->as_query,
438 '(
439 SELECT COUNT( * )
440 FROM artist me
441 START WITH name = ?
1756ae89 442 CONNECT BY parentid = PRIOR artistid
bc6ae32e 443 )',
444 [ [ name => 'root'] ],
445 );
446
c0024355 447 is( $rs->count, 5, 'Connect By count ok' );
c0024355 448 }
449
bc6ae32e 450 # use order siblings by statement
c0024355 451 {
bc6ae32e 452 my $rs = $schema->resultset('Artist')->search({}, {
453 start_with => { name => 'root' },
454 connect_by => { parentid => { -prior => \ 'artistid' } },
455 order_siblings_by => { -desc => 'name' },
456 });
457
458 is_same_sql_bind (
459 $rs->as_query,
460 '(
461 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
462 FROM artist me
463 START WITH name = ?
1756ae89 464 CONNECT BY parentid = PRIOR artistid
bc6ae32e 465 ORDER SIBLINGS BY name DESC
466 )',
467 [ [ name => 'root'] ],
468 );
469
470 is_deeply (
471 [ $rs->get_column ('name')->all ],
472 [ qw/root child2 child1 grandchild greatgrandchild/ ],
473 'Order Siblings By ok',
474 );
c0024355 475 }
476
bc6ae32e 477 # get the root node
c0024355 478 {
bc6ae32e 479 my $rs = $schema->resultset('Artist')->search({ parentid => undef }, {
b34a62e5 480 start_with => { name => 'root' },
481 connect_by => { parentid => { -prior => \ 'artistid' } },
bc6ae32e 482 });
483
484 is_same_sql_bind (
485 $rs->as_query,
486 '(
487 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
488 FROM artist me
489 WHERE ( parentid IS NULL )
490 START WITH name = ?
1756ae89 491 CONNECT BY parentid = PRIOR artistid
bc6ae32e 492 )',
b34a62e5 493 [ [ name => 'root'] ],
bc6ae32e 494 );
495
496 is_deeply(
497 [ $rs->get_column('name')->all ],
498 [ 'root' ],
499 'found root node',
500 );
c0024355 501 }
502
bc6ae32e 503 # combine a connect by with a join
c0024355 504 {
bc6ae32e 505 my $rs = $schema->resultset('Artist')->search(
506 {'cds.title' => { -like => '%cd'} },
507 {
508 join => 'cds',
509 start_with => { 'me.name' => 'root' },
510 connect_by => { parentid => { -prior => \ 'artistid' } },
511 }
512 );
513
514 is_same_sql_bind (
515 $rs->as_query,
516 '(
517 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
518 FROM artist me
519 LEFT JOIN cd cds ON cds.artist = me.artistid
520 WHERE ( cds.title LIKE ? )
521 START WITH me.name = ?
1756ae89 522 CONNECT BY parentid = PRIOR artistid
bc6ae32e 523 )',
524 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
525 );
526
527 is_deeply(
528 [ $rs->get_column('name')->all ],
529 [ 'grandchild' ],
530 'Connect By with a join result name ok'
531 );
532
533
534 is_same_sql_bind (
535 $rs->count_rs->as_query,
536 '(
537 SELECT COUNT( * )
538 FROM artist me
539 LEFT JOIN cd cds ON cds.artist = me.artistid
540 WHERE ( cds.title LIKE ? )
541 START WITH me.name = ?
1756ae89 542 CONNECT BY parentid = PRIOR artistid
bc6ae32e 543 )',
544 [ [ 'cds.title' => '%cd' ], [ 'me.name' => 'root' ] ],
545 );
546
c0024355 547 is( $rs->count, 1, 'Connect By with a join; count ok' );
c0024355 548 }
549
bc6ae32e 550 # combine a connect by with order_by
c0024355 551 {
bc6ae32e 552 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 553 start_with => { name => 'root' },
554 connect_by => { parentid => { -prior => \ 'artistid' } },
555 order_by => { -asc => [ 'LEVEL', 'name' ] },
bc6ae32e 556 });
557
558 is_same_sql_bind (
559 $rs->as_query,
560 '(
561 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
562 FROM artist me
563 START WITH name = ?
1756ae89 564 CONNECT BY parentid = PRIOR artistid
b34a62e5 565 ORDER BY LEVEL ASC, name ASC
bc6ae32e 566 )',
b34a62e5 567 [ [ name => 'root' ] ],
bc6ae32e 568 );
569
570 is_deeply (
571 [ $rs->get_column ('name')->all ],
b34a62e5 572 [ qw/root child1 child2 grandchild greatgrandchild/ ],
bc6ae32e 573 'Connect By with a order_by - result name ok'
574 );
c0024355 575 }
576
bc6ae32e 577
578 # limit a connect by
c0024355 579 {
bc6ae32e 580 my $rs = $schema->resultset('Artist')->search({}, {
b34a62e5 581 start_with => { name => 'root' },
582 connect_by => { parentid => { -prior => \ 'artistid' } },
583 order_by => { -asc => 'name' },
bc6ae32e 584 rows => 2,
585 });
586
587 is_same_sql_bind (
588 $rs->as_query,
d4f4f6b4 589 '(
9a5a7d7e 590 SELECT artistid, name, rank, charfield, parentid FROM (
591 SELECT artistid, name, rank, charfield, parentid, ROWNUM rownum__index FROM (
d4f4f6b4 592 SELECT
9a5a7d7e 593 me.artistid,
594 me.name,
595 me.rank,
596 me.charfield,
597 me.parentid
d4f4f6b4 598 FROM artist me
599 START WITH name = ?
1756ae89 600 CONNECT BY parentid = PRIOR artistid
9a5a7d7e 601 ORDER BY name ASC
602 ) me
603 ) me
604 WHERE rownum__index BETWEEN 1 AND 2
bc6ae32e 605 )',
b34a62e5 606 [ [ name => 'root' ] ],
bc6ae32e 607 );
608
609 is_deeply (
610 [ $rs->get_column ('name')->all ],
b34a62e5 611 [qw/child1 child2/],
bc6ae32e 612 'LIMIT a Connect By query - correct names'
613 );
614
d4f4f6b4 615 # TODO:
616 # prints "START WITH name = ?
1756ae89 617 # CONNECT BY artistid = PRIOR parentid "
d4f4f6b4 618 # after count_subq,
619 # I will fix this later...
620 #
d815b6a5 621 is_same_sql_bind (
622 $rs->count_rs->as_query,
623 '(
624 SELECT COUNT( * ) FROM (
625 SELECT artistid FROM (
626 SELECT artistid, ROWNUM rownum__index FROM (
627 SELECT
628 me.artistid
629 FROM artist me
630 START WITH name = ?
631 CONNECT BY parentid = PRIOR artistid
632 ) me
633 ) me
634 WHERE rownum__index BETWEEN 1 AND 2
635 ) me
636 )',
637 [ [ name => 'root' ] ],
638 );
639
640 is( $rs->count, 2, 'Connect By; LIMIT count ok' );
2ba03b16 641 }
642
5c810af7 643 # combine a connect_by with group_by and having
644 {
645 my $rs = $schema->resultset('Artist')->search({}, {
646 select => ['count(rank)'],
647 start_with => { name => 'root' },
648 connect_by => { parentid => { -prior => \ 'artistid' } },
649 group_by => ['rank'],
650 having => { 'count(rank)' => { '<', 2 } },
651 });
652
653 is_same_sql_bind (
654 $rs->as_query,
655 '(
656 SELECT count(rank)
657 FROM artist me
658 START WITH name = ?
659 CONNECT BY parentid = PRIOR artistid
660 GROUP BY rank HAVING count(rank) < ?
661 )',
662 [ [ name => 'root' ], [ 'count(rank)' => 2 ] ],
663 );
664
665 is_deeply (
666 [ $rs->get_column ('count(rank)')->all ],
667 [1, 1],
668 'Group By a Connect By query - correct values'
669 );
670 }
671
672
2a7879e2 673 # select the whole cycle tree without nocylce
674 {
675 my $rs = $schema->resultset('Artist')->search({}, {
676 start_with => { name => 'cycle-root' },
677 connect_by => { parentid => { -prior => \ 'artistid' } },
678 });
679 eval { $rs->get_column ('name')->all };
73d6cd33 680 if ( $@ =~ /ORA-01436/ ){ # ORA-01436: CONNECT BY loop in user data
2a7879e2 681 pass "connect by initify loop detection without nocycle";
682 }else{
683 fail "connect by initify loop detection without nocycle, not detected by oracle";
684 }
685 }
686
687 # select the whole cycle tree with nocylce
2ba03b16 688 {
689 my $rs = $schema->resultset('Artist')->search({}, {
2a7879e2 690 start_with => { name => 'cycle-root' },
691 '+select' => [ \ 'CONNECT_BY_ISCYCLE' ],
6b2fbbf0 692 connect_by_nocycle => { parentid => { -prior => \ 'artistid' } },
2ba03b16 693 });
694
695 is_same_sql_bind (
696 $rs->as_query,
697 '(
2a7879e2 698 SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE
2ba03b16 699 FROM artist me
700 START WITH name = ?
1756ae89 701 CONNECT BY NOCYCLE parentid = PRIOR artistid
2ba03b16 702 )',
2a7879e2 703 [ [ name => 'cycle-root'] ],
2ba03b16 704 );
705 is_deeply (
706 [ $rs->get_column ('name')->all ],
2a7879e2 707 [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ],
708 'got artist tree with nocycle (name)',
709 );
710 is_deeply (
711 [ $rs->get_column ('CONNECT_BY_ISCYCLE')->all ],
712 [ qw/1 0 0 0/ ],
713 'got artist tree with nocycle (CONNECT_BY_ISCYCLE)',
2ba03b16 714 );
715
716
bc6ae32e 717 is_same_sql_bind (
718 $rs->count_rs->as_query,
2ba03b16 719 '(
720 SELECT COUNT( * )
721 FROM artist me
722 START WITH name = ?
1756ae89 723 CONNECT BY NOCYCLE parentid = PRIOR artistid
bc6ae32e 724 )',
2a7879e2 725 [ [ name => 'cycle-root'] ],
bc6ae32e 726 );
727
2a7879e2 728 is( $rs->count, 4, 'Connect By Nocycle count ok' );
c0024355 729 }
730}
731
86cc4156 732done_testing;
733
0567538f 734# clean up our mess
3ff5b740 735END {
fe0d48d3 736 if($schema && ($dbh = $schema->storage->dbh)) {
3ff5b740 737 $dbh->do("DROP SEQUENCE artist_seq");
e6dd7b42 738 $dbh->do("DROP SEQUENCE cd_seq");
c0024355 739 $dbh->do("DROP SEQUENCE track_seq");
39b8d119 740 $dbh->do("DROP SEQUENCE pkid1_seq");
741 $dbh->do("DROP SEQUENCE pkid2_seq");
742 $dbh->do("DROP SEQUENCE nonpkid_seq");
3ff5b740 743 $dbh->do("DROP TABLE artist");
39b8d119 744 $dbh->do("DROP TABLE sequence_test");
3ff5b740 745 $dbh->do("DROP TABLE track");
b7b18f32 746 $dbh->do("DROP TABLE cd");
5db2758d 747 $dbh->do("DROP TABLE bindtype_test");
3ff5b740 748 }
749}
0567538f 750