mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-11-24 08:32:02 +00:00
Joins by Nullable keys: development [#CLICKHOUSE-4].
This commit is contained in:
parent
ab215c0fcd
commit
463fddb2ca
@ -269,8 +269,14 @@ void Join::setSampleBlock(const Block & block)
|
||||
ConstColumnPlainPtrs key_columns(keys_size);
|
||||
|
||||
for (size_t i = 0; i < keys_size; ++i)
|
||||
{
|
||||
key_columns[i] = block.getByName(key_names_right[i]).column.get();
|
||||
|
||||
/// We will join only keys, where all components are not NULL.
|
||||
if (key_columns[i]->isNullable())
|
||||
key_columns[i] = static_cast<const ColumnNullable &>(*key_columns[i]).getNestedColumn().get();
|
||||
}
|
||||
|
||||
/// Choose data structure to use for JOIN.
|
||||
init(chooseMethod(key_columns, key_sizes));
|
||||
|
||||
@ -836,11 +842,24 @@ void Join::checkTypesOfKeys(const Block & block_left, const Block & block_right)
|
||||
size_t keys_size = key_names_left.size();
|
||||
|
||||
for (size_t i = 0; i < keys_size; ++i)
|
||||
if (!block_left.getByName(key_names_left[i]).type->equals(*block_right.getByName(key_names_right[i]).type))
|
||||
{
|
||||
/// Compare up to Nullability.
|
||||
|
||||
IDataType * left_type = block_left.getByName(key_names_left[i]).type.get();
|
||||
IDataType * right_type = block_right.getByName(key_names_right[i]).type.get();
|
||||
|
||||
if (left_type->isNullable())
|
||||
left_type = static_cast<const DataTypeNullable &>(*left_type).getNestedType().get();
|
||||
|
||||
if (right_type->isNullable())
|
||||
right_type = static_cast<const DataTypeNullable &>(*right_type).getNestedType().get();
|
||||
|
||||
if (!left_type->equals(*right_type))
|
||||
throw Exception("Type mismatch of columns to JOIN by: "
|
||||
+ key_names_left[i] + " " + block_left.getByName(key_names_left[i]).type->getName() + " at left, "
|
||||
+ key_names_right[i] + " " + block_right.getByName(key_names_right[i]).type->getName() + " at right",
|
||||
+ key_names_left[i] + " " + left_type->getName() + " at left, "
|
||||
+ key_names_right[i] + " " + right_type->getName() + " at right",
|
||||
ErrorCodes::TYPE_MISMATCH);
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
|
@ -18,11 +18,11 @@
|
||||
7 7 7
|
||||
8 8 8
|
||||
9 9 9
|
||||
14 14
|
||||
12 12
|
||||
11 11
|
||||
10 10
|
||||
11 11
|
||||
12 12
|
||||
13 13
|
||||
14 14
|
||||
0 0
|
||||
1 1
|
||||
2 2
|
||||
@ -33,11 +33,11 @@
|
||||
7 7 7
|
||||
8 8 8
|
||||
9 9 9
|
||||
14 14
|
||||
12 12
|
||||
11 11
|
||||
10 10
|
||||
11 11
|
||||
12 12
|
||||
13 13
|
||||
14 14
|
||||
5 5 5
|
||||
6 6 6
|
||||
7 7 7
|
||||
@ -53,28 +53,3 @@
|
||||
7 7 7
|
||||
8 8 8
|
||||
9 9 9
|
||||
5 5 5
|
||||
6 6 6
|
||||
7 7 7
|
||||
8 8 8
|
||||
9 9 9
|
||||
14 \N 14
|
||||
12 \N 12
|
||||
11 \N 11
|
||||
10 \N 10
|
||||
13 \N 13
|
||||
0 0 \N
|
||||
1 1 \N
|
||||
2 2 \N
|
||||
3 3 \N
|
||||
4 4 \N
|
||||
5 5 5
|
||||
6 6 6
|
||||
7 7 7
|
||||
8 8 8
|
||||
9 9 9
|
||||
14 \N 14
|
||||
12 \N 12
|
||||
11 \N 11
|
||||
10 \N 10
|
||||
13 \N 13
|
||||
|
@ -8,7 +8,7 @@ FROM
|
||||
ANY INNER JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -18,7 +18,7 @@ FROM
|
||||
ANY LEFT JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -28,7 +28,7 @@ FROM
|
||||
ANY RIGHT JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -38,7 +38,7 @@ FROM
|
||||
ANY FULL JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
|
||||
SET join_use_nulls = 1;
|
||||
@ -51,7 +51,7 @@ FROM
|
||||
ANY INNER JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -61,7 +61,7 @@ FROM
|
||||
ANY LEFT JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -71,7 +71,7 @@ FROM
|
||||
ANY RIGHT JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
@ -81,4 +81,4 @@ FROM
|
||||
ANY FULL JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k);
|
||||
) USING (k) ORDER BY k;
|
||||
|
@ -0,0 +1,23 @@
|
||||
5 5 5
|
||||
6 6 6
|
||||
8 8 8
|
||||
9 9 9
|
||||
0 0
|
||||
1 1
|
||||
2 2
|
||||
3 3
|
||||
4 4
|
||||
5 5 5
|
||||
6 6 6
|
||||
7 7 7
|
||||
8 8
|
||||
9 9 9
|
||||
5 5 5
|
||||
6 6 6
|
||||
9 9 9
|
||||
7 7
|
||||
14 14
|
||||
12 12
|
||||
11 11
|
||||
10 10
|
||||
13 13
|
31
dbms/tests/queries/0_stateless/00445_join_nullable_keys.sql
Normal file
31
dbms/tests/queries/0_stateless/00445_join_nullable_keys.sql
Normal file
@ -0,0 +1,31 @@
|
||||
SET join_use_nulls = 0;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
(
|
||||
SELECT nullIf(number, 7) AS k, toString(number) AS a FROM system.numbers LIMIT 10
|
||||
)
|
||||
ANY INNER JOIN
|
||||
(
|
||||
SELECT number AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
(
|
||||
SELECT number AS k, toString(number) AS a FROM system.numbers LIMIT 10
|
||||
)
|
||||
ANY LEFT JOIN
|
||||
(
|
||||
SELECT nullIf(number, 8) AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k) ORDER BY k;
|
||||
|
||||
SELECT k, a, b
|
||||
FROM
|
||||
(
|
||||
SELECT nullIf(number, 7) AS k, toString(number) AS a FROM system.numbers LIMIT 10
|
||||
)
|
||||
ANY RIGHT JOIN
|
||||
(
|
||||
SELECT nullIf(number, 8) AS k, toString(number) AS b FROM system.numbers LIMIT 5, 10
|
||||
) USING (k) ORDER BY k;
|
Loading…
Reference in New Issue
Block a user