File: 73oracle_hq.t

package info (click to toggle)
libdbix-class-perl 0.08196-3
  • links: PTS, VCS
  • area: main
  • in suites: wheezy
  • size: 4,424 kB
  • sloc: perl: 22,328; sql: 362; makefile: 10
file content (569 lines) | stat: -rw-r--r-- 16,649 bytes parent folder | download
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
use strict;
use warnings;

use Test::Exception;
use Test::More;
use DBIx::Class::Optional::Dependencies ();
use lib qw(t/lib);
use DBIC::SqlMakerTest;

use DBIx::Class::SQLMaker::LimitDialects;
my $ROWS = DBIx::Class::SQLMaker::LimitDialects->__rows_bindtype,
my $TOTAL = DBIx::Class::SQLMaker::LimitDialects->__total_bindtype,

$ENV{NLS_SORT} = "BINARY";
$ENV{NLS_COMP} = "BINARY";
$ENV{NLS_LANG} = "AMERICAN";

my ($dsn,  $user,  $pass)  = @ENV{map { "DBICTEST_ORA_${_}" }  qw/DSN USER PASS/};

plan skip_all => 'Set $ENV{DBICTEST_ORA_DSN}, _USER and _PASS to run this test.'
 unless ($dsn && $user && $pass);

plan skip_all => 'Test needs ' . DBIx::Class::Optional::Dependencies->req_missing_for ('rdbms_oracle')
  unless DBIx::Class::Optional::Dependencies->req_ok_for ('rdbms_oracle');

use DBICTest::Schema::Artist;
BEGIN {
  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' }
  );
}

use DBICTest::Schema;

my $schema = DBICTest::Schema->connect($dsn, $user, $pass);

note "Oracle Version: " . $schema->storage->_server_info->{dbms_version};

my $dbh = $schema->storage->dbh;
do_creates($dbh);

