add function toUnixTimestampEx and toUnixTimestamp64Second

This commit is contained in:
zhanglistar 2024-10-12 14:40:55 +08:00
parent 9876841c64
commit 23ca36ab30
8 changed files with 162 additions and 25 deletions

View File

@ -195,7 +195,7 @@ makeDateTime64(year, month, day, hour, minute, second[, precision])
**Returned value**
- A date and time created from the supplied arguments. [DateTime64](../../sql-reference/data-types/datetime64.md).
- A date and time created from the supplied arguments. [DateTime64](../../sql-reference/data-types/datetime64.md).
**Example**
@ -868,6 +868,44 @@ Behavior for
* Functions `toStartOfDay`, `toStartOfHour`, `toStartOfFifteenMinutes`, `toStartOfTenMinutes`, `toStartOfFiveMinutes`, `toStartOfMinute`, `timeSlot` return `DateTime` if their argument is a `Date` or `DateTime`, and they return `DateTime64` if their argument is a `Date32` or `DateTime64`.
:::
## toUnixTimestampEx
Like `toUnixTimestamp`, converts a string, a date or a date with time to the [Unix Timestamp](https://en.wikipedia.org/wiki/Unix_time) in `Int64` representation.
If the function is called with a string, it accepts an optional timezone argument.
**Syntax**
``` sql
toUnixTimestampEx(date)
toUnixTimestampEx(str, [timezone])
```
**Returned value**
- Returns the unix timestamp. [UInt32](../data-types/int-uint.md).
**Example**
``` sql
SELECT
'1969-01-01 00:00:00' AS dt_str,
toUnixTimestamp(dt_str) AS from_str,
toUnixTimestampEx(dt_str) AS ex_str,
toUnixTimestamp(dt_str, 'Asia/Tokyo') AS from_str_tokyo,
toUnixTimestampEx(dt_str, 'Asia/Tokyo') AS ex_str_tokyo,
toUnixTimestamp(toDateTime(dt_str)) AS from_datetime,
toUnixTimestampEx(toDateTime64(dt_str, 0)) AS ex_datetime64
```
Result:
```
┌─dt_str──────────────┬─from_str─┬────ex_str─┬─from_str_tokyo─┬─ex_str_tokyo─┬─from_datetime─┬─ex_datetime64─┐
│ 1969-01-01 00:00:00 │ 0 │ -31564800 │ 0 │ -31568400 │ 0 │ -31564800 │
└─────────────────────┴──────────┴───────────┴────────────────┴──────────────┴───────────────┴───────────────┘
```
## toStartOfYear
Rounds down a date or date with time to the first day of the year. Returns the date as a `Date` object.

View File

@ -122,7 +122,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [Int8](../data-types/int-uint.md), overflow or underflow of the result occurs.
This is not considered an error.
This is not considered an error.
For example: `SELECT toInt8(128) == -128;`.
:::
@ -370,7 +370,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [Int16](../data-types/int-uint.md), overflow or underflow of the result occurs.
This is not considered an error.
This is not considered an error.
For example: `SELECT toInt16(32768) == -32768;`.
:::
@ -618,7 +618,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [Int32](../data-types/int-uint.md), the result over or under flows.
This is not considered an error.
This is not considered an error.
For example: `SELECT toInt32(2147483648) == -2147483648;`
:::
@ -865,7 +865,7 @@ Unsupported types:
:::note
If the input value cannot be represented within the bounds of [Int64](../data-types/int-uint.md), the result over or under flows.
This is not considered an error.
This is not considered an error.
For example: `SELECT toInt64(9223372036854775808) == -9223372036854775808;`
:::
@ -1608,7 +1608,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [UInt8](../data-types/int-uint.md), overflow or underflow of the result occurs.
This is not considered an error.
This is not considered an error.
For example: `SELECT toUInt8(256) == 0;`.
:::
@ -1856,7 +1856,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [UInt16](../data-types/int-uint.md), overflow or underflow of the result occurs.
This is not considered an error.
This is not considered an error.
For example: `SELECT toUInt16(65536) == 0;`.
:::
@ -2104,7 +2104,7 @@ Unsupported arguments:
:::note
If the input value cannot be represented within the bounds of [UInt32](../data-types/int-uint.md), the result over or under flows.
This is not considered an error.
This is not considered an error.
For example: `SELECT toUInt32(4294967296) == 0;`
:::
@ -2353,7 +2353,7 @@ Unsupported types:
:::note
If the input value cannot be represented within the bounds of [UInt64](../data-types/int-uint.md), the result over or under flows.
This is not considered an error.
This is not considered an error.
For example: `SELECT toUInt64(18446744073709551616) == 0;`
:::
@ -3691,8 +3691,8 @@ toDateTime(expr[, time_zone ])
- `time_zone` — Time zone. [String](../data-types/string.md).
:::note
If `expr` is a number, it is interpreted as the number of seconds since the beginning of the Unix Epoch (as Unix timestamp).
If `expr` is a [String](../data-types/string.md), it may be interpreted as a Unix timestamp or as a string representation of date / date with time.
If `expr` is a number, it is interpreted as the number of seconds since the beginning of the Unix Epoch (as Unix timestamp).
If `expr` is a [String](../data-types/string.md), it may be interpreted as a Unix timestamp or as a string representation of date / date with time.
Thus, parsing of short numbers' string representations (up to 4 digits) is explicitly disabled due to ambiguity, e.g. a string `'1999'` may be both a year (an incomplete string representation of Date / DateTime) or a unix timestamp. Longer numeric strings are allowed.
:::
@ -5536,7 +5536,7 @@ Result:
## reinterpretAsUInt256
Performs byte reinterpretation by treating the input value as a value of type UInt256. Unlike [`CAST`](#cast), the function does not attempt to preserve the original value - if the target type is not able to represent the input type, the output is meaningless.
Performs byte reinterpretation by treating the input value as a value of type UInt256. Unlike [`CAST`](#cast), the function does not attempt to preserve the original value - if the target type is not able to represent the input type, the output is meaningless.
**Syntax**
@ -5612,7 +5612,7 @@ Result:
## reinterpretAsInt16
Performs byte reinterpretation by treating the input value as a value of type Int16. Unlike [`CAST`](#cast), the function does not attempt to preserve the original value - if the target type is not able to represent the input type, the output is meaningless.
Performs byte reinterpretation by treating the input value as a value of type Int16. Unlike [`CAST`](#cast), the function does not attempt to preserve the original value - if the target type is not able to represent the input type, the output is meaningless.
**Syntax**
@ -7170,6 +7170,45 @@ Result:
└──────────────────────────────┘
```
## toUnixTimestamp64Second
Converts a `DateTime64` to a `Int64` value with fixed second precision. The input value is scaled up or down appropriately depending on its precision.
:::note
The output value is a timestamp in UTC, not in the timezone of `DateTime64`.
:::
**Syntax**
```sql
toUnixTimestamp64Second(value)
```
**Arguments**
- `value` — DateTime64 value with any precision. [DateTime64](../data-types/datetime64.md).
**Returned value**
- `value` converted to the `Int64` data type. [Int64](../data-types/int-uint.md).
**Example**
Query:
```sql
WITH toDateTime64('2009-02-13 23:31:31.011', 3, 'UTC') AS dt64
SELECT toUnixTimestamp64Second(dt64);
```
Result:
```response
┌─toUnixTimestamp64Second(dt64)─┐
│ 1234567891 │
└───────────────────────────────┘
```
## toUnixTimestamp64Micro
Converts a `DateTime64` to a `Int64` value with fixed microsecond precision. The input value is scaled up or down appropriately depending on its precision.

View File

@ -1150,6 +1150,9 @@ struct ConvertThroughParsing
/// Function toUnixTimestamp has exactly the same implementation as toDateTime of String type.
struct NameToUnixTimestamp { static constexpr auto name = "toUnixTimestamp"; };
/// Function toUnixTimestampEx has exactly the same implementation as toDateTime of String type.
struct NameToUnixTimestampEx { static constexpr auto name = "toUnixTimestampEx"; };
enum class BehaviourOnErrorFromString : uint8_t
{
ConvertDefaultBehaviorTag,
@ -1559,6 +1562,17 @@ struct ConvertImpl
return ConvertImpl<FromDataType, DataTypeDateTime, Name, date_time_overflow_behavior>::template execute<Additions>(
arguments, result_type, input_rows_count, from_string_tag);
}
else if constexpr (std::is_same_v<Name, NameToUnixTimestampEx>
&& std::is_same_v<FromDataType, DataTypeString>
&& std::is_same_v<ToDataType, DataTypeInt64>)
{
/// Convert String to DateTime64
ColumnPtr res = ConvertImpl<FromDataType, DataTypeDateTime64, Name, date_time_overflow_behavior>::template execute<UInt32>(
arguments, result_type, input_rows_count, from_string_tag, 0);
/// Convert DateTime64 to Int64
return ConvertImpl<DataTypeDateTime64, ToDataType, Name, date_time_overflow_behavior>::template execute<Additions>(
ColumnsWithTypeAndName{{res, result_type, arguments[0].name}}, result_type, input_rows_count, from_string_tag);
}
else if constexpr ((std::is_same_v<FromDataType, DataTypeString> || std::is_same_v<FromDataType, DataTypeFixedString>))
{
switch (from_string_tag)
@ -1813,6 +1827,11 @@ struct ConvertImpl
{
vec_to[i] = static_cast<ToFieldType>(vec_from[i] * DATE_SECONDS_PER_DAY);
}
else if constexpr (std::is_same_v<Name, NameToUnixTimestampEx>
&& (std::is_same_v<FromDataType, DataTypeDate> || std::is_same_v<FromDataType, DataTypeDate32>))
{
vec_to[i] = static_cast<ToFieldType>(vec_from[i] * DATE_SECONDS_PER_DAY);
}
else
{
/// If From Data is Nan or Inf and we convert to integer type, throw exception
@ -2080,6 +2099,8 @@ public:
if ((std::is_same_v<Name, NameToString> && !arguments.empty() && (isDateTime64(arguments[0].type) || isDateTime(arguments[0].type)))
// toUnixTimestamp(value[, timezone : String])
|| std::is_same_v<Name, NameToUnixTimestamp>
// toUnixTimestampEx(value[, timezone : String])
|| std::is_same_v<Name, NameToUnixTimestampEx>
// toDate(value[, timezone : String])
|| std::is_same_v<ToDataType, DataTypeDate> // TODO: shall we allow timestamp argument for toDate? DateTime knows nothing about timezones and this argument is ignored below.
// toDate32(value[, timezone : String])
@ -2236,6 +2257,7 @@ private:
if constexpr (IsDataTypeDecimal<RightDataType>)
{
if constexpr (std::is_same_v<RightDataType, DataTypeDateTime64>)
{
/// Account for optional timezone argument.
@ -2319,8 +2341,10 @@ private:
}
}
else
{
result_column = ConvertImpl<LeftDataType, RightDataType, Name>::execute(arguments, result_type, input_rows_count, from_string_tag);
}
return true;
};
@ -2880,6 +2904,7 @@ using FunctionToIPv4 = FunctionConvert<DataTypeIPv4, NameToIPv4, ToNumberMonoton
using FunctionToIPv6 = FunctionConvert<DataTypeIPv6, NameToIPv6, ToNumberMonotonicity<UInt128>>;
using FunctionToString = FunctionConvert<DataTypeString, NameToString, ToStringMonotonicity>;
using FunctionToUnixTimestamp = FunctionConvert<DataTypeUInt32, NameToUnixTimestamp, ToNumberMonotonicity<UInt32>>;
using FunctionToUnixTimestampEx = FunctionConvert<DataTypeInt64, NameToUnixTimestampEx, ToNumberMonotonicity<Int64>>;
using FunctionToDecimal32 = FunctionConvert<DataTypeDecimal<Decimal32>, NameToDecimal32, UnknownMonotonicity>;
using FunctionToDecimal64 = FunctionConvert<DataTypeDecimal<Decimal64>, NameToDecimal64, UnknownMonotonicity>;
using FunctionToDecimal128 = FunctionConvert<DataTypeDecimal<Decimal128>, NameToDecimal128, UnknownMonotonicity>;
@ -5420,6 +5445,7 @@ REGISTER_FUNCTION(Conversion)
factory.registerFunction<FunctionToString>();
factory.registerFunction<FunctionToUnixTimestamp>();
factory.registerFunction<FunctionToUnixTimestampEx>();
factory.registerFunction<FunctionToUInt8OrZero>();
factory.registerFunction<FunctionToUInt16OrZero>();

View File

@ -0,0 +1,13 @@
#include <Functions/FunctionUnixTimestamp64.h>
#include <Functions/FunctionFactory.h>
namespace DB
{
REGISTER_FUNCTION(ToUnixTimestamp64Second)
{
factory.registerFunction("toUnixTimestamp64Second",
[](ContextPtr){ return std::make_shared<FunctionToUnixTimestamp64>(0, "toUnixTimestamp64Second"); });
}
}

View File

@ -1,8 +1,8 @@
const column
2019-09-16 19:20:12.345 1568650812345 1568650812345000 1568650812345000000
2019-09-16 19:20:12.345678 1568650812345 1568650812345678 1568650812345678000
2019-09-16 19:20:12.345678910 1568650812345 1568650812345678 1568650812345678910
2019-09-16 19:20:12.345 1568650812345 1568650812345000 1568650812345000000 1568650812
2019-09-16 19:20:12.345678 1568650812345 1568650812345678 1568650812345678000 1568650812
2019-09-16 19:20:12.345678910 1568650812345 1568650812345678 1568650812345678910 1568650812
non-const column
2019-09-16 19:20:12.345 1568650812345 1568650812345000 1568650812345000000
2019-09-16 19:20:12.345678 1568650812345 1568650812345678 1568650812345678000
2019-09-16 19:20:12.345678910 1568650812345 1568650812345678 1568650812345678910
2019-09-16 19:20:12.345 1568650812345 1568650812345000 1568650812345000000 1568650812
2019-09-16 19:20:12.345678 1568650812345 1568650812345678 1568650812345678000 1568650812
2019-09-16 19:20:12.345678910 1568650812345 1568650812345678 1568650812345678910 1568650812

View File

@ -2,32 +2,35 @@
SELECT toUnixTimestamp64Milli(); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Micro(); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Nano(); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Second(); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Milli('abc'); -- {serverError ILLEGAL_TYPE_OF_ARGUMENT}
SELECT toUnixTimestamp64Micro('abc'); -- {serverError ILLEGAL_TYPE_OF_ARGUMENT}
SELECT toUnixTimestamp64Nano('abc'); -- {serverError ILLEGAL_TYPE_OF_ARGUMENT}
SELECT toUnixTimestamp64Second('abc'); -- {serverError ILLEGAL_TYPE_OF_ARGUMENT}
SELECT toUnixTimestamp64Milli('abc', 123); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Micro('abc', 123); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Nano('abc', 123); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT toUnixTimestamp64Second('abc', 123); -- {serverError NUMBER_OF_ARGUMENTS_DOESNT_MATCH}
SELECT 'const column';
WITH toDateTime64('2019-09-16 19:20:12.345678910', 3, 'Asia/Istanbul') AS dt64
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);
WITH toDateTime64('2019-09-16 19:20:12.345678910', 6, 'Asia/Istanbul') AS dt64
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);
WITH toDateTime64('2019-09-16 19:20:12.345678910', 9, 'Asia/Istanbul') AS dt64
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);
SELECT 'non-const column';
WITH toDateTime64('2019-09-16 19:20:12.345678910', 3, 'Asia/Istanbul') AS x
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);
WITH toDateTime64('2019-09-16 19:20:12.345678910', 6, 'Asia/Istanbul') AS x
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);
WITH toDateTime64('2019-09-16 19:20:12.345678910', 9, 'Asia/Istanbul') AS x
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64);
SELECT materialize(x) as dt64, toUnixTimestamp64Milli(dt64), toUnixTimestamp64Micro(dt64), toUnixTimestamp64Nano(dt64), toUnixTimestamp64Second(dt64);

View File

@ -0,0 +1,9 @@
1683676800
1683676800
1683676800
1683676800
-1293882467
0
0
-28800
-28800

View File

@ -0,0 +1,9 @@
SELECT toUnixTimestampEx(makeDate(2023, 5, 10));
SELECT toUnixTimestampEx(makeDate32(2023, 5, 10));
SELECT toUnixTimestampEx(makeDate(2023, 5, 10), 'Pacific/Auckland');
SELECT toUnixTimestampEx(makeDate32(2023, 5, 10), 'Pacific/Auckland');
SELECT toUnixTimestampEx(toDateTime64('1928-12-31 12:12:12.123', 3, 'UTC'));
SELECT toUnixTimestampEx('1970-01-01 00:00:00', 'UTC');
SELECT toUnixTimestampEx(materialize('1970-01-01 00:00:00'), 'UTC');
SELECT toUnixTimestampEx('1970-01-01 00:00:00', 'Asia/Shanghai');
SELECT toUnixTimestampEx(materialize('1970-01-01 00:00:00'), 'Asia/Shanghai');