File: generic_subq.t

package info (click to toggle)
libdbix-class-perl 0.082844-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 5,320 kB
  • sloc: perl: 27,215; sql: 322; sh: 29; makefile: 16
file content (332 lines) | stat: -rw-r--r-- 10,346 bytes parent folder | download | duplicates (2)
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
use strict;
use warnings;

use Test::More;
use lib qw(t/lib);
use List::Util 'min';
use DBICTest ':DiffSQL';
my ($ROWS, $TOTAL, $OFFSET) = (
   DBIx::Class::SQLMaker::ClassicExtensions->__rows_bindtype,
   DBIx::Class::SQLMaker::ClassicExtensions->__total_bindtype,
   DBIx::Class::SQLMaker::ClassicExtensions->__offset_bindtype,
);


my $schema = DBICTest->init_schema;

$schema->storage->_sql_maker->limit_dialect ('GenericSubQ');

my $rs = $schema->resultset ('BooksInLibrary')->search ({}, {
  '+columns' => [{ owner_name => 'owner.name' }],
  join => 'owner',
  rows => 2,
  order_by => 'me.title',
});

is_same_sql_bind(
  $rs->as_query,
  '(
    SELECT  me.id, me.source, me.owner, me.title, me.price,
            owner_name
      FROM (
        SELECT  me.id, me.source, me.owner, me.title, me.price,
                owner.name AS owner_name
          FROM books me
          JOIN owners owner ON owner.id = me.owner
        WHERE ( source = ? )
      ) me
    WHERE
      (
        SELECT COUNT(*)
          FROM books rownum__emulation
        WHERE rownum__emulation.title < me.title
      ) < ?
    ORDER BY me.title ASC
  )',
  [
    [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ],
    [ $ROWS => 2 ],
  ],
);

is_deeply (
  [ $rs->get_column ('title')->all ],
  ['Best Recipe Cookbook', 'Dynamical Systems'],
  'Correct columns selected with rows',
);

$schema->storage->_sql_maker->quote_char ('"');
$schema->storage->_sql_maker->name_sep ('.');

$rs = $schema->resultset ('BooksInLibrary')->search ({}, {
  order_by => { -desc => 'title' },
  '+select' => ['owner.name'],
  '+as' => ['owner.name'],
  join => 'owner',
  rows => 3,
  offset => 1,
});

is_same_sql_bind(
  $rs->as_query,
  '(
    SELECT  "me"."id", "me"."source", "me"."owner", "me"."title", "me"."price",
            "owner__name"
      FROM (
        SELECT  "me"."id", "me"."source", "me"."owner", "me"."title", "me"."price",
                "owner"."name" AS "owner__name"
          FROM "books" "me"
          JOIN "owners" "owner" ON "owner"."id" = "me"."owner"
        WHERE ( "source" = ? )
      ) "me"
    WHERE
      (
        SELECT COUNT(*)
          FROM "books" "rownum__emulation"
        WHERE "rownum__emulation"."title" > "me"."title"
      ) BETWEEN ? AND ?
    ORDER BY "me"."title" DESC
  )',
  [
    [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ],
    [ $OFFSET => 1 ],
    [ $TOTAL => 3 ],
  ],
);

is_deeply (
  [ $rs->get_column ('title')->all ],
  [ 'Dynamical Systems', 'Best Recipe Cookbook' ],
  'Correct columns selected with rows',
);

$rs = $schema->resultset ('BooksInLibrary')->search ({}, {
  order_by => 'title',
  'select' => ['owner.name'],
  'as' => ['owner_name'],
  join => 'owner',
  offset => 1,
});

is_same_sql_bind(
  $rs->as_query,
  '(
    SELECT "owner_name"
      FROM (
        SELECT "owner"."name" AS "owner_name", "me"."title"
          FROM "books" "me"
          JOIN "owners" "owner" ON "owner"."id" = "me"."owner"
        WHERE ( "source" = ? )
      ) "me"
    WHERE
      (
        SELECT COUNT(*)
          FROM "books" "rownum__emulation"
        WHERE "rownum__emulation"."title" < "me"."title"
      ) BETWEEN ? AND ?
    ORDER BY "me"."title" ASC
  )',
  [
    [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'source' } => 'Library' ],
    [ $OFFSET => 1 ],
    [ $TOTAL => 2147483647 ],
  ],
);

is_deeply (
  [ $rs->get_column ('owner_name')->all ],
  [ ('Newton') x 2 ],
  'Correct columns selected with rows',
);

$rs = $schema->resultset('CD')->search({}, {
  columns => [qw( me.cdid me.title me.genreid me.year tracks.position tracks.title )],
  join => 'tracks',
  collapse => 1,
  order_by => [ { -asc => 'me.genreid' }, { -desc => 'year' }, 'me.title', \ 'single_track DESC', { -desc => [qw( me.cdid tracks.position )] } ],
});

my @full_res = @{$rs->all_hri};

is (@full_res, 5, 'Expected amount of CDs');

is_deeply (
  \@full_res,
  [
    { cdid => 2, genreid => undef, title => "Forkful of bees", year => 2001, tracks => [
      { position => 3, title => "Sticky Honey" },
      { position => 2, title => "Stripy" },
      { position => 1, title => "Stung with Success" },
    ] },
    { cdid => 4, genreid => undef, title => "Generic Manufactured Singles", year => 2001, tracks => [
      { position => 3, title => "No More Ideas" },
      { position => 2, title => "Boring Song" },
      { position => 1, title => "Boring Name" },
    ] },
    { cdid => 5, genreid => undef, title => "Come Be Depressed With Us", year => 1998, tracks => [
      { position => 3, title => "Suicidal" },
      { position => 2, title => "Under The Weather" },
      { position => 1, title => "Sad" },
    ] },
    { cdid => 3, genreid => undef, title => "Caterwaulin' Blues", year => 1997, tracks => [
      { position => 3, title => "Fowlin" },
      { position => 2, title => "Howlin" },
      { position => 1, title => "Yowlin" },
    ] },
    { cdid => 1, genreid => 1, title => "Spoonful of bees", year => 1999, tracks => [
      { position => 3, title => "Beehind You" },
      { position => 2, title => "Apiary" },
      { position => 1, title => "The Bees Knees" },
    ] },
  ],
  'Complex ordered gensubq limited cds and tracks in expected sqlite order'
);

