From 02da9af32d01fe91dd280361870e703ebaeb3225 Mon Sep 17 00:00:00 2001 From: Maksim Kita Date: Sat, 17 Oct 2020 00:31:29 +0300 Subject: [PATCH] DateTime comparison with date string literal --- docs/en/operations/settings/settings.md | 2 +- docs/en/sql-reference/data-types/date.md | 37 ++++++++- src/IO/ReadHelpers.cpp | 28 +++++-- src/IO/ReadHelpers.h | 30 +++++-- ...e_time_compare_with_date_literal.reference | 80 +++++++++++++++++++ ...23_date_time_compare_with_date_literal.sql | 70 ++++++++++++++++ 6 files changed, 231 insertions(+), 16 deletions(-) create mode 100644 tests/queries/0_stateless/01523_date_time_compare_with_date_literal.reference create mode 100644 tests/queries/0_stateless/01523_date_time_compare_with_date_literal.sql diff --git a/docs/en/operations/settings/settings.md b/docs/en/operations/settings/settings.md index d83f7d6c219..f9c3c8a5d75 100644 --- a/docs/en/operations/settings/settings.md +++ b/docs/en/operations/settings/settings.md @@ -384,7 +384,7 @@ Possible values: - `'basic'` — Use basic parser. - ClickHouse can parse only the basic `YYYY-MM-DD HH:MM:SS` format. For example, `'2019-08-20 10:18:56'`. + ClickHouse can parse only the basic `YYYY-MM-DD HH:MM:SS` or `YYYY-MM-DD` format. For example, `'2019-08-20 10:18:56'` or `2019-08-20`. Default value: `'basic'`. diff --git a/docs/en/sql-reference/data-types/date.md b/docs/en/sql-reference/data-types/date.md index c686a987b2f..886e93f433c 100644 --- a/docs/en/sql-reference/data-types/date.md +++ b/docs/en/sql-reference/data-types/date.md @@ -3,10 +3,45 @@ toc_priority: 47 toc_title: Date --- -# Date {#date} +# Date {#data_type-date} A date. Stored in two bytes as the number of days since 1970-01-01 (unsigned). Allows storing values from just after the beginning of the Unix Epoch to the upper threshold defined by a constant at the compilation stage (currently, this is until the year 2106, but the final fully-supported year is 2105). The date value is stored without the time zone. +## Examples {#examples} + +**1.** Creating a table with a `DateTime`-type column and inserting data into it: + +``` sql +CREATE TABLE dt +( + `timestamp` Date, + `event_id` UInt8 +) +ENGINE = TinyLog; +``` + +``` sql +INSERT INTO dt Values (1546300800, 1), ('2019-01-01', 2); +``` + +``` sql +SELECT * FROM dt; +``` + +``` text +┌──timestamp─┬─event_id─┐ +│ 2019-01-01 │ 1 │ +│ 2019-01-01 │ 2 │ +└────────────┴──────────┘ +``` + +## See Also {#see-also} + +- [Functions for working with dates and times](../../sql-reference/functions/date-time-functions.md) +- [Operators for working with dates and times](../../sql-reference/operators/index.md#operators-datetime) +- [`DateTime` data type](../../sql-reference/data-types/datetime.md) + + [Original article](https://clickhouse.tech/docs/en/data_types/date/) diff --git a/src/IO/ReadHelpers.cpp b/src/IO/ReadHelpers.cpp index bf41de3959a..73ee0dfcd95 100644 --- a/src/IO/ReadHelpers.cpp +++ b/src/IO/ReadHelpers.cpp @@ -817,7 +817,11 @@ ReturnType readDateTimeTextFallback(time_t & datetime, ReadBuffer & buf, const D { static constexpr bool throw_exception = std::is_same_v; + /// YYYY-MM-DD hh:mm:ss static constexpr auto date_time_broken_down_length = 19; + /// YYYY-MM-DD + static constexpr auto date_broken_down_length = 10; + /// unix timestamp max length static constexpr auto unix_timestamp_max_length = 10; char s[date_time_broken_down_length]; @@ -831,12 +835,15 @@ ReturnType readDateTimeTextFallback(time_t & datetime, ReadBuffer & buf, const D ++buf.position(); } - /// 2015-01-01 01:02:03 + /// 2015-01-01 01:02:03 or 2015-01-01 if (s_pos == s + 4 && !buf.eof() && (*buf.position() < '0' || *buf.position() > '9')) { - const size_t remaining_size = date_time_broken_down_length - (s_pos - s); - size_t size = buf.read(s_pos, remaining_size); - if (remaining_size != size) + const auto already_read_length = s_pos - s; + const size_t remaining_date_time_size = date_time_broken_down_length - already_read_length; + const size_t remaining_date_size = date_broken_down_length - already_read_length; + + size_t size = buf.read(s_pos, remaining_date_time_size); + if (size != remaining_date_time_size && size != remaining_date_size) { s_pos[size] = 0; @@ -850,9 +857,16 @@ ReturnType readDateTimeTextFallback(time_t & datetime, ReadBuffer & buf, const D UInt8 month = (s[5] - '0') * 10 + (s[6] - '0'); UInt8 day = (s[8] - '0') * 10 + (s[9] - '0'); - UInt8 hour = (s[11] - '0') * 10 + (s[12] - '0'); - UInt8 minute = (s[14] - '0') * 10 + (s[15] - '0'); - UInt8 second = (s[17] - '0') * 10 + (s[18] - '0'); + UInt8 hour = 0; + UInt8 minute = 0; + UInt8 second = 0; + + if (size == remaining_date_time_size) + { + hour = (s[11] - '0') * 10 + (s[12] - '0'); + minute = (s[14] - '0') * 10 + (s[15] - '0'); + second = (s[17] - '0') * 10 + (s[18] - '0'); + } if (unlikely(year == 0)) datetime = 0; diff --git a/src/IO/ReadHelpers.h b/src/IO/ReadHelpers.h index 9ff1858c723..c79e260bf46 100644 --- a/src/IO/ReadHelpers.h +++ b/src/IO/ReadHelpers.h @@ -700,7 +700,7 @@ UInt128 stringToUUID(const String & str); template ReturnType readDateTimeTextFallback(time_t & datetime, ReadBuffer & buf, const DateLUTImpl & date_lut); -/** In YYYY-MM-DD hh:mm:ss format, according to specified time zone. +/** In YYYY-MM-DD hh:mm:ss or YYYY-MM-DD format, according to specified time zone. * As an exception, also supported parsing of unix timestamp in form of decimal number. */ template @@ -709,12 +709,21 @@ inline ReturnType readDateTimeTextImpl(time_t & datetime, ReadBuffer & buf, cons /** Read 10 characters, that could represent unix timestamp. * Only unix timestamp of 5-10 characters is supported. * Then look at 5th character. If it is a number - treat whole as unix timestamp. - * If it is not a number - then parse datetime in YYYY-MM-DD hh:mm:ss format. + * If it is not a number - then parse datetime in YYYY-MM-DD hh:mm:ss or YYYY-MM-DD format. */ /// Optimistic path, when whole value is in buffer. const char * s = buf.position(); - if (s + 19 <= buf.buffer().end()) + + /// YYYY-MM-DD hh:mm:ss + static constexpr auto DateTimeStringInputSize = 19; + bool optimistic_path_for_date_time_input = s + DateTimeStringInputSize <= buf.buffer().end(); + + /// YYYY-MM-DD + static constexpr auto DateStringInputSize = 10; + bool optimistic_path_for_date_input = s + DateStringInputSize <= buf.buffer().end(); + + if (optimistic_path_for_date_time_input || optimistic_path_for_date_input) { if (s[4] < '0' || s[4] > '9') { @@ -722,16 +731,23 @@ inline ReturnType readDateTimeTextImpl(time_t & datetime, ReadBuffer & buf, cons UInt8 month = (s[5] - '0') * 10 + (s[6] - '0'); UInt8 day = (s[8] - '0') * 10 + (s[9] - '0'); - UInt8 hour = (s[11] - '0') * 10 + (s[12] - '0'); - UInt8 minute = (s[14] - '0') * 10 + (s[15] - '0'); - UInt8 second = (s[17] - '0') * 10 + (s[18] - '0'); + UInt8 hour = 0; + UInt8 minute = 0; + UInt8 second = 0; + + if (optimistic_path_for_date_time_input) + { + hour = (s[11] - '0') * 10 + (s[12] - '0'); + minute = (s[14] - '0') * 10 + (s[15] - '0'); + second = (s[17] - '0') * 10 + (s[18] - '0'); + } if (unlikely(year == 0)) datetime = 0; else datetime = date_lut.makeDateTime(year, month, day, hour, minute, second); - buf.position() += 19; + buf.position() += optimistic_path_for_date_time_input ? DateTimeStringInputSize : DateStringInputSize; return ReturnType(true); } else diff --git a/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.reference b/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.reference new file mode 100644 index 00000000000..aad646c5a79 --- /dev/null +++ b/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.reference @@ -0,0 +1,80 @@ +DateTime +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 + +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 +2020-10-16 00:00:00 + + +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 + +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 + +2020-10-15 00:00:00 +2020-10-15 12:00:00 +2020-10-16 00:00:00 + +DateTime64 +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 + +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + + +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 + +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 + +2020-10-15 00:00:00.000 +2020-10-15 12:00:00.000 +2020-10-16 00:00:00.000 + diff --git a/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.sql b/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.sql new file mode 100644 index 00000000000..5a3aa23bcbf --- /dev/null +++ b/tests/queries/0_stateless/01523_date_time_compare_with_date_literal.sql @@ -0,0 +1,70 @@ +DROP TABLE IF EXISTS test; + +CREATE TABLE test(timestamp DateTime) ENGINE = MergeTree ORDER BY timestamp; + +INSERT INTO test VALUES ('2020-10-15 00:00:00'); +INSERT INTO test VALUES ('2020-10-15 12:00:00'); +INSERT INTO test VALUES ('2020-10-16 00:00:00'); + +SELECT 'DateTime'; +SELECT * FROM test WHERE timestamp != '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp == '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp > '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp >= '2020-10-15' ORDER by timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp < '2020-10-16' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp <= '2020-10-16' ORDER BY timestamp; +SELECT ''; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' != timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' == timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' < timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' <= timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-16' > timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-16' >= timestamp ORDER BY timestamp; +SELECT ''; + +DROP TABLE test; +CREATE TABLE test(timestamp DateTime64) ENGINE = MergeTree ORDER BY timestamp; + +INSERT INTO test VALUES ('2020-10-15 00:00:00'); +INSERT INTO test VALUES ('2020-10-15 12:00:00'); +INSERT INTO test VALUES ('2020-10-16 00:00:00'); + +SELECT 'DateTime64'; +SELECT * FROM test WHERE timestamp != '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp == '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp > '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp >= '2020-10-15' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp < '2020-10-16' ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE timestamp <= '2020-10-16' ORDER BY timestamp; +SELECT ''; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' != timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' == timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' < timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-15' <= timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-16' > timestamp ORDER BY timestamp; +SELECT ''; +SELECT * FROM test WHERE '2020-10-16' >= timestamp ORDER BY timestamp; +SELECT ''; + +DROP TABLE test;