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
|
# test of problems with having (Reported by Mark Rogers)
#
--disable_warnings
drop table if exists t1,t2;
--enable_warnings
create table t1 (a int);
select count(a) as b from t1 where a=0 having b > 0;
insert into t1 values (null);
select count(a) as b from t1 where a=0 having b > 0;
select count(a) as b from t1 where a=0 having b >=0;
explain extended select count(a) as b from t1 where a=0 having b >=0;
drop table t1;
#
# Test of problem with HAVING and AVG()
#
CREATE TABLE t1 (
raw_id int(10) NOT NULL default '0',
chr_start int(10) NOT NULL default '0',
chr_end int(10) NOT NULL default '0',
raw_start int(10) NOT NULL default '0',
raw_end int(10) NOT NULL default '0',
raw_ori int(2) NOT NULL default '0'
);
INSERT INTO t1 VALUES (469713,1,164123,1,164123,1),(317330,164124,317193,101,153170,1),(469434,317194,375620,101,58527,1),(591816,375621,484273,1,108653,1),(591807,484274,534671,91,50488,1),(318885,534672,649362,101,114791,1),(318728,649363,775520,102,126259,1),(336829,775521,813997,101,38577,1),(317740,813998,953227,101,139330,1),(1,813998,953227,101,139330,1);
CREATE TABLE t2 (
id int(10) unsigned NOT NULL default '0',
contig_id int(10) unsigned NOT NULL default '0',
seq_start int(10) NOT NULL default '0',
seq_end int(10) NOT NULL default '0',
strand tinyint(2) NOT NULL default '0',
KEY id (id)
);
INSERT INTO t2 VALUES (133195,469713,61327,61384,1),(133196,469713,64113,64387,1),(133197,1,1,1,0),(133197,1,1,1,-2);
SELECT e.id,
MIN( IF(sgp.raw_ori=1,
(e.seq_start+sgp.chr_start-sgp.raw_start),
(sgp.chr_start+sgp.raw_end-e.seq_end))) as start,
MAX( IF(sgp.raw_ori=1,
(e.seq_end+sgp.chr_start-sgp.raw_start),
(sgp.chr_start+sgp.raw_end-e.seq_start))) as end,
AVG(IF (sgp.raw_ori=1,e.strand,(-e.strand))) as chr_strand
FROM t1 sgp,
t2 e
WHERE sgp.raw_id=e.contig_id
GROUP BY e.id
HAVING chr_strand= -1 and end >= 0
AND start <= 999660;
drop table t1,t2;
#
# Test problem with having and MAX() IS NOT NULL
#
CREATE TABLE t1 (Fld1 int(11) default NULL,Fld2 int(11) default NULL);
INSERT INTO t1 VALUES (1,10),(1,20),(2,NULL),(2,NULL),(3,50);
select Fld1, max(Fld2) as q from t1 group by Fld1 having q is not null;
select Fld1, max(Fld2) from t1 group by Fld1 having max(Fld2) is not null;
select Fld1, max(Fld2) from t1 group by Fld1 having avg(Fld2) is not null;
select Fld1, max(Fld2) from t1 group by Fld1 having std(Fld2) is not null;
select Fld1, max(Fld2) from t1 group by Fld1 having variance(Fld2) is not null;
drop table t1;
#
# Test problem with count(distinct) in having
#
create table t1 (id int not null, qty int not null);
insert into t1 values (1,2),(1,3),(2,4),(2,5);
select id, sum(qty) as sqty from t1 group by id having sqty>2;
select sum(qty) as sqty from t1 group by id having count(id) > 0;
select sum(qty) as sqty from t1 group by id having count(distinct id) > 0;
drop table t1;
#
# Test case for Bug #4358 Problem with HAVING clause that uses alias from the
# select list and TEXT field
#
CREATE TABLE t1 (
`id` bigint(20) NOT NULL default '0',
`description` text
) ENGINE=MyISAM;
CREATE TABLE t2 (
`id` bigint(20) NOT NULL default '0',
`description` varchar(20)
) ENGINE=MyISAM;
INSERT INTO t1 VALUES (1, 'test');
INSERT INTO t2 VALUES (1, 'test');
CREATE TABLE t3 (
`id` bigint(20) NOT NULL default '0',
`order_id` bigint(20) NOT NULL default '0'
) ENGINE=MyISAM;
select
a.id, a.description,
count(b.id) as c
from t1 a left join t3 b on a.id=b.order_id
group by a.id, a.description
having (a.description is not null) and (c=0);
select
a.*,
count(b.id) as c
from t2 a left join t3 b on a.id=b.order_id
group by a.id, a.description
having (a.description is not null) and (c=0);
INSERT INTO t1 VALUES (2, 'test2');
select
a.id, a.description,
count(b.id) as c
from t1 a left join t3 b on a.id=b.order_id
group by a.id, a.description
having (a.description is not null) and (c=0);
drop table t1,t2,t3;
#
# Tests for WL#1972 CORRECT EVALUATION OF COLUMN REFERENCES IN THE HAVING CLAUSE
# Per the SAP VERI tests and WL#1972, MySQL must ensure that HAVING can
# correctly evaluate column references from the GROUP BY clause, even if the
# same references are not also found in the select list.
#
# set global sql_mode='ansi';
# set session sql_mode='ansi';
--disable_warnings
drop table if exists wl1972;
--enable_warnings
create table wl1972 (
col1 int,
col2 varchar(5) character set latin1 collate latin1_bin)
engine=innodb;
insert into wl1972 values(10,'hello');
insert into wl1972 values(20,'hello');
insert into wl1972 values(30,'hello');
insert into wl1972 values(10,'bye');
insert into wl1972 values(10,'sam');
insert into wl1972 values(10,'bob');
select count(*) from wl1972 group by col1 having col1 = 10;
select count(*) as count_col1 from wl1972 group by col1 having col1 = 10;
select count(*) as count_col1 from wl1972 as t1 group by col1 having col1 = 10;
select count(*) from wl1972 group by col2 having col2 = 'hello';
--error 1054
select count(*) from wl1972 group by col2 having col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by col1 having col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by col1 having count_col1 = 10;
select col1 as count_col1 from wl1972 as t1 group by count_col1 having col1 = 10;
# ANSI: should return SQLSTATE 42000 Syntax error or access violation
# MySQL: returns 10 - because of GROUP BY name resolution
select col1 as count_col1 from wl1972 as t1 group by count_col1 having count_col1 = 10;
# ANSI: should return SQLSTATE 42000 Syntax error or access violation
# MySQL: returns 10 - because of GROUP BY name resolution
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col1 = 10;
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having count_col1 = 10;
select col1 as count_col1,col2 from wl1972 as t1 group by col1,col2 having col2 = 'hello';
select col1 as count_col1,col2 as group_col2 from wl1972 as t1
group by col1,col2 having group_col2 = 'hello';
--error 1064
select sum(col1) as co12 from wl1972 group by col2 having col2 10;
select sum(col1) as co2, count(col2) as cc from wl1972 group by col1 having col1 =10;
select t1.col1 from wl1972 as t1 where t1.col2 in
(select t2.col2 from wl1972 as t2
group by t2.col1,t2.col2 having t2.col1<=10);
select t1.col1 from wl1972 as t1 where t1.col2 in
(select t2.col2 from wl1972 as t2
group by t2.col1,t2.col2 having t2.col1<=
(select min(t3.col1) from wl1972 as t3));
drop table wl1972;
# More queries to test ANSI compatibility
create table wl1972 (s1 int);
insert into wl1972 values (1),(2),(3);
select count(*) from wl1972 group by s1 having s1 is null;
select s1*0 as s1 from wl1972 group by s1 having s1 <> 0;
# ANSI requires: 3 rows
# MySQL returns: 0 rows - because of GROUP BY name resolution
select s1*0 from wl1972 group by s1 having s1 = 0;
select s1 from wl1972 group by 1 having 1 = 0;
select count(s1) from wl1972 group by s1 having count(1+1)=2;
# ANSI requires: 3 rows
# MySQL returns: 0 rows - because of GROUP BY name resolution
select count(s1) from wl1972 group by s1 having s1*0=0;
-- error 1052
select * from wl1972 a, wl1972 b group by a.s1 having s1 is null;
# ANSI requires: 0 rows
# MySQL returns:
# "ERROR 1052 (23000): Column 's1' in having clause is ambiguous"
# I think the column is ambiguous in ANSI too.
# It is the same as:
# select a.s1, b.s1 from wl1972 a, wl1972 b group by a.s1 having s1 is null;
# currently we first check SELECT, thus s1 is ambiguous.
drop table wl1972;
create table wl1972 (s1 char character set latin1 collate latin1_german1_ci);
insert into wl1972 values ('ΓΌ'),('y');
select s1,count(s1) from wl1972
group by s1 collate latin1_swedish_ci having s1 = 'y';
# ANSI requires: 1 row, with count(s1) = 2
# MySQL returns: 1 row, with count(s1) = 1
drop table wl1972;
|