for my $slice (
  [0, 10],
  [3, 5 ],
  [4, 6 ],
  [0, 2 ],
  [1, 3 ],
) {

  my $rownum_cmp_op = $slice->[0]
    ? 'BETWEEN ? AND ?'
    : ' < ?'
  ;

{
  local $TODO = "Temporary workaround until fix of https://twitter.com/dbix_class/status/957271153751527424 proliferates";

  is_deeply(
    $rs->slice(@$slice)->all_hri,
    [ @full_res[ $slice->[0] .. min($#full_res, $slice->[1]) ] ],
    "Expected array slice on complex ordered limited gensubq ($slice->[0] : $slice->[1])",
  );
}

  is_same_sql_bind(
    $rs->slice(@$slice)->as_query,
    qq{(
      SELECT  "me"."cdid", "me"."title", "me"."genreid", "me"."year",
              "tracks"."position", "tracks"."title"
        FROM (
          SELECT "me"."cdid", "me"."title", "me"."genreid", "me"."year", "me"."single_track"
            FROM (
              SELECT "me"."cdid", "me"."title", "me"."genreid", "me"."year", "me"."single_track"
                FROM cd "me"
                LEFT JOIN "track" "tracks"
                  ON "tracks"."cd" = "me"."cdid"
              GROUP BY "me"."cdid", "me"."title", "me"."genreid", "me"."year", "me"."single_track"
             ) "me"
          WHERE (
            SELECT COUNT( * )
              FROM cd "rownum__emulation"
            WHERE (
              ( "me"."genreid" IS NOT NULL AND "rownum__emulation"."genreid" IS NULL )
                OR
              (
                "rownum__emulation"."genreid" < "me"."genreid"
                  AND
                "me"."genreid" IS NOT NULL
                  AND
                "rownum__emulation"."genreid" IS NOT NULL
              )
                OR
              (
                (
                  "me"."genreid" = "rownum__emulation"."genreid"
                    OR
                  ( "me"."genreid" IS NULL AND "rownum__emulation"."genreid" IS NULL )
                )
                  AND
                "rownum__emulation"."year" > "me"."year"
              )
                OR
              (
                (
                  "me"."genreid" = "rownum__emulation"."genreid"
                    OR
                  ( "me"."genreid" IS NULL AND "rownum__emulation"."genreid" IS NULL )
                )
                  AND
                "me"."year" = "rownum__emulation"."year"
                  AND
                "rownum__emulation"."title" < "me"."title"
              )
                OR
              (
                (
                  "me"."genreid" = "rownum__emulation"."genreid"
                    OR
                  ( "me"."genreid" IS NULL AND "rownum__emulation"."genreid" IS NULL )
                )
                  AND
                "me"."year" = "rownum__emulation"."year"
                  AND
                "me"."title" = "rownum__emulation"."title"
                  AND
                (
                  ("me"."single_track" IS NULL AND "rownum__emulation"."single_track" IS NOT NULL )
                    OR
                  (
                    "rownum__emulation"."single_track" > "me"."single_track"
                      AND
                    "me"."single_track" IS NOT NULL
                      AND
                    "rownum__emulation"."single_track" IS NOT NULL
                  )
                )
              )
                OR
              (
                (
                  "me"."genreid" = "rownum__emulation"."genreid"
                    OR
                  ( "me"."genreid" IS NULL AND "rownum__emulation"."genreid" IS NULL )
                )
                AND
                "me"."year" = "rownum__emulation"."year"
                  AND
                "me"."title" = "rownum__emulation"."title"
                  AND
                (
                  ( "me"."single_track" = "rownum__emulation"."single_track" )
                    OR
                  ( "me"."single_track" IS NULL AND "rownum__emulation"."single_track" IS NULL )
                )
                  AND
                "rownum__emulation"."cdid" > "me"."cdid"
              )
            )
          ) $rownum_cmp_op
          ORDER BY "me"."genreid" ASC, "me"."year" DESC, "me"."title" ASC, "me"."single_track" DESC, "me"."cdid" DESC
        ) "me"
        LEFT JOIN "track" "tracks"
          ON "tracks"."cd" = "me"."cdid"
      ORDER BY "me"."genreid" ASC, "year" DESC, "me"."title", single_track DESC, "me"."cdid" DESC, "tracks"."position" DESC
    )},
    [
      ( $slice->[0] ? [ $OFFSET => $slice->[0] ] : () ),
      [ $TOTAL => $slice->[1] + ($slice->[0] ? 0 : 1 ) ],
    ],
    "Expected sql on complex ordered limited gensubq ($slice->[0] : $slice->[1])",
  );
}

{
  $rs = $schema->resultset('Artist')->search({}, {
    columns => 'artistid',
    offset => 1,
    order_by => 'artistid',
  });
  local $rs->result_source->{name} = "weird \n newline/multi \t \t space containing \n table";

  like (
    ${$rs->as_query}->[0],
    qr| weird \s \n \s newline/multi \s \t \s \t \s space \s containing \s \n \s table|x,
    'Newlines/spaces preserved in final sql',
  );
}

done_testing;