Parameterize pagination
[dbsrgits/DBIx-Class.git] / t / prefetch / grouped.t
CommitLineData
0c5ea449 1use strict;
2use warnings;
6841b059 3
0c5ea449 4use Test::More;
6841b059 5use Test::Exception;
0c5ea449 6
7use lib qw(t/lib);
8use DBICTest;
9use DBIC::SqlMakerTest;
fcb7fcbb 10use DBIx::Class::SQLMaker::LimitDialects;
11
12my $ROWS = DBIx::Class::SQLMaker::LimitDialects->__rows_bindtype;
0c5ea449 13
0c5ea449 14my $schema = DBICTest->init_schema();
a2287768 15my $sdebug = $schema->storage->debug;
0c5ea449 16
17my $cd_rs = $schema->resultset('CD')->search (
18 { 'tracks.cd' => { '!=', undef } },
19 { prefetch => 'tracks' },
20);
21
22# Database sanity check
23is($cd_rs->count, 5, 'CDs with tracks count');
24for ($cd_rs->all) {
25 is ($_->tracks->count, 3, '3 tracks for CD' . $_->id );
26}
27
28# Test a belongs_to prefetch of a has_many
29{
30 my $track_rs = $schema->resultset ('Track')->search (
31 { 'me.cd' => { -in => [ $cd_rs->get_column ('cdid')->all ] } },
32 {
0c5ea449 33 select => [
34 'me.cd',
0c5ea449 35 { count => 'me.trackid' },
36 ],
37 as => [qw/
38 cd
39 track_count
0c5ea449 40 /],
41 group_by => [qw/me.cd/],
42 prefetch => 'cd',
43 },
44 );
45
22ed9526 46 # this used to fuck up ->all, do not remove!
47 ok ($track_rs->first, 'There is stuff in the rs');
48
0c5ea449 49 is($track_rs->count, 5, 'Prefetched count with groupby');
50 is($track_rs->all, 5, 'Prefetched objects with groupby');
51
52 {
53 my $query_cnt = 0;
54 $schema->storage->debugcb ( sub { $query_cnt++ } );
a2287768 55 $schema->storage->debug (1);
0c5ea449 56
0c5ea449 57 while (my $collapsed_track = $track_rs->next) {
0c5ea449 58 my $cdid = $collapsed_track->get_column('cd');
59 is($collapsed_track->get_column('track_count'), 3, "Correct count of tracks for CD $cdid" );
60 ok($collapsed_track->cd->title, "Prefetched title for CD $cdid" );
61 }
62
22ed9526 63 is ($query_cnt, 1, 'Single query on prefetched titles');
0c5ea449 64 $schema->storage->debugcb (undef);
a2287768 65 $schema->storage->debug ($sdebug);
0c5ea449 66 }
67
68 # Test sql by hand, as the sqlite db will simply paper over
69 # improper group/select combinations
70 #
0c5ea449 71 is_same_sql_bind (
72 $track_rs->count_rs->as_query,
73 '(
74 SELECT COUNT( * )
75 FROM (
76 SELECT me.cd
77 FROM track me
78 JOIN cd cd ON cd.cdid = me.cd
d8dbe471 79 WHERE ( me.cd IN ( ?, ?, ?, ?, ? ) )
0c5ea449 80 GROUP BY me.cd
81 )
336feb8e 82 me
0c5ea449 83 )',
0e773352 84 [ map { [ { sqlt_datatype => 'integer', dbic_colname => 'me.cd' }
85 => $_ ] } ($cd_rs->get_column ('cdid')->all) ],
0c5ea449 86 'count() query generated expected SQL',
87 );
88
0c5ea449 89 is_same_sql_bind (
90 $track_rs->as_query,
91 '(
5b45001f 92 SELECT me.cd, me.track_count, cd.cdid, cd.artist, cd.title, cd.year, cd.genreid, cd.single_track
0c5ea449 93 FROM (
0491b597 94 SELECT me.cd, COUNT (me.trackid) AS track_count
0c5ea449 95 FROM track me
1c1937b7 96 JOIN cd cd ON cd.cdid = me.cd
d8dbe471 97 WHERE ( me.cd IN ( ?, ?, ?, ?, ? ) )
0c5ea449 98 GROUP BY me.cd
0491b597 99 ) me
0c5ea449 100 JOIN cd cd ON cd.cdid = me.cd
d8dbe471 101 WHERE ( me.cd IN ( ?, ?, ?, ?, ? ) )
0c5ea449 102 )',
0e773352 103 [ map { [ { sqlt_datatype => 'integer', dbic_colname => 'me.cd' }
104 => $_ ] } ( ($cd_rs->get_column ('cdid')->all) x 2 ) ],
0c5ea449 105 'next() query generated expected SQL',
106 );
107
108
109 # add an extra track to one of the cds, and then make sure we can get it on top
110 # (check if limit works)
111 my $top_cd = $cd_rs->slice (1,1)->next;
112 $top_cd->create_related ('tracks', {
113 title => 'over the top',
114 });
115
116 my $top_cd_collapsed_track = $track_rs->search ({}, {
117 rows => 2,
118 order_by => [
119 { -desc => 'track_count' },
120 ],
121 });
122
123 is ($top_cd_collapsed_track->count, 2);
124
125 is (
126 $top_cd->title,
127 $top_cd_collapsed_track->first->cd->title,
128 'Correct collapsed track with prefetched CD returned on top'
129 );
130}
131
132# test a has_many/might_have prefetch at the same level
0c5ea449 133# Note that one of the CDs now has 4 tracks instead of 3
134{
dace9819 135 my $most_tracks_rs = $schema->resultset ('CD')->search (
136 {
137 'me.cdid' => { '!=' => undef }, # duh - this is just to test WHERE
138 },
139 {
140 prefetch => [qw/tracks liner_notes/],
50136dd9 141 select => ['me.cdid', { count => 'tracks.trackid' }, { max => 'tracks.trackid', -as => 'maxtr'} ],
142 as => [qw/cdid track_count max_track_id/],
dace9819 143 group_by => 'me.cdid',
50136dd9 144 order_by => [ { -desc => 'track_count' }, { -asc => 'maxtr' } ],
dace9819 145 rows => 2,
146 }
147 );
0c5ea449 148
149 is_same_sql_bind (
150 $most_tracks_rs->count_rs->as_query,
151 '(
152 SELECT COUNT( * )
153 FROM (
154 SELECT me.cdid
155 FROM cd me
dace9819 156 WHERE ( me.cdid IS NOT NULL )
0c5ea449 157 GROUP BY me.cdid
fcb7fcbb 158 LIMIT ?
336feb8e 159 ) me
0c5ea449 160 )',
fcb7fcbb 161 [[$ROWS => 2]],
0c5ea449 162 'count() query generated expected SQL',
163 );
164
165 is_same_sql_bind (
166 $most_tracks_rs->as_query,
167 '(
dc81dba3 168 SELECT me.cdid, me.track_count, me.maxtr,
3d98c75e 169 tracks.trackid, tracks.cd, tracks.position, tracks.title, tracks.last_updated_on, tracks.last_updated_at,
8bc3fbf5 170 liner_notes.liner_id, liner_notes.notes
0c5ea449 171 FROM (
dc81dba3 172 SELECT me.cdid, COUNT( tracks.trackid ) AS track_count, MAX( tracks.trackid ) AS maxtr
0c5ea449 173 FROM cd me
174 LEFT JOIN track tracks ON tracks.cd = me.cdid
dace9819 175 WHERE ( me.cdid IS NOT NULL )
0c5ea449 176 GROUP BY me.cdid
50136dd9 177 ORDER BY track_count DESC, maxtr ASC
fcb7fcbb 178 LIMIT ?
0c5ea449 179 ) me
180 LEFT JOIN track tracks ON tracks.cd = me.cdid
181 LEFT JOIN liner_notes liner_notes ON liner_notes.liner_id = me.cdid
dace9819 182 WHERE ( me.cdid IS NOT NULL )
50136dd9 183 ORDER BY track_count DESC, maxtr ASC, tracks.cd
0c5ea449 184 )',
fcb7fcbb 185 [[$ROWS => 2]],
0c5ea449 186 'next() query generated expected SQL',
187 );
188
189 is ($most_tracks_rs->count, 2, 'Limit works');
190 my $top_cd = $most_tracks_rs->first;
22ed9526 191 is ($top_cd->id, 2, 'Correct cd fetched on top'); # 2 because of the slice(1,1) earlier
0c5ea449 192
193 my $query_cnt = 0;
194 $schema->storage->debugcb ( sub { $query_cnt++ } );
a2287768 195 $schema->storage->debug (1);
0c5ea449 196
197 is ($top_cd->get_column ('track_count'), 4, 'Track count fetched correctly');
198 is ($top_cd->tracks->count, 4, 'Count of prefetched tracks rs still correct');
199 is ($top_cd->tracks->all, 4, 'Number of prefetched track objects still correct');
200 is (
201 $top_cd->liner_notes->notes,
202 'Buy Whiskey!',
203 'Correct liner pre-fetched with top cd',
204 );
205
206 is ($query_cnt, 0, 'No queries executed during prefetched data access');
207 $schema->storage->debugcb (undef);
a2287768 208 $schema->storage->debug ($sdebug);
0c5ea449 209}
f785d72e 210
211# make sure that distinct still works
212{
213 my $rs = $schema->resultset("CD")->search({}, {
214 prefetch => 'tags',
215 order_by => 'cdid',
216 distinct => 1,
217 });
218
219 is_same_sql_bind (
220 $rs->as_query,
221 '(
222 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track,
d59eba65 223 tags.tagid, tags.cd, tags.tag
f785d72e 224 FROM (
225 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
226 FROM cd me
d955e938 227 GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
f785d72e 228 ORDER BY cdid
229 ) me
230 LEFT JOIN tags tags ON tags.cd = me.cdid
231 ORDER BY cdid, tags.cd, tags.tag
232 )',
233 [],
234 'Prefetch + distinct resulted in correct group_by',
235 );
236
237 is ($rs->all, 5, 'Correct number of CD objects');
238 is ($rs->count, 5, 'Correct count of CDs');
239}
6841b059 240
ffad45f5 241# RT 47779, test group_by as a scalar ref
242{
243 my $track_rs = $schema->resultset ('Track')->search (
244 { 'me.cd' => { -in => [ $cd_rs->get_column ('cdid')->all ] } },
245 {
246 select => [
247 'me.cd',
248 { count => 'me.trackid' },
249 ],
250 as => [qw/
251 cd
252 track_count
253 /],
254 group_by => \'SUBSTR(me.cd, 1, 1)',
255 prefetch => 'cd',
256 },
257 );
258
259 is_same_sql_bind (
260 $track_rs->count_rs->as_query,
261 '(
262 SELECT COUNT( * )
263 FROM (
efd7c5e5 264 SELECT SUBSTR(me.cd, 1, 1)
ffad45f5 265 FROM track me
266 JOIN cd cd ON cd.cdid = me.cd
267 WHERE ( me.cd IN ( ?, ?, ?, ?, ? ) )
268 GROUP BY SUBSTR(me.cd, 1, 1)
269 )
336feb8e 270 me
ffad45f5 271 )',
0e773352 272 [ map { [ { sqlt_datatype => 'integer', dbic_colname => 'me.cd' }
273 => $_ ] } ($cd_rs->get_column ('cdid')->all) ],
ffad45f5 274 'count() query generated expected SQL',
275 );
276}
277
8423891f 278{
d8ce00f5 279 my $cd_rs = $schema->resultset('CD')->search({}, {
8423891f 280 distinct => 1,
281 join => [qw/ tracks /],
282 prefetch => [qw/ artist /],
283 });
d8ce00f5 284 is($cd_rs->count, 5, 'complex prefetch + non-prefetching has_many join count correct');
285 is($cd_rs->all, 5, 'complex prefetch + non-prefetching has_many join number of objects correct');
286
7cc643b4 287 # make sure join tracks was thrown out
288 is_same_sql_bind (
289 $cd_rs->as_query,
290 '(
291 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track,
292 artist.artistid, artist.name, artist.rank, artist.charfield
293 FROM (
294 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
295 FROM cd me
296 JOIN artist artist ON artist.artistid = me.artist
297 GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
298 ) me
299 JOIN artist artist ON artist.artistid = me.artist
300 )',
301 [],
302 );
303
304
305
d8ce00f5 306 # try the same as above, but add a condition so the tracks join can not be thrown away
307 my $cd_rs2 = $cd_rs->search ({ 'tracks.title' => { '!=' => 'ugabuganoexist' } });
308 is($cd_rs2->count, 5, 'complex prefetch + non-prefetching restricted has_many join count correct');
309 is($cd_rs2->all, 5, 'complex prefetch + non-prefetching restricted has_many join number of objects correct');
310
311 # the outer group_by seems like a necessary evil, if someone can figure out how to take it away
312 # without breaking compat - be my guest
313 is_same_sql_bind (
314 $cd_rs2->as_query,
315 '(
316 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track,
317 artist.artistid, artist.name, artist.rank, artist.charfield
318 FROM (
319 SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
320 FROM cd me
321 LEFT JOIN track tracks ON tracks.cd = me.cdid
322 JOIN artist artist ON artist.artistid = me.artist
323 WHERE ( tracks.title != ? )
324 GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track
325 ) me
326 LEFT JOIN track tracks ON tracks.cd = me.cdid
327 JOIN artist artist ON artist.artistid = me.artist
328 WHERE ( tracks.title != ? )
329 GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track,
330 artist.artistid, artist.name, artist.rank, artist.charfield
331 )',
0e773352 332 [ map { [ { sqlt_datatype => 'varchar', sqlt_size => 100, dbic_colname => 'tracks.title' }
333 => 'ugabuganoexist' ] } (1,2)
334 ],
d8ce00f5 335 );
8423891f 336}
337
d59eba65 338{
339 my $rs = $schema->resultset('CD')->search({},
340 {
341 '+select' => [{ count => 'tags.tag' }],
342 '+as' => ['test_count'],
343 prefetch => ['tags'],
344 distinct => 1,
345 order_by => {'-asc' => 'tags.tag'},
346 rows => 1
347 }
348 );
349 is_same_sql_bind($rs->as_query, q{
886d0b49 350 (SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, me.test_count, tags.tagid, tags.cd, tags.tag
351 FROM (SELECT me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, COUNT( tags.tag ) AS test_count
d59eba65 352 FROM cd me LEFT JOIN tags tags ON tags.cd = me.cdid
353 GROUP BY me.cdid, me.artist, me.title, me.year, me.genreid, me.single_track, tags.tag
fcb7fcbb 354 ORDER BY tags.tag ASC LIMIT ?)
d59eba65 355 me
886d0b49 356 LEFT JOIN tags tags ON tags.cd = me.cdid
357 ORDER BY tags.tag ASC, tags.cd, tags.tag
358 )
fcb7fcbb 359 }, [[$ROWS => 1]]);
d59eba65 360}
361
6841b059 362done_testing;