### test hierarchical queries
{
  $schema->resultset('Artist')->create ({
    name => 'root',
    rank => 1,
    cds => [],
    children => [
      {
        name => 'child1',
        rank => 2,
        children => [
          {
            name => 'grandchild',
            rank => 3,
            cds => [
              {
                title => "grandchilds's cd" ,
                year => '2008',
                tracks => [
                  {
                    position => 1,
                    title => 'Track 1 grandchild',
                  }
                ],
              }
            ],
            children => [
              {
                name => 'greatgrandchild',
                rank => 3,
              }
            ],
          }
        ],
      },
      {
        name => 'child2',
        rank => 3,
      },
    ],
  });

  $schema->resultset('Artist')->create({
    name => 'cycle-root',
    children => [
      {
        name => 'cycle-child1',
        children => [ { name => 'cycle-grandchild' } ],
      },
      {
        name => 'cycle-child2'
      },
    ],
  });

  $schema->resultset('Artist')->find({ name => 'cycle-root' })
    ->update({ parentid => { -ident => 'artistid' } });

  # select the whole tree
  {
    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
          FROM artist me
        START WITH name = ?
        CONNECT BY parentid = PRIOR artistid
      )',
      [ [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'] ],
    );
    is_deeply (
      [ $rs->get_column ('name')->all ],
      [ qw/root child1 grandchild greatgrandchild child2/ ],
      'got artist tree',
    );

    is_same_sql_bind (
      $rs->count_rs->as_query,
      '(
        SELECT COUNT( * )
          FROM artist me
        START WITH name = ?
        CONNECT BY parentid = PRIOR artistid
      )',
      [ [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'] ],
    );

    is( $rs->count, 5, 'Connect By count ok' );
  }

  # use order siblings by statement
  SKIP: {
    # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/state21b.htm#2066123
    skip q{Oracle8i doesn't support ORDER SIBLINGS BY}, 1
      if $schema->storage->_server_info->{normalized_dbms_version} < 9;

    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident =>  'artistid' } } },
      order_siblings_by => { -desc => 'name' },
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        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
      )',
      [ [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'] ],
    );

    is_deeply (
      [ $rs->get_column ('name')->all ],
      [ qw/root child2 child1 grandchild greatgrandchild/ ],
      'Order Siblings By ok',
    );
  }

  # get the root node
  {
    my $rs = $schema->resultset('Artist')->search({ parentid => undef }, {
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
          FROM artist me
        WHERE ( parentid IS NULL )
        START WITH name = ?
        CONNECT BY parentid = PRIOR artistid
      )',
      [ [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'] ],
    );

    is_deeply(
      [ $rs->get_column('name')->all ],
      [ 'root' ],
      'found root node',
    );
  }

  # combine a connect by with a join
  SKIP: {
    # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/state21b.htm#2066123
    skip q{Oracle8i doesn't support connect by with join}, 1
      if $schema->storage->_server_info->{normalized_dbms_version} < 9;

    my $rs = $schema->resultset('Artist')->search(
      {'cds.title' => { -like => '%cd'} },
      {
        join => 'cds',
        start_with => { 'me.name' => 'root' },
        connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
      }
    );

    is_same_sql_bind (
      $rs->as_query,
      '(
        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 me.name = ?
        CONNECT BY parentid = PRIOR artistid
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'cds.title', 'sqlt_size' => 100 }
            => '%cd'],
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'me.name', 'sqlt_size' => 100 }
            => 'root'],
      ],
    );

    is_deeply(
      [ $rs->get_column('name')->all ],
      [ 'grandchild' ],
      'Connect By with a join result name ok'
    );

    is_same_sql_bind (
      $rs->count_rs->as_query,
      '(
        SELECT COUNT( * )
          FROM artist me
          LEFT JOIN cd cds ON cds.artist = me.artistid
        WHERE ( cds.title LIKE ? )
        START WITH me.name = ?
        CONNECT BY parentid = PRIOR artistid
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'cds.title', 'sqlt_size' => 100 }
            => '%cd'],
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'me.name', 'sqlt_size' => 100 }
            => 'root'],
      ],
    );

    is( $rs->count, 1, 'Connect By with a join; count ok' );
  }

  # combine a connect by with order_by
  {
    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
      order_by => { -asc => [ 'LEVEL', 'name' ] },
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
          FROM artist me
        START WITH name = ?
        CONNECT BY parentid = PRIOR artistid
        ORDER BY LEVEL ASC, name ASC
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'],
      ],
    );


    # Don't use "$rs->get_column ('name')->all" they build a query arround the $rs.
    #   If $rs has a order by, the order by is in the subquery and this doesn't work with Oracle 8i.
    # TODO: write extra test and fix order by handling on Oracle 8i
    is_deeply (
      [ map { $_->[1] } $rs->cursor->all ],
      [ qw/root child1 child2 grandchild greatgrandchild/ ],
      'Connect By with a order_by - result name ok (without get_column)'
    );

    SKIP: {
      skip q{Connect By with a order_by - result name ok (with get_column), Oracle8i doesn't support order by in a subquery},1
        if $schema->storage->_server_info->{normalized_dbms_version} < 9;
      is_deeply (
        [  $rs->get_column ('name')->all ],
        [ qw/root child1 child2 grandchild greatgrandchild/ ],
        'Connect By with a order_by - result name ok (with get_column)'
      );
    }
  }


  # limit a connect by
  SKIP: {
    skip q{Oracle8i doesn't support order by in a subquery}, 1
      if $schema->storage->_server_info->{normalized_dbms_version} < 9;

    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
      order_by => [ { -asc => 'name' }, {  -desc => 'artistid' } ],
      rows => 2,
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT artistid, name, rank, charfield, parentid
          FROM (
            SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid
              FROM artist me
            START WITH name = ?
            CONNECT BY parentid = PRIOR artistid
            ORDER BY name ASC, artistid DESC
          ) me
        WHERE ROWNUM <= ?
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'], [ $ROWS => 2 ],
      ],
    );

    is_deeply (
      [ $rs->get_column ('name')->all ],
      [qw/child1 child2/],
      'LIMIT a Connect By query - correct names'
    );

    is_same_sql_bind (
      $rs->count_rs->as_query,
      '(
        SELECT COUNT( * )
          FROM (
            SELECT artistid
              FROM (
                SELECT artistid, ROWNUM rownum__index
                  FROM (
                    SELECT me.artistid
                      FROM artist me
                    START WITH name = ?
                    CONNECT BY parentid = PRIOR artistid
                  ) me
              ) me
            WHERE rownum__index BETWEEN ? AND ?
          ) me
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'],
        [ $ROWS => 1 ],
        [ $TOTAL => 2 ],
      ],
    );

    is( $rs->count, 2, 'Connect By; LIMIT count ok' );
  }

  # combine a connect_by with group_by and having
  # add some bindvals to make sure things still work
  {
    my $rs = $schema->resultset('Artist')->search({}, {
      select => \[ 'COUNT(rank) + ?', [ __cbind => 3 ] ],
      as => 'cnt',
      start_with => { name => 'root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
      group_by => \[ 'rank + ? ', [ __gbind =>  1] ],
      having => \[ 'count(rank) < ?', [ cnt => 2 ] ],
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT COUNT(rank) + ?
          FROM artist me
        START WITH name = ?
        CONNECT BY parentid = PRIOR artistid
        GROUP BY( rank + ? ) HAVING count(rank) < ?
      )',
      [
        [ { dbic_colname => '__cbind' }
            => 3 ],
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'root'],
        [ { dbic_colname => '__gbind' }
            => 1 ],
        [ { dbic_colname => 'cnt' }
            => 2 ],
      ],
    );

    is_deeply (
      [ $rs->get_column ('cnt')->all ],
      [4, 4],
      'Group By a Connect By query - correct values'
    );
  }

  # select the whole cycle tree without nocylce
  {
    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'cycle-root' },
      connect_by => { parentid => { -prior => { -ident => 'artistid' } } },
    });

    # ORA-01436:  CONNECT BY loop in user data
    throws_ok { $rs->get_column ('name')->all } qr/ORA-01436/,
      "connect by initify loop detection without nocycle";
  }

  # select the whole cycle tree with nocylce
  SKIP: {
    # http://download.oracle.com/docs/cd/A87860_01/doc/server.817/a85397/expressi.htm#1023748
    skip q{Oracle8i doesn't support connect by nocycle}, 1
      if $schema->storage->_server_info->{normalized_dbms_version} < 9;

    my $rs = $schema->resultset('Artist')->search({}, {
      start_with => { name => 'cycle-root' },
      '+select'  => \ 'CONNECT_BY_ISCYCLE',
      '+as'      => [ 'connector' ],
      connect_by_nocycle => { parentid => { -prior => { -ident => 'artistid' } } },
    });

    is_same_sql_bind (
      $rs->as_query,
      '(
        SELECT me.artistid, me.name, me.rank, me.charfield, me.parentid, CONNECT_BY_ISCYCLE
          FROM artist me
        START WITH name = ?
        CONNECT BY NOCYCLE parentid = PRIOR artistid
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'cycle-root'],
      ],
    );
    is_deeply (
      [ $rs->get_column ('name')->all ],
      [ qw/cycle-root cycle-child1 cycle-grandchild cycle-child2/ ],
      'got artist tree with nocycle (name)',
    );
    is_deeply (
      [ $rs->get_column ('connector')->all ],
      [ qw/1 0 0 0/ ],
      'got artist tree with nocycle (CONNECT_BY_ISCYCLE)',
    );

    is_same_sql_bind (
      $rs->count_rs->as_query,
      '(
        SELECT COUNT( * )
          FROM artist me
        START WITH name = ?
        CONNECT BY NOCYCLE parentid = PRIOR artistid
      )',
      [
        [ { 'sqlt_datatype' => 'varchar', 'dbic_colname' => 'name', 'sqlt_size' => 100 }
            => 'cycle-root'],
      ],
    );

    is( $rs->count, 4, 'Connect By Nocycle count ok' );
  }
}

