mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-21 15:12:02 +00:00
Merge pull request #26234 from jasine/master
convert timestamp and timestamptz data types to DateTime64 in postgres engine
This commit is contained in:
commit
e42a26a585
@ -9,6 +9,7 @@
|
||||
#include <DataTypes/IDataType.h>
|
||||
#include <DataTypes/DataTypeNullable.h>
|
||||
#include <DataTypes/DataTypeArray.h>
|
||||
#include <DataTypes/DataTypeDateTime64.h>
|
||||
#include <DataTypes/DataTypesDecimal.h>
|
||||
#include <Interpreters/convertFieldToType.h>
|
||||
#include <IO/ReadHelpers.h>
|
||||
@ -102,7 +103,16 @@ void insertPostgreSQLValue(
|
||||
assert_cast<ColumnUInt32 &>(column).insertValue(time);
|
||||
break;
|
||||
}
|
||||
case ExternalResultDescription::ValueType::vtDateTime64:[[fallthrough]];
|
||||
case ExternalResultDescription::ValueType::vtDateTime64:
|
||||
{
|
||||
ReadBufferFromString in(value);
|
||||
DateTime64 time = 0;
|
||||
readDateTime64Text(time, 6, in, assert_cast<const DataTypeDateTime64 *>(data_type.get())->getTimeZone());
|
||||
if (time < 0)
|
||||
time = 0;
|
||||
assert_cast<ColumnDecimal<Decimal64> &>(column).insertValue(time);
|
||||
break;
|
||||
}
|
||||
case ExternalResultDescription::ValueType::vtDecimal32: [[fallthrough]];
|
||||
case ExternalResultDescription::ValueType::vtDecimal64: [[fallthrough]];
|
||||
case ExternalResultDescription::ValueType::vtDecimal128: [[fallthrough]];
|
||||
@ -206,6 +216,14 @@ void preparePostgreSQLArrayInfo(
|
||||
readDateTimeText(time, in, assert_cast<const DataTypeDateTime *>(nested.get())->getTimeZone());
|
||||
return time;
|
||||
};
|
||||
else if (which.isDateTime64())
|
||||
parser = [nested](std::string & field) -> Field
|
||||
{
|
||||
ReadBufferFromString in(field);
|
||||
DateTime64 time = 0;
|
||||
readDateTime64Text(time, 6, in, assert_cast<const DataTypeDateTime64 *>(nested.get())->getTimeZone());
|
||||
return time;
|
||||
};
|
||||
else if (which.isDecimal32())
|
||||
parser = [nested](std::string & field) -> Field
|
||||
{
|
||||
|
@ -9,7 +9,7 @@
|
||||
#include <DataTypes/DataTypeArray.h>
|
||||
#include <DataTypes/DataTypesDecimal.h>
|
||||
#include <DataTypes/DataTypeDate.h>
|
||||
#include <DataTypes/DataTypeDateTime.h>
|
||||
#include <DataTypes/DataTypeDateTime64.h>
|
||||
#include <boost/algorithm/string/split.hpp>
|
||||
#include <boost/algorithm/string/trim.hpp>
|
||||
#include <Common/quoteString.h>
|
||||
@ -71,7 +71,7 @@ static DataTypePtr convertPostgreSQLDataType(String & type, const std::function<
|
||||
else if (type == "bigserial")
|
||||
res = std::make_shared<DataTypeUInt64>();
|
||||
else if (type.starts_with("timestamp"))
|
||||
res = std::make_shared<DataTypeDateTime>();
|
||||
res = std::make_shared<DataTypeDateTime64>(6);
|
||||
else if (type == "date")
|
||||
res = std::make_shared<DataTypeDate>();
|
||||
else if (type.starts_with("numeric"))
|
||||
|
@ -327,6 +327,16 @@ ASTPtr StorageMaterializedPostgreSQL::getColumnDeclaration(const DataTypePtr & d
|
||||
return make_decimal_expression("Decimal256");
|
||||
}
|
||||
|
||||
if (which.isDateTime64())
|
||||
{
|
||||
auto ast_expression = std::make_shared<ASTFunction>();
|
||||
|
||||
ast_expression->name = "DateTime64";
|
||||
ast_expression->arguments = std::make_shared<ASTExpressionList>();
|
||||
ast_expression->arguments->children.emplace_back(std::make_shared<ASTLiteral>(UInt32(6)));
|
||||
return ast_expression;
|
||||
}
|
||||
|
||||
return std::make_shared<ASTIdentifier>(data_type->getName());
|
||||
}
|
||||
|
||||
|
@ -234,6 +234,10 @@ public:
|
||||
else if (which.isFloat64()) nested_column = ColumnFloat64::create();
|
||||
else if (which.isDate()) nested_column = ColumnUInt16::create();
|
||||
else if (which.isDateTime()) nested_column = ColumnUInt32::create();
|
||||
else if (which.isDateTime64())
|
||||
{
|
||||
nested_column = ColumnDecimal<DateTime64>::create(0, 6);
|
||||
}
|
||||
else if (which.isDecimal32())
|
||||
{
|
||||
const auto & type = typeid_cast<const DataTypeDecimal<Decimal32> *>(nested.get());
|
||||
|
@ -236,7 +236,7 @@ def test_different_data_types(started_cluster):
|
||||
(
|
||||
key Integer NOT NULL PRIMARY KEY,
|
||||
a Date[] NOT NULL, -- Date
|
||||
b Timestamp[] NOT NULL, -- DateTime
|
||||
b Timestamp[] NOT NULL, -- DateTime64(6)
|
||||
c real[][] NOT NULL, -- Float32
|
||||
d double precision[][] NOT NULL, -- Float64
|
||||
e decimal(5, 5)[][][] NOT NULL, -- Decimal32
|
||||
@ -253,11 +253,11 @@ def test_different_data_types(started_cluster):
|
||||
for i in range(10):
|
||||
instance.query('''
|
||||
INSERT INTO postgres_database.test_data_types VALUES
|
||||
({}, -32768, -2147483648, -9223372036854775808, 1.12345, 1.1234567890, 2147483647, 9223372036854775807, '2000-05-12 12:12:12', '2000-05-12', 0.2, 0.2)'''.format(i))
|
||||
({}, -32768, -2147483648, -9223372036854775808, 1.12345, 1.1234567890, 2147483647, 9223372036854775807, '2000-05-12 12:12:12.012345', '2000-05-12', 0.2, 0.2)'''.format(i))
|
||||
|
||||
check_tables_are_synchronized('test_data_types', 'id');
|
||||
result = instance.query('SELECT * FROM test_database.test_data_types ORDER BY id LIMIT 1;')
|
||||
assert(result == '0\t-32768\t-2147483648\t-9223372036854775808\t1.12345\t1.123456789\t2147483647\t9223372036854775807\t2000-05-12 12:12:12\t2000-05-12\t0.20000\t0.20000\n')
|
||||
assert(result == '0\t-32768\t-2147483648\t-9223372036854775808\t1.12345\t1.123456789\t2147483647\t9223372036854775807\t2000-05-12 12:12:12.012345\t2000-05-12\t0.20000\t0.20000\n')
|
||||
|
||||
for i in range(10):
|
||||
col = random.choice(['a', 'b', 'c'])
|
||||
@ -270,7 +270,7 @@ def test_different_data_types(started_cluster):
|
||||
"VALUES ("
|
||||
"0, "
|
||||
"['2000-05-12', '2000-05-12'], "
|
||||
"['2000-05-12 12:12:12', '2000-05-12 12:12:12'], "
|
||||
"['2000-05-12 12:12:12.012345', '2000-05-12 12:12:12.012345'], "
|
||||
"[[1.12345], [1.12345], [1.12345]], "
|
||||
"[[1.1234567891], [1.1234567891], [1.1234567891]], "
|
||||
"[[[0.11111, 0.11111]], [[0.22222, 0.22222]], [[0.33333, 0.33333]]], "
|
||||
@ -284,7 +284,7 @@ def test_different_data_types(started_cluster):
|
||||
expected = (
|
||||
"0\t" +
|
||||
"['2000-05-12','2000-05-12']\t" +
|
||||
"['2000-05-12 12:12:12','2000-05-12 12:12:12']\t" +
|
||||
"['2000-05-12 12:12:12.012345','2000-05-12 12:12:12.012345']\t" +
|
||||
"[[1.12345],[1.12345],[1.12345]]\t" +
|
||||
"[[1.1234567891],[1.1234567891],[1.1234567891]]\t" +
|
||||
"[[[0.11111,0.11111]],[[0.22222,0.22222]],[[0.33333,0.33333]]]\t"
|
||||
@ -622,7 +622,7 @@ def test_virtual_columns(started_cluster):
|
||||
instance.query("INSERT INTO postgres_database.postgresql_replica_0 SELECT number, number from numbers(10)")
|
||||
check_tables_are_synchronized('postgresql_replica_0');
|
||||
|
||||
# just check that it works, no check with `expected` becuase _version is taken as LSN, which will be different each time.
|
||||
# just check that it works, no check with `expected` because _version is taken as LSN, which will be different each time.
|
||||
result = instance.query('SELECT key, value, _sign, _version FROM test_database.postgresql_replica_0;')
|
||||
print(result)
|
||||
|
||||
|
@ -85,10 +85,10 @@ def test_postgres_conversions(started_cluster):
|
||||
h timestamp, i date, j decimal(5, 3), k numeric, l boolean)''')
|
||||
node1.query('''
|
||||
INSERT INTO TABLE FUNCTION postgresql('postgres1:5432', 'clickhouse', 'test_types', 'postgres', 'mysecretpassword') VALUES
|
||||
(-32768, -2147483648, -9223372036854775808, 1.12345, 1.1234567890, 2147483647, 9223372036854775807, '2000-05-12 12:12:12', '2000-05-12', 22.222, 22.222, 1)''')
|
||||
(-32768, -2147483648, -9223372036854775808, 1.12345, 1.1234567890, 2147483647, 9223372036854775807, '2000-05-12 12:12:12.012345', '2000-05-12', 22.222, 22.222, 1)''')
|
||||
result = node1.query('''
|
||||
SELECT a, b, c, d, e, f, g, h, i, j, toDecimal128(k, 3), l FROM postgresql('postgres1:5432', 'clickhouse', 'test_types', 'postgres', 'mysecretpassword')''')
|
||||
assert(result == '-32768\t-2147483648\t-9223372036854775808\t1.12345\t1.123456789\t2147483647\t9223372036854775807\t2000-05-12 12:12:12\t2000-05-12\t22.222\t22.222\t1\n')
|
||||
assert(result == '-32768\t-2147483648\t-9223372036854775808\t1.12345\t1.123456789\t2147483647\t9223372036854775807\t2000-05-12 12:12:12.012345\t2000-05-12\t22.222\t22.222\t1\n')
|
||||
|
||||
cursor.execute("INSERT INTO test_types (l) VALUES (TRUE), (true), ('yes'), ('y'), ('1');")
|
||||
cursor.execute("INSERT INTO test_types (l) VALUES (FALSE), (false), ('no'), ('off'), ('0');")
|
||||
@ -100,7 +100,7 @@ def test_postgres_conversions(started_cluster):
|
||||
'''CREATE TABLE IF NOT EXISTS test_array_dimensions
|
||||
(
|
||||
a Date[] NOT NULL, -- Date
|
||||
b Timestamp[] NOT NULL, -- DateTime
|
||||
b Timestamp[] NOT NULL, -- DateTime64(6)
|
||||
c real[][] NOT NULL, -- Float32
|
||||
d double precision[][] NOT NULL, -- Float64
|
||||
e decimal(5, 5)[][][] NOT NULL, -- Decimal32
|
||||
@ -114,7 +114,7 @@ def test_postgres_conversions(started_cluster):
|
||||
result = node1.query('''
|
||||
DESCRIBE TABLE postgresql('postgres1:5432', 'clickhouse', 'test_array_dimensions', 'postgres', 'mysecretpassword')''')
|
||||
expected = ('a\tArray(Date)\t\t\t\t\t\n' +
|
||||
'b\tArray(DateTime)\t\t\t\t\t\n' +
|
||||
'b\tArray(DateTime64(6))\t\t\t\t\t\n' +
|
||||
'c\tArray(Array(Float32))\t\t\t\t\t\n' +
|
||||
'd\tArray(Array(Float64))\t\t\t\t\t\n' +
|
||||
'e\tArray(Array(Array(Decimal(5, 5))))\t\t\t\t\t\n' +
|
||||
@ -129,7 +129,7 @@ def test_postgres_conversions(started_cluster):
|
||||
node1.query("INSERT INTO TABLE FUNCTION postgresql('postgres1:5432', 'clickhouse', 'test_array_dimensions', 'postgres', 'mysecretpassword') "
|
||||
"VALUES ("
|
||||
"['2000-05-12', '2000-05-12'], "
|
||||
"['2000-05-12 12:12:12', '2000-05-12 12:12:12'], "
|
||||
"['2000-05-12 12:12:12.012345', '2000-05-12 12:12:12.012345'], "
|
||||
"[[1.12345], [1.12345], [1.12345]], "
|
||||
"[[1.1234567891], [1.1234567891], [1.1234567891]], "
|
||||
"[[[0.11111, 0.11111]], [[0.22222, 0.22222]], [[0.33333, 0.33333]]], "
|
||||
@ -144,7 +144,7 @@ def test_postgres_conversions(started_cluster):
|
||||
SELECT * FROM postgresql('postgres1:5432', 'clickhouse', 'test_array_dimensions', 'postgres', 'mysecretpassword')''')
|
||||
expected = (
|
||||
"['2000-05-12','2000-05-12']\t" +
|
||||
"['2000-05-12 12:12:12','2000-05-12 12:12:12']\t" +
|
||||
"['2000-05-12 12:12:12.012345','2000-05-12 12:12:12.012345']\t" +
|
||||
"[[1.12345],[1.12345],[1.12345]]\t" +
|
||||
"[[1.1234567891],[1.1234567891],[1.1234567891]]\t" +
|
||||
"[[[0.11111,0.11111]],[[0.22222,0.22222]],[[0.33333,0.33333]]]\t"
|
||||
|
Loading…
Reference in New Issue
Block a user