Institute a central "load this first in testing" package
[dbsrgits/DBIx-Class.git] / t / count / distinct.t
CommitLineData
c0329273 1BEGIN { do "./t/lib/ANFANG.pm" or die ( $@ || $! ) }
2
2a2ca43f 3use strict;
8273e845 4use warnings;
2a2ca43f 5
6use Test::More;
7655b3c9 7use Test::Exception;
2a2ca43f 8
a5a7bb73 9use DBICTest ':DiffSQL';
2a2ca43f 10
11my $schema = DBICTest->init_schema();
12
2d4f6f0b 13# The tag Blue is assigned to cds 1 2 3 and 5
14# The tag Cheesy is assigned to cds 2 4 and 5
15#
16# This combination should make some interesting group_by's
17#
866557f9 18my $rs;
2d4f6f0b 19my $in_rs = $schema->resultset('Tag')->search({ tag => [ 'Blue', 'Cheesy' ] });
2a2ca43f 20
0d2035db 21for my $get_count (
22 sub { shift->count },
23 sub { my $crs = shift->count_rs; isa_ok ($crs, 'DBIx::Class::ResultSetColumn'); $crs->next }
24) {
25 $rs = $schema->resultset('Tag')->search({ tag => 'Blue' });
26 is($get_count->($rs), 4, 'Count without DISTINCT');
2a2ca43f 27
0d2035db 28 $rs = $schema->resultset('Tag')->search({ tag => [ 'Blue', 'Cheesy' ] }, { group_by => 'tag' });
29 is($get_count->($rs), 2, 'Count with single column group_by');
2a2ca43f 30
0d2035db 31 $rs = $schema->resultset('Tag')->search({ tag => [ 'Blue', 'Cheesy' ] }, { group_by => 'cd' });
32 is($get_count->($rs), 5, 'Count with another single column group_by');
2d4f6f0b 33
0d2035db 34 $rs = $schema->resultset('Tag')->search({ tag => 'Blue' }, { group_by => [ qw/tag cd/ ]});
35 is($get_count->($rs), 4, 'Count with multiple column group_by');
2a2ca43f 36
0d2035db 37 $rs = $schema->resultset('Tag')->search({ tag => 'Blue' }, { distinct => 1 });
38 is($get_count->($rs), 4, 'Count with single column distinct');
0027911c 39
0d2035db 40 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->get_column('tag')->as_query } });
41 is($get_count->($rs), 7, 'Count with IN subquery');
0027911c 42
0d2035db 43 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->get_column('tag')->as_query } }, { group_by => 'tag' });
44 is($get_count->($rs), 2, 'Count with IN subquery with outside group_by');
0027911c 45
0d2035db 46 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->get_column('tag')->as_query } }, { distinct => 1 });
47 is($get_count->($rs), 7, 'Count with IN subquery with outside distinct');
0027911c 48
8273e845 49 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->get_column('tag')->as_query } }, { distinct => 1, select => 'tag' }),
0d2035db 50 is($get_count->($rs), 2, 'Count with IN subquery with outside distinct on a single column');
0027911c 51
0d2035db 52 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->search({}, { group_by => 'tag' })->get_column('tag')->as_query } });
53 is($get_count->($rs), 7, 'Count with IN subquery with single group_by');
2d4f6f0b 54
0d2035db 55 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->search({}, { group_by => 'cd' })->get_column('tag')->as_query } });
56 is($get_count->($rs), 7, 'Count with IN subquery with another single group_by');
0027911c 57
0d2035db 58 $rs = $schema->resultset('Tag')->search({ tag => { -in => $in_rs->search({}, { group_by => [ qw/tag cd/ ] })->get_column('tag')->as_query } });
59 is($get_count->($rs), 7, 'Count with IN subquery with multiple group_by');
0027911c 60
0d2035db 61 $rs = $schema->resultset('Tag')->search({ tag => \"= 'Blue'" });
62 is($get_count->($rs), 4, 'Count without DISTINCT, using literal SQL');
0027911c 63
0d2035db 64 $rs = $schema->resultset('Tag')->search({ tag => \" IN ('Blue', 'Cheesy')" }, { group_by => 'tag' });
65 is($get_count->($rs), 2, 'Count with literal SQL and single group_by');
0027911c 66
0d2035db 67 $rs = $schema->resultset('Tag')->search({ tag => \" IN ('Blue', 'Cheesy')" }, { group_by => 'cd' });
68 is($get_count->($rs), 5, 'Count with literal SQL and another single group_by');
2d4f6f0b 69
0d2035db 70 $rs = $schema->resultset('Tag')->search({ tag => \" IN ('Blue', 'Cheesy')" }, { group_by => [ qw/tag cd/ ] });
71 is($get_count->($rs), 7, 'Count with literal SQL and multiple group_by');
7655b3c9 72
0d2035db 73 $rs = $schema->resultset('Tag')->search({ tag => 'Blue' }, { '+select' => { max => 'tagid' }, distinct => 1 });
74 is($get_count->($rs), 4, 'Count with +select aggreggate');
909a20df 75
4b08a8b9 76 $rs = $schema->resultset('Tag')->search({}, { select => [\'length(me.tag)'], distinct => 1 });
0d2035db 77 is($get_count->($rs), 3, 'Count by distinct function result as select literal');
78}
0814e804 79
04ebc6f4 80throws_ok(
81 sub { my $row = $schema->resultset('Tag')->search({}, { select => { distinct => [qw/tag cd/] } })->first },
df72bc73 82 qr/\Qselect => { distinct => ... } syntax is not supported for multiple columns/,
04ebc6f4 83 'throw on unsupported syntax'
84);
7655b3c9 85
324bc214 86# make sure distinct+func works
87{
88 my $rs = $schema->resultset('Artist')->search(
89 {},
90 {
91 join => 'cds',
92 distinct => 1,
93 '+select' => [ { count => 'cds.cdid', -as => 'amount_of_cds' } ],
94 '+as' => [qw/num_cds/],
95 order_by => { -desc => 'amount_of_cds' },
96 }
97 );
98
99 is_same_sql_bind (
100 $rs->as_query,
101 '(
102 SELECT me.artistid, me.name, me.rank, me.charfield, COUNT( cds.cdid ) AS amount_of_cds
103 FROM artist me LEFT JOIN cd cds ON cds.artist = me.artistid
104 GROUP BY me.artistid, me.name, me.rank, me.charfield
105 ORDER BY amount_of_cds DESC
106 )',
107 [],
108 );
109
110 is ($rs->next->get_column ('num_cds'), 3, 'Function aliased correctly');
111}
112
ff46b7b3 113# and check distinct has_many join count
114{
115 my $rs = $schema->resultset('Artist')->search(
116 { 'cds.title' => { '!=', 'fooooo' } },
117 {
118 join => 'cds',
119 distinct => 1,
120 '+select' => [ { count => 'cds.cdid', -as => 'amount_of_cds' } ],
121 '+as' => [qw/num_cds/],
122 order_by => { -desc => 'amount_of_cds' },
123 }
124 );
125
126 is_same_sql_bind (
127 $rs->as_query,
128 '(
129 SELECT me.artistid, me.name, me.rank, me.charfield, COUNT( cds.cdid ) AS amount_of_cds
130 FROM artist me
131 LEFT JOIN cd cds
132 ON cds.artist = me.artistid
133 WHERE cds.title != ?
134 GROUP BY me.artistid, me.name, me.rank, me.charfield
135 ORDER BY amount_of_cds DESC
136 )',
137 [
138 [{
139 sqlt_datatype => 'varchar',
140 dbic_colname => 'cds.title',
141 sqlt_size => 100,
142 } => 'fooooo' ],
143 ],
144 );
145
146 is_same_sql_bind (
147 $rs->count_rs->as_query,
148 '(
149 SELECT COUNT( * )
150 FROM (
151 SELECT me.artistid, me.name, me.rank, me.charfield
152 FROM artist me
153 LEFT JOIN cd cds
154 ON cds.artist = me.artistid
155 WHERE cds.title != ?
156 GROUP BY me.artistid, me.name, me.rank, me.charfield
157 ) me
158 )',
159 [
160 [{
161 sqlt_datatype => 'varchar',
162 dbic_colname => 'cds.title',
163 sqlt_size => 100,
164 } => 'fooooo' ],
165 ],
166 );
167
168 is ($rs->next->get_column ('num_cds'), 3, 'Function aliased correctly');
169}
170
04ebc6f4 171# These two rely on the database to throw an exception. This might not be the case one day. Please revise.
040fc6ba 172dies_ok(sub { my $count = $schema->resultset('Tag')->search({}, { '+select' => \'tagid AS tag_id', distinct => 1 })->count }, 'expecting to die');
324bc214 173
174done_testing;