Optimize predicate with toYYYYMM converter

Like toYear(PR #50062), the predicate with toYYYYMM could also be
optimized with its preimage. For example, we could transform the
predicate "toYYYYMM(c) = 202305" to "c >= '2023-05-01' AND c <=
'2023-05-31'", so that the invocation of toYYYYMM is avoided. The
similar transformation also applies to other comparisons.

This commit extends OptimizeDateFilterInPlaceVisitor by having it
recognize the toYYYYMM converter in the WHERE/PREWHERE clauses and
replace it with the above tranformed predicate in-place at the AST
level.
This commit is contained in:
Zhiguo Zhou 2023-05-29 14:31:54 +08:00
parent 3543d95980
commit 3d0f336643
3 changed files with 120 additions and 5 deletions

View File

@ -10,14 +10,37 @@
namespace DB
{
ASTPtr generateOptimizedDateFilterAST(const String & comparator, const String & converter, const String & column, UInt64 year)
ASTPtr generateOptimizedDateFilterAST(const String & comparator, const String & converter, const String & column, UInt64 compare_to)
{
const DateLUTImpl & date_lut = DateLUT::instance();
if (converter != "toYear") return {};
String start_date;
String end_date;
String start_date = date_lut.dateToString(date_lut.makeDayNum(year, 1, 1));
String end_date = date_lut.dateToString(date_lut.makeDayNum(year, 12, 31));
if (converter == "toYear")
{
UInt64 year = compare_to;
start_date = date_lut.dateToString(date_lut.makeDayNum(year, 1, 1));
end_date = date_lut.dateToString(date_lut.makeDayNum(year, 12, 31));
}
else if (converter == "toYYYYMM")
{
UInt64 year = compare_to / 100;
UInt64 month = compare_to % 100;
if (month == 0 || month > 12) return {};
static constexpr UInt8 days_of_month[] = {31, 28, 31, 30, 31, 30, 31, 31, 30, 31, 30, 31};
bool leap_year = (year & 3) == 0 && (year % 100 || (year % 400 == 0 && year));
start_date = date_lut.dateToString(date_lut.makeDayNum(year, month, 1));
end_date = date_lut.dateToString(date_lut.makeDayNum(year, month, days_of_month[month - 1] + (leap_year && month == 2)));
}
else
{
return {};
}
if (comparator == "equals")
{
@ -82,7 +105,7 @@ bool rewritePredicateInPlace(ASTFunction & function, ASTPtr & ast)
{
if (const auto * func = function.arguments->children[i]->as<ASTFunction>(); func)
{
if (func->name == "toYear")
if (func->name == "toYear" || func->name == "toYYYYMM")
{
func_id = i;
}

View File

@ -37,3 +37,72 @@ WHERE ((date1 >= \'1993-01-01\') AND (date1 <= \'1993-12-31\')) AND ((id >= 1) A
SELECT value1
FROM t
WHERE ((id >= 1) AND (id <= 3)) AND ((date1 >= \'1993-01-01\') AND (date1 <= \'1993-12-31\'))
SELECT value1
FROM t
WHERE ((date1 >= \'1900-02-01\') AND (date1 <= \'1900-02-28\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1992-02-01\') AND (date1 <= \'1992-02-29\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'2000-02-01\') AND (date1 <= \'2000-02-29\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (toYYYYMM(date1) = 199300) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-01-01\') AND (date1 <= \'1993-01-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-02-01\') AND (date1 <= \'1993-02-28\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-03-01\') AND (date1 <= \'1993-03-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-04-01\') AND (date1 <= \'1993-04-30\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-05-01\') AND (date1 <= \'1993-05-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-06-01\') AND (date1 <= \'1993-06-30\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-07-01\') AND (date1 <= \'1993-07-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-08-01\') AND (date1 <= \'1993-08-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-09-01\') AND (date1 <= \'1993-09-30\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-10-01\') AND (date1 <= \'1993-10-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-11-01\') AND (date1 <= \'1993-11-30\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1993-12-01\') AND (date1 <= \'1993-12-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (toYYYYMM(date1) = 199313) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 < \'1992-03-01\') OR (date1 > \'1992-03-31\')) AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (date1 < \'1992-03-01\') AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (date1 > \'1992-03-31\') AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (date1 <= \'1992-03-31\') AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE (date1 >= \'1992-03-01\') AND ((id >= 1) AND (id <= 3))
SELECT value1
FROM t
WHERE ((date1 >= \'1992-03-01\') OR ((date1 >= \'1993-01-01\') AND (date1 <= \'1993-12-31\'))) AND ((id >= 1) AND (id <= 3))

View File

@ -13,5 +13,28 @@ EXPLAIN SYNTAX SELECT value1, toYear(date1) as year1 FROM t WHERE year1 = 1993 A
EXPLAIN SYNTAX SELECT value1 FROM t WHERE 1993 > toYear(date1) AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t PREWHERE toYear(date1) = 1993 WHERE id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE id BETWEEN 1 AND 3 HAVING toYear(date1) = 1993;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 190002 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199202 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 200002 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199300 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199301 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199302 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199303 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199304 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199305 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199306 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199307 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199308 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199309 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199310 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199311 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199312 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) = 199313 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) <> 199203 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) < 199203 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) > 199203 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) <= 199203 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE toYYYYMM(date1) >= 199203 AND id BETWEEN 1 AND 3;
EXPLAIN SYNTAX SELECT value1 FROM t WHERE (toYYYYMM(date1) >= 199203 OR toYear(date1) = 1993) AND id BETWEEN 1 AND 3;
DROP TABLE t;