done_testing;

sub do_creates {
  my $dbh = shift;

  eval {
    $dbh->do("DROP SEQUENCE artist_autoinc_seq");
    $dbh->do("DROP SEQUENCE artist_pk_seq");
    $dbh->do("DROP SEQUENCE cd_seq");
    $dbh->do("DROP SEQUENCE track_seq");
    $dbh->do("DROP TABLE artist");
    $dbh->do("DROP TABLE track");
    $dbh->do("DROP TABLE cd");
  };

  $dbh->do("CREATE SEQUENCE artist_pk_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 TABLE artist (artistid NUMBER(12), parentid NUMBER(12), name VARCHAR(255), autoinc_col NUMBER(12), rank NUMBER(38), charfield VARCHAR2(10))");
  $dbh->do("ALTER TABLE artist ADD (CONSTRAINT artist_pk PRIMARY KEY (artistid))");

  $dbh->do("CREATE TABLE cd (cdid NUMBER(12), artist NUMBER(12), title VARCHAR(255), year VARCHAR(4), genreid NUMBER(12), single_track NUMBER(12))");
  $dbh->do("ALTER TABLE cd ADD (CONSTRAINT cd_pk PRIMARY KEY (cdid))");

  $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)");
  $dbh->do("ALTER TABLE track ADD (CONSTRAINT track_pk PRIMARY KEY (trackid))");

  $dbh->do(qq{
    CREATE OR REPLACE TRIGGER artist_insert_trg_pk
    BEFORE INSERT ON artist
    FOR EACH ROW
      BEGIN
        IF :new.artistid IS NULL THEN
          SELECT artist_pk_seq.nextval
          INTO :new.artistid
          FROM DUAL;
        END IF;
      END;
  });
  $dbh->do(qq{
    CREATE OR REPLACE TRIGGER cd_insert_trg
    BEFORE INSERT OR UPDATE ON cd
    FOR EACH ROW

      DECLARE
      tmpVar NUMBER;

      BEGIN
        tmpVar := 0;

        IF :new.cdid IS NULL THEN
          SELECT cd_seq.nextval
          INTO tmpVar
          FROM dual;

          :new.cdid := tmpVar;
        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;
  });
}

# clean up our mess
END {
  eval {
    my $dbh = $schema->storage->dbh;
    $dbh->do("DROP SEQUENCE artist_pk_seq");
    $dbh->do("DROP SEQUENCE cd_seq");
    $dbh->do("DROP SEQUENCE track_seq");
    $dbh->do("DROP TABLE artist");
    $dbh->do("DROP TABLE track");
    $dbh->do("DROP TABLE cd");
  };
}