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 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363
|
--source include/have_partition.inc
--source include/have_sequence.inc
#
# MDEV-8320: Allow index usage for DATE(datetime_column) = const
#
--disable_warnings
drop table if exists t0,t1,t2,t3;
--enable_warnings
create table t0(a int);
insert into t0 values (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
create table t1(a int);
insert into t1 select A.a + B.a* 10 from t0 A, t0 B;
create table t2 (pk int primary key, a datetime, b date, key(a), key(b));
insert into t2
select
A.a*10+B.a,
date_add(date_add('2017-01-01', interval A.a*8 day), interval B.a hour),
date_add('2017-01-01', interval A.a*7 day)
from t1 A, t0 B;
analyze table t2;
--echo #
--echo # "YEAR(datetime_col) CMP year_value", basic checks
--echo #
let $q= select count(*) from t2 where year(a) < 2018;
eval $q;
--echo # Compare the results, they must be equal:
select count(*) from t2 where a < '2018-01-01';
eval explain format=json $q;
--echo # Check rewrite for a prepared statement:
execute immediate
"explain format=json select * from t2 where year(a) < ?"
using 2018;
eval prepare stmt from "$q";
execute stmt;
execute stmt;
eval create or replace view v1 as $q;
select * from v1;
eval create or replace procedure sp() $q;
call sp();
call sp();
--echo # Prepared statement with a placeholder
prepare stmt from "select count(*) from t2 where year(a) < ?";
execute stmt using 2018;
execute stmt using 2017;
let $q= select count(*) from t2 where year(a) <= 2018;
eval $q;
select count(*) from t2 where a < '2019-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where year(a) > 2018;
eval $q;
select count(*) from t2 where a > '2018-12-31 23:59:59.999999';
eval explain format=json $q;
let $q= select count(*) from t2 where year(a) >= 2018;
eval $q;
select count(*) from t2 where a >= '2018-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where year(a) = 2017;
eval $q;
select count(*) from t2 where a >= '2017-01-01' and a < '2018-01-01';
eval explain format=json $q;
--echo #
--echo # "YEAR(datetime_col) CMP year_value", reverse argument order
--echo #
let $q= select count(*) from t2 where 2017 < year(a);
eval $q;
select count(*) from t2 where a >= '2018-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where 2018 <= year(a);
select count(*) from t2 where a >= '2018-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where 2018 > year(a);
eval $q;
select count(*) from t2 where a < '2018-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where 2018 >= year(a);
select count(*) from t2 where a < '2019-01-01';
eval explain format=json $q;
let $q= select count(*) from t2 where 2018 = year(a);
eval $q;
select count(*) from t2 where a >= '2018-01-01' and a < '2019-01-01';
eval explain format=json $q;
--echo #
--echo # "DATE(datetime_col) CMP date_value", basic checks
--echo #
let $q= select count(*) from t2 where date(a) < '2017-06-01';
eval $q;
select count(*) from t2 where a < '2017-06-01';
eval explain format=json $q;
let $q= select count(*) from t2 where date(a) <= '2017-06-03';
eval $q;
select count(*) from t2 where a < '2017-06-04';
eval explain format=json $q;
let $q= select count(*) from t2 where date(a) > '2018-06-01';
eval $q;
select count(*) from t2 where a >= '2018-06-02';
eval explain format=json $q;
let $q= select count(*) from t2 where date(a) >= '2018-06-01';
eval $q;
select count(*) from t2 where a >= '2018-06-01';
eval explain format=json $q;
let $q= select count(*) from t2 where date(a) = '2017-06-02';
eval $q;
select count(*) from t2 where a >= '2017-06-02' and a < '2017-06-03';
eval explain format=json $q;
--echo #
--echo # "DATE(datetime_col) CMP date_value", reverse order
--echo #
let $q= select count(*) from t2 where '2017-06-01' > date(a);
eval $q;
select count(*) from t2 where '2017-06-01' > a;
eval explain format=json $q;
let $q= select count(*) from t2 where '2017-06-03' >= date(a);
eval $q;
select count(*) from t2 where '2017-06-03' >= a;
eval explain format=json $q;
let $q= select count(*) from t2 where '2018-06-01' < date(a);
eval $q;
select count(*) from t2 where '2018-06-02' <= a;
eval explain format=json $q;
let $q= select count(*) from t2 where '2018-06-01' <= date(a);
eval $q;
select count(*) from t2 where '2018-06-01' <= a;
eval explain format=json $q;
let $q= select count(*) from t2 where '2017-06-02' = date(a);
eval $q;
select count(*) from t2 where a >= '2017-06-02' and a < '2017-06-03';
eval explain format=json $q;
--echo # Check rewrite of a more complicated query
explain format=json select * from t2 as t21 force index(a),
t2 as t22 force index(a)
where year(t21.a) < 2018 and t21.b > '2017-11-01'
and date(t22.a) >= '2017-02-01' and t22.b > '2017-11-01';
--echo #
--echo # Incorrect const values processing (no rewrite is possible)
--echo #
explain format=json select * from t2 where year(a) = -1;
explain format=json select * from t2 where year(a) > -5;
explain format=json select * from t2 where year(a) < -1;
explain format=json select * from t2 where year(a) <= 10000;
explain format=json select * from t2 where year(a) >= 10020;
explain format=json select * from t2 where date(a) = '10000-01-01';
explain format=json select * from t2 where date(a) < '-1-01-01';
--echo #
--echo # Try DATE function and DATE (not DATETIME) column:
--echo #
let $q= select count(*) from t2 where date(b)< '2017-06-03';
eval $q;
select count(*) from t2 where b < '2017-06-03';
eval explain format=json $q;
let $q= select count(*) from t2 where date(b)= '2017-06-04';
eval $q;
select count(*) from t2 where b >= '2017-06-04' and b < '2017-06-05';
eval explain format=json $q;
--echo #
--echo # Check actual query results
--echo #
insert into t2 values (10001,'2006-12-31 23:59:59','2006-12-31');
insert into t2 values (10002,'2007-01-01 00:00:00','2007-01-01');
insert into t2 values (10003,'2007-12-31 23:59:59','2007-12-31');
insert into t2 values (10004,'2008-01-01 00:00:00','2008-01-01');
explain format=json
select * from t2 force index(b) where year(b)=2007;
select * from t2 force index(b) where year(b)=2007;
insert into t2 values (10010,'2006-12-31 00:00:00','2006-12-31');
insert into t2 values (10011,'2006-12-30 23:59:59','2006-12-30');
explain format=json
select * from t2 force index(a) where date(a)='2006-12-31';
select * from t2 force index(a) where date(a)='2006-12-31';
--echo #
--echo # Test the TIMESTAMP column
--echo #
create table t3 (a timestamp, b date, key(a));
--echo # Insert data starting from 2016 since that year had a leap second
--echo # (https://en.wikipedia.org/wiki/Leap_second)
set time_zone="UTC"; # To make sure we avoid daylight saving time shifts
insert into t3
select
timestampadd(hour, B.a, date_add('2016-01-01', interval A.a*8 day)),
date_add('2016-01-01', interval A.a*7 day)
from t1 A, t0 B;
--echo # Results of those two queries must be equal:
let $q= select count(*) from t3 force index(a) where year(a)= 2016;
eval $q;
--echo # The result must be the same as this query's:
select count(*) from t3 force index(a) where a >= '2016-01-01 00:00:00'
and a <= '2016-12-31 23:59:59.999999';
explain format=json
select count(*) from t3 force index(a) where year(a)= 2016;
set time_zone= @@global.time_zone;
--echo #
--echo # Incorrect const values processing (no rewrite is possible)
--echo #
explain format=json select * from t2 where year(a) = -1;
explain format=json select * from t2 where year(a) > -5;
explain format=json select * from t2 where year(a) < -1;
explain format=json select * from t2 where year(a) <= 10000;
explain format=json select * from t2 where year(a) >= 10020;
explain format=json select * from t2 where date(a) = '10000-01-01';
explain format=json select * from t2 where date(a) < '-1-01-01';
--echo #
--echo # Composite indexes
--echo #
create table t4 (a datetime, b int, key(a, b)) ;
insert into t4 values ('2009-11-29 13:43:32', 2);
insert into t4 values ('2009-10-15 12:15:11', 2);
insert into t4 values ('2009-09-01 15:55:00', 3);
insert into t4 values ('2009-08-23 12:07:47', 4);
explain format=json select * from t4 where year(a) = 2009;
explain format=json select * from t4 where year(a) >= 2009;
explain format=json select * from t4 where year(a) < 2018;
explain format=json select * from t4 where date(a) = '2009-12-01';
explain format=json select * from t4 where b = 2 and year(a) = 2009;
explain format=json select * from t4 where b = 10 and year(a) > 2001;
explain format=json select * from t4 where b = 2 and date(a) = '2009-11-02';
--echo # Reverse order of fields in the index
create table t5 (a datetime, b int, c varchar(20), key(b, a));
insert into t5 values ('2009-11-29 13:43:32', 2, 'abc');
insert into t5 values ('2009-10-15 12:15:11', 2, 'def');
insert into t5 values ('2009-09-01 15:55:00', 3, 'gfd');
insert into t5 values ('2009-08-23 12:07:47', 4, 'xyz');
explain format=json select * from t5 where year(a) = 2009;
explain format=json select * from t4 where date(a) = '2009-12-01';
explain format=json select * from t5 where b = 2 and year(a) = 2009;
explain format=json select * from t5 where b = 10 and year(a) > 2001;
explain format=json select * from t5 where b = 3 and date(a) > '2009-09-01';
--echo #
--echo # No rewrite for a non-indexed column
--echo #
create table t6 (a datetime);
insert into t6 values ('2009-11-29 13:43:32');
insert into t6 values ('2009-10-15 12:15:11');
insert into t6 values ('2009-09-01 15:55:00');
insert into t6 values ('2009-08-23 12:07:47');
explain format=json select * from t6 where year(a) = 2009;
explain format=json select * from t6 where date(a) = '2009-12-01';
drop table t0,t1,t2,t3,t4,t5,t6;
drop view v1;
drop procedure sp;
--echo #
--echo # MDEV-30946 Index usage for DATE(datetime_column) = const
--echo # does not work for DELETE and UPDATE
--echo #
create table t1 (pk int primary key, a datetime, c int, key(a));
insert into t1 (pk,a,c) values (1,'2009-11-29 13:43:32', 2);
insert into t1 (pk,a,c) values (2,'2009-11-29 03:23:32', 2);
insert into t1 (pk,a,c) values (3,'2009-10-16 05:56:32', 2);
insert into t1 (pk,a,c) values (4,'2010-11-29 13:43:32', 2);
insert into t1 (pk,a,c) values (5,'2010-10-16 05:56:32', 2);
insert into t1 (pk,a,c) values (6,'2011-11-29 13:43:32', 2);
insert into t1 (pk,a,c) values (7,'2012-10-16 05:56:32', 2);
--echo # YEAR() conditions, UPDATE
explain format=json update t1 set c = 0 where year(a) = 2010;
update t1 set c = 0 where year(a) = 2010;
select * from t1;
explain format=json update t1 set c = 1
where c < (select count(*) from t1 where year(a) = 2010);
explain format=json update t1 set c = 0
where year(a) = 2010 and c < (select count(*) from t1 where year(a) = 2010);
--echo # Multi-table update
create table t2 (a int);
insert into t2 values (4),(5),(6);
explain format=json update t1, t2 set c = 0
where year(t1.a) = 2010 and t1.c = t2.a;
prepare stmt from "update t1 set c = 0 where year(a) = 2010";
execute stmt;
execute stmt;
--echo # YEAR() conditions, DELETE
explain format=json delete from t1 where year(a) = 2010;
delete from t1 where year(a) = 2010;
select * from t1;
explain format=json delete from t1
where c < (select count(*) from t1 where year(a) = 2010);
delete from t1 where c < (select count(*) from t1 where year(a) = 2010);
prepare stmt from "delete from t1 where year(a) = 2009";
execute stmt;
execute stmt;
select * from t1;
--echo # DATE() conditions, UPDATE
explain format=json update t1 set c = 0 where date(a) = '2010-10-16';
explain format=json update t1 set c = 0 where date(a) <= '2011-10-16';
prepare stmt from "update t1 set c = 3 where date(a) = '2011-11-29'";
execute stmt;
execute stmt;
select * from t1;
--echo # DATE() conditions, DELETE
explain format=json delete from t1 where date(a) = '2010-10-16';
explain format=json delete from t1 where date(a) <= '2011-10-16';
prepare stmt from "delete from t1 where date(a) <= '2012-01-01'";
execute stmt;
execute stmt;
select * from t1;
--echo # Test partition pruning
create table t3 (
a datetime,
key(a)
) partition by range(year(a)) (
partition p0 values less than (2022),
partition p1 values less than (MAXVALUE)
);
insert into t3
select date_add('2020-01-01', interval seq*10 day)
from seq_1_to_100;
--echo # Must be only "p0" partition
explain partitions select * from t3 where year(a) = 2020;
explain partitions delete from t3 where year(a) = 2020;
explain partitions update t3 set a = a + 1 where year(a) = 2020;
drop tables t1,t2,t3;
|