mirror of
https://github.com/ClickHouse/ClickHouse.git
synced 2024-12-17 20:02:05 +00:00
Fixes for join key inferring
Fix error with wrong right column type in aggregate with nulls Add logging inferred type for join keys Add test for join_use_nulls
This commit is contained in:
parent
354757d94d
commit
cc770ad441
@ -1,5 +1,7 @@
|
||||
#include <Interpreters/TableJoin.h>
|
||||
|
||||
#include <common/logger_useful.h>
|
||||
|
||||
#include <Parsers/ASTExpressionList.h>
|
||||
|
||||
#include <Core/Settings.h>
|
||||
@ -231,7 +233,7 @@ void TableJoin::addJoinedColumn(const NameAndTypePair & joined_column)
|
||||
}
|
||||
|
||||
if (rightBecomeNullable(type))
|
||||
type = makeNullable(joined_column.type);
|
||||
type = makeNullable(type);
|
||||
|
||||
columns_added_by_join.emplace_back(joined_column.name, type);
|
||||
}
|
||||
@ -416,6 +418,22 @@ bool TableJoin::inferJoinKeyCommonType(const NamesAndTypesList & left, const Nam
|
||||
left_type_map[key_names_left[i]] = right_type_map[key_names_right[i]] = supertype;
|
||||
}
|
||||
|
||||
if (!left_type_map.empty() || !right_type_map.empty())
|
||||
{
|
||||
auto format_type_map = [](NameToTypeMap mapping) -> std::string
|
||||
{
|
||||
std::vector<std::string> text;
|
||||
for (const auto & [k, v] : mapping)
|
||||
text.push_back(k + ": " + v->getName());
|
||||
return fmt::format("{}", fmt::join(text, ", "));
|
||||
};
|
||||
LOG_TRACE(
|
||||
&Poco::Logger::get("TableJoin"),
|
||||
"Infer supertype for joined columns. Left: [{}], Right: [{}]",
|
||||
format_type_map(left_type_map),
|
||||
format_type_map(right_type_map));
|
||||
}
|
||||
|
||||
return !left_type_map.empty();
|
||||
}
|
||||
|
||||
|
@ -618,6 +618,17 @@
|
||||
8 108 \N
|
||||
9 109 \N
|
||||
10 110 \N
|
||||
= left =
|
||||
1 101 201
|
||||
2 102 202
|
||||
3 103 203
|
||||
4 104 204
|
||||
5 105 205
|
||||
6 106 \N
|
||||
7 107 \N
|
||||
8 108 \N
|
||||
9 109 \N
|
||||
10 110 \N
|
||||
= right =
|
||||
-4 \N 196
|
||||
-3 \N 197
|
||||
@ -629,3 +640,165 @@
|
||||
3 103 203
|
||||
4 104 204
|
||||
5 105 205
|
||||
= inner =
|
||||
1 101 201
|
||||
2 102 202
|
||||
3 103 203
|
||||
4 104 204
|
||||
5 105 205
|
||||
= full =
|
||||
1 1 1
|
||||
2 2 2
|
||||
3 3 3
|
||||
4 4 4
|
||||
5 5 5
|
||||
6 6 \N
|
||||
7 7 \N
|
||||
8 8 \N
|
||||
9 9 \N
|
||||
10 10 \N
|
||||
\N \N -4
|
||||
\N \N -3
|
||||
\N \N -2
|
||||
\N \N -1
|
||||
\N \N 0
|
||||
= left =
|
||||
1 1 1
|
||||
2 2 2
|
||||
3 3 3
|
||||
4 4 4
|
||||
5 5 5
|
||||
6 6 \N
|
||||
7 7 \N
|
||||
8 8 \N
|
||||
9 9 \N
|
||||
10 10 \N
|
||||
= right =
|
||||
1 1 1
|
||||
2 2 2
|
||||
3 3 3
|
||||
4 4 4
|
||||
5 5 5
|
||||
\N \N -4
|
||||
\N \N -3
|
||||
\N \N -2
|
||||
\N \N -1
|
||||
\N \N 0
|
||||
= inner =
|
||||
1 1 1
|
||||
2 2 2
|
||||
3 3 3
|
||||
4 4 4
|
||||
5 5 5
|
||||
= join on =
|
||||
= full =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
6 106 \N \N
|
||||
7 107 \N \N
|
||||
8 108 \N \N
|
||||
9 109 \N \N
|
||||
10 110 \N \N
|
||||
\N \N -4 196
|
||||
\N \N -3 197
|
||||
\N \N -2 198
|
||||
\N \N -1 199
|
||||
\N \N 0 200
|
||||
= left =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
6 106 \N \N
|
||||
7 107 \N \N
|
||||
8 108 \N \N
|
||||
9 109 \N \N
|
||||
10 110 \N \N
|
||||
= right =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
\N \N -4 196
|
||||
\N \N -3 197
|
||||
\N \N -2 198
|
||||
\N \N -1 199
|
||||
\N \N 0 200
|
||||
= inner =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
= full =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
6 106 \N \N
|
||||
7 107 \N \N
|
||||
8 108 \N \N
|
||||
9 109 \N \N
|
||||
10 110 \N \N
|
||||
\N \N -4 196
|
||||
\N \N -3 197
|
||||
\N \N -2 198
|
||||
\N \N -1 199
|
||||
\N \N 0 200
|
||||
= left =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
6 106 \N \N
|
||||
7 107 \N \N
|
||||
8 108 \N \N
|
||||
9 109 \N \N
|
||||
10 110 \N \N
|
||||
= right =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
\N \N -4 196
|
||||
\N \N -3 197
|
||||
\N \N -2 198
|
||||
\N \N -1 199
|
||||
\N \N 0 200
|
||||
= inner =
|
||||
1 101 1 201
|
||||
2 102 2 202
|
||||
3 103 3 203
|
||||
4 104 4 204
|
||||
5 105 5 205
|
||||
= agg =
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
0 -10 \N
|
||||
1 55 1055
|
||||
1 55 15 1055 1015
|
||||
\N \N -10 \N 990
|
||||
= types =
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
|
@ -238,10 +238,77 @@ SELECT '=== join use nulls ===';
|
||||
|
||||
SET join_use_nulls = 1;
|
||||
|
||||
|
||||
SELECT '= full =';
|
||||
SELECT a, b, t2.b FROM t1 FULL JOIN t2 USING (a) ORDER BY (a);
|
||||
SELECT '= left =';
|
||||
SELECT a, b, t2.b FROM t1 LEFT JOIN t2 USING (a) ORDER BY (a);
|
||||
SELECT '= right =';
|
||||
SELECT a, b, t2.b FROM t1 RIGHT JOIN t2 USING (a) ORDER BY (a);
|
||||
SELECT '= inner =';
|
||||
SELECT a, b, t2.b FROM t1 INNER JOIN t2 USING (a) ORDER BY (a);
|
||||
|
||||
SELECT '= full =';
|
||||
SELECT a, t1.a, t2.a FROM t1 FULL JOIN t2 USING (a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= left =';
|
||||
SELECT a, t1.a, t2.a FROM t1 LEFT JOIN t2 USING (a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= right =';
|
||||
SELECT a, t1.a, t2.a FROM t1 RIGHT JOIN t2 USING (a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= inner =';
|
||||
SELECT a, t1.a, t2.a FROM t1 INNER JOIN t2 USING (a) ORDER BY (t1.a, t2.a);
|
||||
|
||||
SELECT '= join on =';
|
||||
SELECT '= full =';
|
||||
SELECT a, b, t2.a, t2.b FROM t1 FULL JOIN t2 ON (t1.a == t2.a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= left =';
|
||||
SELECT a, b, t2.a, t2.b FROM t1 LEFT JOIN t2 ON (t1.a == t2.a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= right =';
|
||||
SELECT a, b, t2.a, t2.b FROM t1 RIGHT JOIN t2 ON (t1.a == t2.a) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= inner =';
|
||||
SELECT a, b, t2.a, t2.b FROM t1 INNER JOIN t2 ON (t1.a == t2.a) ORDER BY (t1.a, t2.a);
|
||||
|
||||
SELECT '= full =';
|
||||
SELECT * FROM t1 FULL JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= left =';
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= right =';
|
||||
SELECT * FROM t1 RIGHT JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) ORDER BY (t1.a, t2.a);
|
||||
SELECT '= inner =';
|
||||
SELECT * FROM t1 INNER JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) ORDER BY (t1.a, t2.a);
|
||||
|
||||
-- Int64 and UInt64 has no supertype
|
||||
SELECT * FROM t1 FULL JOIN t2 ON (t1.a + t1.b + 100 = t2.a + t2.b) ORDER BY (t1.a, t2.a); -- { serverError 53 }
|
||||
SELECT * FROM t1 LEFT JOIN t2 ON (t1.a + t1.b + 100 = t2.a + t2.b) ORDER BY (t1.a, t2.a); -- { serverError 53 }
|
||||
SELECT * FROM t1 RIGHT JOIN t2 ON (t1.a + t1.b + 100 = t2.a + t2.b) ORDER BY (t1.a, t2.a); -- { serverError 53 }
|
||||
SELECT * FROM t1 INNER JOIN t2 ON (t1.a + t1.b + 100 = t2.a + t2.b) ORDER BY (t1.a, t2.a); -- { serverError 53 }
|
||||
|
||||
SELECT '= agg =';
|
||||
SELECT sum(a) == 7 FROM t1 FULL JOIN t2 USING (a) WHERE b > 102 AND t2.b <= 204;
|
||||
SELECT sum(a) == 7 FROM t1 INNER JOIN t2 USING (a) WHERE b > 102 AND t2.b <= 204;
|
||||
|
||||
SELECT sum(b) = 103 FROM t1 LEFT JOIN t2 USING (a) WHERE b > 102 AND t2.b < 204;
|
||||
SELECT sum(t2.b) = 203 FROM t1 RIGHT JOIN t2 USING (a) WHERE b > 102 AND t2.b < 204;
|
||||
|
||||
SELECT sum(a) == 2 + 3 + 4 FROM t1 FULL JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) WHERE t1.b < 105 AND t2.b > 201;
|
||||
SELECT sum(a) == 55 FROM t1 FULL JOIN t2 ON (t1.a + t1.b = t2.a + t2.b - 100) WHERE 1;
|
||||
|
||||
SELECT a > 0, sum(a), sum(b) FROM t1 FULL JOIN t2 USING (a) GROUP BY (a > 0) ORDER BY a > 0;
|
||||
SELECT a > 0, sum(a), sum(t2.a), sum(b), sum(t2.b) FROM t1 FULL JOIN t2 ON (t1.a == t2.a) GROUP BY (a > 0) ORDER BY a > 0;
|
||||
|
||||
SELECT '= types =';
|
||||
SELECT any(toTypeName(a)) == 'Nullable(Int32)' AND any(toTypeName(t2.a)) == 'Nullable(Int32)' FROM t1 FULL JOIN t2 USING (a);
|
||||
SELECT any(toTypeName(a)) == 'Int32' AND any(toTypeName(t2.a)) == 'Nullable(Int32)' FROM t1 LEFT JOIN t2 USING (a);
|
||||
SELECT any(toTypeName(a)) == 'Nullable(Int32)' AND any(toTypeName(t2.a)) == 'Int32' FROM t1 RIGHT JOIN t2 USING (a);
|
||||
SELECT any(toTypeName(a)) == 'Int32' AND any(toTypeName(t2.a)) == 'Int32' FROM t1 INNER JOIN t2 USING (a);
|
||||
|
||||
SELECT toTypeName(any(a)) == 'Nullable(Int32)' AND toTypeName(any(t2.a)) == 'Nullable(Int32)' FROM t1 FULL JOIN t2 USING (a);
|
||||
SELECT min(toTypeName(a) == 'Nullable(Int32)' AND toTypeName(t2.a) == 'Nullable(Int32)') FROM t1 FULL JOIN t2 USING (a);
|
||||
|
||||
SELECT any(toTypeName(a)) == 'Nullable(UInt16)' AND any(toTypeName(t2.a)) == 'Nullable(Int16)' FROM t1 FULL JOIN t2 ON (t1.a == t2.a);
|
||||
SELECT any(toTypeName(a)) == 'UInt16' AND any(toTypeName(t2.a)) == 'Nullable(Int16)' FROM t1 LEFT JOIN t2 ON (t1.a == t2.a);
|
||||
SELECT any(toTypeName(a)) == 'Nullable(UInt16)' AND any(toTypeName(t2.a)) == 'Int16' FROM t1 RIGHT JOIN t2 ON (t1.a == t2.a);
|
||||
SELECT any(toTypeName(a)) == 'UInt16' AND any(toTypeName(t2.a)) == 'Int16' FROM t1 INNER JOIN t2 ON (t1.a == t2.a);
|
||||
SELECT toTypeName(any(a)) == 'Nullable(UInt16)' AND toTypeName(any(t2.a)) == 'Nullable(Int16)' FROM t1 FULL JOIN t2 ON (t1.a == t2.a);
|
||||
|
||||
SET join_use_nulls = 0;
|
||||
|
||||
|
Loading…
Reference in New Issue
Block a user