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