Merge pull request #62907 from kitaisreal/query-plan-convert-outer-join-to-inner-join-optimization

QueryPlan convert OUTER JOIN to INNER JOIN optimization
This commit is contained in:
Alexey Milovidov 2024-04-28 23:07:44 +00:00 committed by GitHub
commit eaf3b91ab6
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
20 changed files with 497 additions and 24 deletions

View File

@ -738,6 +738,7 @@ class IColumn;
M(Bool, query_plan_split_filter, true, "Allow to split filters in the query plan", 0) \
M(Bool, query_plan_merge_expressions, true, "Allow to merge expressions in the query plan", 0) \
M(Bool, query_plan_filter_push_down, true, "Allow to push down filter by predicate query plan step", 0) \
M(Bool, query_plan_convert_outer_join_to_inner_join, true, "Allow to convert OUTER JOIN to INNER JOIN if filter after JOIN always filters default values", 0) \
M(Bool, query_plan_optimize_prewhere, true, "Allow to push down filter to PREWHERE expression for supported storages", 0) \
M(Bool, query_plan_execute_functions_after_sorting, true, "Allow to re-order functions after sorting", 0) \
M(Bool, query_plan_reuse_storage_ordering_for_window_functions, true, "Allow to use the storage sorting for window functions", 0) \

View File

@ -95,7 +95,8 @@ static std::map<ClickHouseVersion, SettingsChangesHistory::SettingsChanges> sett
{"allow_experimental_database_replicated", false, true, "Database engine Replicated is now in Beta stage"},
{"temporary_data_in_cache_reserve_space_wait_lock_timeout_milliseconds", (10 * 60 * 1000), (10 * 60 * 1000), "Wait time to lock cache for sapce reservation in temporary data in filesystem cache"},
{"azure_allow_parallel_part_upload", "true", "true", "Use multiple threads for azure multipart upload."},
}},
{"query_plan_convert_outer_join_to_inner_join", false, true, "Allow to convert OUTER JOIN to INNER JOIN if filter after JOIN always filters default values"},
}},
{"24.3", {{"s3_connect_timeout_ms", 1000, 1000, "Introduce new dedicated setting for s3 connection timeout"},
{"allow_experimental_shared_merge_tree", false, true, "The setting is obsolete"},
{"use_page_cache_for_disks_without_file_cache", false, false, "Added userspace page cache"},

View File

@ -2013,6 +2013,63 @@ ActionsDAG::SplitResult ActionsDAG::splitActionsBySortingDescription(const NameS
return res;
}
bool ActionsDAG::isFilterAlwaysFalseForDefaultValueInputs(const std::string & filter_name, const Block & input_stream_header)
{
const auto * filter_node = tryFindInOutputs(filter_name);
if (!filter_node)
throw Exception(ErrorCodes::LOGICAL_ERROR,
"Outputs for ActionsDAG does not contain filter column name {}. DAG:\n{}",
filter_name,
dumpDAG());
std::unordered_map<std::string, ColumnWithTypeAndName> input_node_name_to_default_input_column;
for (const auto * input : inputs)
{
if (!input_stream_header.has(input->result_name))
continue;
if (input->column)
continue;
auto constant_column = input->result_type->createColumnConst(0, input->result_type->getDefault());
auto constant_column_with_type_and_name = ColumnWithTypeAndName{constant_column, input->result_type, input->result_name};
input_node_name_to_default_input_column.emplace(input->result_name, std::move(constant_column_with_type_and_name));
}
ActionsDAGPtr filter_with_default_value_inputs;
try
{
filter_with_default_value_inputs = buildFilterActionsDAG({filter_node}, input_node_name_to_default_input_column);
}
catch (const Exception &)
{
/** It is possible that duing DAG construction, some functions cannot be executed for constant default value inputs
* and exception will be thrown.
*/
return false;
}
const auto * filter_with_default_value_inputs_filter_node = filter_with_default_value_inputs->getOutputs()[0];
if (!filter_with_default_value_inputs_filter_node->column || !isColumnConst(*filter_with_default_value_inputs_filter_node->column))
return false;
const auto & constant_type = filter_with_default_value_inputs_filter_node->result_type;
auto which_constant_type = WhichDataType(constant_type);
if (!which_constant_type.isUInt8() && !which_constant_type.isNothing())
return false;
Field value;
filter_with_default_value_inputs_filter_node->column->get(0, value);
if (value.isNull())
return true;
UInt8 predicate_value = value.safeGet<UInt8>();
return predicate_value == 0;
}
ActionsDAG::SplitResult ActionsDAG::splitActionsForFilter(const std::string & column_name) const
{
const auto * node = tryFindInOutputs(column_name);

View File

@ -355,6 +355,13 @@ public:
/// The second contains the rest.
SplitResult splitActionsBySortingDescription(const NameSet & sort_columns) const;
/** Returns true if filter DAG is always false for inputs with default values.
*
* @param filter_name - name of filter node in current DAG.
* @param input_stream_header - input stream header.
*/
bool isFilterAlwaysFalseForDefaultValueInputs(const std::string & filter_name, const Block & input_stream_header);
/// Create actions which may calculate part of filter using only available_inputs.
/// If nothing may be calculated, returns nullptr.
/// Otherwise, return actions which inputs are from available_inputs.

View File

@ -31,8 +31,21 @@ public:
}
std::string getName() const override { return "FullSortingMergeJoin"; }
const TableJoin & getTableJoin() const override { return *table_join; }
bool isCloneSupported() const override
{
return true;
}
std::shared_ptr<IJoin> clone(const std::shared_ptr<TableJoin> & table_join_,
const Block &,
const Block & right_sample_block_) const override
{
return std::make_shared<FullSortingMergeJoin>(table_join_, right_sample_block_, null_direction);
}
int getNullDirection() const { return null_direction; }
bool addBlockToJoin(const Block & /* block */, bool /* check_limits */) override

View File

@ -236,11 +236,13 @@ static void correctNullabilityInplace(ColumnWithTypeAndName & column, bool nulla
}
HashJoin::HashJoin(std::shared_ptr<TableJoin> table_join_, const Block & right_sample_block_,
bool any_take_last_row_, size_t reserve_num, const String & instance_id_)
bool any_take_last_row_, size_t reserve_num_, const String & instance_id_)
: table_join(table_join_)
, kind(table_join->kind())
, strictness(table_join->strictness())
, any_take_last_row(any_take_last_row_)
, reserve_num(reserve_num_)
, instance_id(instance_id_)
, asof_inequality(table_join->getAsofInequality())
, data(std::make_shared<RightTableData>())
, right_sample_block(right_sample_block_)
@ -325,7 +327,7 @@ HashJoin::HashJoin(std::shared_ptr<TableJoin> table_join_, const Block & right_s
}
for (auto & maps : data->maps)
dataMapInit(maps, reserve_num);
dataMapInit(maps);
}
HashJoin::Type HashJoin::chooseMethod(JoinKind kind, const ColumnRawPtrs & key_columns, Sizes & key_sizes)
@ -487,9 +489,8 @@ struct KeyGetterForType
using Type = typename KeyGetterForTypeImpl<type, Value, Mapped>::Type;
};
void HashJoin::dataMapInit(MapsVariant & map, size_t reserve_num)
void HashJoin::dataMapInit(MapsVariant & map)
{
if (kind == JoinKind::Cross)
return;
joinDispatchInit(kind, strictness, map);

View File

@ -148,13 +148,26 @@ class HashJoin : public IJoin
public:
HashJoin(
std::shared_ptr<TableJoin> table_join_, const Block & right_sample_block,
bool any_take_last_row_ = false, size_t reserve_num = 0, const String & instance_id_ = "");
bool any_take_last_row_ = false, size_t reserve_num_ = 0, const String & instance_id_ = "");
~HashJoin() override;
std::string getName() const override { return "HashJoin"; }
const TableJoin & getTableJoin() const override { return *table_join; }
bool isCloneSupported() const override
{
return true;
}
std::shared_ptr<IJoin> clone(const std::shared_ptr<TableJoin> & table_join_,
const Block &,
const Block & right_sample_block_) const override
{
return std::make_shared<HashJoin>(table_join_, right_sample_block_, any_take_last_row, reserve_num, instance_id);
}
/** Add block of data from right hand of JOIN to the map.
* Returns false, if some limit was exceeded and you should not insert more data.
*/
@ -412,7 +425,9 @@ private:
/// This join was created from StorageJoin and it is already filled.
bool from_storage_join = false;
bool any_take_last_row; /// Overwrite existing values when encountering the same key again
const bool any_take_last_row; /// Overwrite existing values when encountering the same key again
const size_t reserve_num;
const String instance_id;
std::optional<TypeIndex> asof_type;
const ASOFJoinInequality asof_inequality;
@ -454,7 +469,7 @@ private:
/// If set HashJoin instance is not available for modification (addBlockToJoin)
TableLockHolder storage_join_lock = nullptr;
void dataMapInit(MapsVariant &, size_t);
void dataMapInit(MapsVariant & map);
void initRightBlockStructure(Block & saved_block_sample);

View File

@ -11,6 +11,11 @@
namespace DB
{
namespace ErrorCodes
{
extern const int UNSUPPORTED_METHOD;
}
struct ExtraBlock;
using ExtraBlockPtr = std::shared_ptr<ExtraBlock>;
@ -52,6 +57,23 @@ public:
virtual const TableJoin & getTableJoin() const = 0;
/// Returns true if clone is supported
virtual bool isCloneSupported() const
{
return false;
}
/// Clone underlyhing JOIN algorithm using table join, left sample block, right sample block
virtual std::shared_ptr<IJoin> clone(const std::shared_ptr<TableJoin> & table_join_,
const Block & left_sample_block_,
const Block & right_sample_block_) const
{
(void)(table_join_);
(void)(left_sample_block_);
(void)(right_sample_block_);
throw Exception(ErrorCodes::UNSUPPORTED_METHOD, "Clone method is not supported for {}", getName());
}
/// Add block of data from right hand of JOIN.
/// @returns false, if some limit was exceeded and you should not insert more data.
virtual bool addBlockToJoin(const Block & block, bool check_limits = true) = 0; /// NOLINT

View File

@ -243,7 +243,10 @@ public:
table_join.strictness = strictness;
}
TableJoin(const TableJoin & rhs) = default;
JoinKind kind() const { return table_join.kind; }
void setKind(JoinKind kind) { table_join.kind = kind; }
JoinStrictness strictness() const { return table_join.strictness; }
bool sameStrictnessAndKind(JoinStrictness, JoinKind) const;
const SizeLimits & sizeLimits() const { return size_limits; }

View File

@ -1089,18 +1089,6 @@ JoinTreeQueryPlan buildQueryPlanForJoinNode(const QueryTreeNodePtr & join_table_
auto right_plan = std::move(right_join_tree_query_plan.query_plan);
auto right_plan_output_columns = right_plan.getCurrentDataStream().header.getColumnsWithTypeAndName();
// {
// WriteBufferFromOwnString buf;
// left_plan.explainPlan(buf, {.header = true, .actions = true});
// std::cerr << "left plan \n "<< buf.str() << std::endl;
// }
// {
// WriteBufferFromOwnString buf;
// right_plan.explainPlan(buf, {.header = true, .actions = true});
// std::cerr << "right plan \n "<< buf.str() << std::endl;
// }
JoinClausesAndActions join_clauses_and_actions;
JoinKind join_kind = join_node.getKind();
JoinStrictness join_strictness = join_node.getStrictness();

View File

@ -31,6 +31,7 @@ public:
void describeActions(FormatSettings & settings) const override;
const JoinPtr & getJoin() const { return join; }
void setJoin(JoinPtr join_) { join = std::move(join_); }
bool allowPushDownToRight() const;
bool canUpdateInputStream() const override { return true; }

View File

@ -50,6 +50,9 @@ size_t tryMergeExpressions(QueryPlan::Node * parent_node, QueryPlan::Nodes &);
/// May split FilterStep and push down only part of it.
size_t tryPushDownFilter(QueryPlan::Node * parent_node, QueryPlan::Nodes & nodes);
/// Convert OUTER JOIN to INNER JOIN if filter after JOIN always filters default values
size_t tryConvertOuterJoinToInnerJoin(QueryPlan::Node * parent_node, QueryPlan::Nodes & nodes);
/// Move ExpressionStep after SortingStep if possible.
/// May split ExpressionStep and lift up only a part of it.
size_t tryExecuteFunctionsAfterSorting(QueryPlan::Node * parent_node, QueryPlan::Nodes & nodes);
@ -78,12 +81,13 @@ size_t tryAggregatePartitionsIndependently(QueryPlan::Node * node, QueryPlan::No
inline const auto & getOptimizations()
{
static const std::array<Optimization, 10> optimizations = {{
static const std::array<Optimization, 11> optimizations = {{
{tryLiftUpArrayJoin, "liftUpArrayJoin", &QueryPlanOptimizationSettings::lift_up_array_join},
{tryPushDownLimit, "pushDownLimit", &QueryPlanOptimizationSettings::push_down_limit},
{trySplitFilter, "splitFilter", &QueryPlanOptimizationSettings::split_filter},
{tryMergeExpressions, "mergeExpressions", &QueryPlanOptimizationSettings::merge_expressions},
{tryPushDownFilter, "pushDownFilter", &QueryPlanOptimizationSettings::filter_push_down},
{tryConvertOuterJoinToInnerJoin, "convertOuterJoinToInnerJoin", &QueryPlanOptimizationSettings::convert_outer_join_to_inner_join},
{tryExecuteFunctionsAfterSorting, "liftUpFunctions", &QueryPlanOptimizationSettings::execute_functions_after_sorting},
{tryReuseStorageOrderingForWindowFunctions, "reuseStorageOrderingForWindowFunctions", &QueryPlanOptimizationSettings::reuse_storage_ordering_for_window_functions},
{tryLiftUpUnion, "liftUpUnion", &QueryPlanOptimizationSettings::lift_up_union},

View File

@ -22,6 +22,8 @@ QueryPlanOptimizationSettings QueryPlanOptimizationSettings::fromSettings(const
settings.filter_push_down = from.query_plan_enable_optimizations && from.query_plan_filter_push_down;
settings.convert_outer_join_to_inner_join = from.query_plan_enable_optimizations && from.query_plan_convert_outer_join_to_inner_join;
settings.optimize_prewhere = from.query_plan_enable_optimizations && from.query_plan_optimize_prewhere;
settings.execute_functions_after_sorting = from.query_plan_enable_optimizations && from.query_plan_execute_functions_after_sorting;

View File

@ -34,6 +34,9 @@ struct QueryPlanOptimizationSettings
/// If filter push down optimization is enabled.
bool filter_push_down = true;
/// If convert OUTER JOIN to INNER JOIN optimization is enabled.
bool convert_outer_join_to_inner_join = true;
/// If reorder-functions-after-sorting optimization is enabled.
bool execute_functions_after_sorting = true;

View File

@ -0,0 +1,65 @@
#include <Processors/QueryPlan/Optimizations/Optimizations.h>
#include <Processors/QueryPlan/FilterStep.h>
#include <Processors/QueryPlan/ExpressionStep.h>
#include <Processors/QueryPlan/JoinStep.h>
#include <Interpreters/ActionsDAG.h>
#include <Interpreters/IJoin.h>
#include <Interpreters/TableJoin.h>
namespace DB::QueryPlanOptimizations
{
size_t tryConvertOuterJoinToInnerJoin(QueryPlan::Node * parent_node, QueryPlan::Nodes &)
{
auto & parent = parent_node->step;
auto * filter = typeid_cast<FilterStep *>(parent.get());
if (!filter)
return 0;
QueryPlan::Node * child_node = parent_node->children.front();
auto & child = child_node->step;
auto * join = typeid_cast<JoinStep *>(child.get());
if (!join || !join->getJoin()->isCloneSupported())
return 0;
const auto & table_join = join->getJoin()->getTableJoin();
if (table_join.strictness() == JoinStrictness::Asof)
return 0;
/// TODO: Support join_use_nulls
if (table_join.joinUseNulls())
return 0;
bool check_left_stream = table_join.kind() == JoinKind::Right || table_join.kind() == JoinKind::Full;
bool check_right_stream = table_join.kind() == JoinKind::Left || table_join.kind() == JoinKind::Full;
if (!check_left_stream && !check_right_stream)
return 0;
const auto & filter_dag = filter->getExpression();
const auto & filter_column_name = filter->getFilterColumnName();
const auto & left_stream_input_header = join->getInputStreams().front().header;
const auto & right_stream_input_header = join->getInputStreams().back().header;
bool left_stream_safe = true;
bool right_stream_safe = true;
if (check_left_stream)
left_stream_safe = filter_dag->isFilterAlwaysFalseForDefaultValueInputs(filter_column_name, left_stream_input_header);
if (check_right_stream)
right_stream_safe = filter_dag->isFilterAlwaysFalseForDefaultValueInputs(filter_column_name, right_stream_input_header);
if (!left_stream_safe || !right_stream_safe)
return 0;
auto updated_table_join = std::make_shared<TableJoin>(table_join);
updated_table_join->setKind(JoinKind::Inner);
auto updated_join = join->getJoin()->clone(updated_table_join, left_stream_input_header, right_stream_input_header);
join->setJoin(std::move(updated_join));
return 1;
}
}

View File

@ -236,9 +236,7 @@ static size_t tryPushDownOverJoinStep(QueryPlan::Node * parent_node, QueryPlan::
* Additional filter push down optimizations:
* 1. TODO: Support building equivalent sets for more than 2 JOINS. It is possible, but will require more complex analysis step.
* 2. TODO: Support building equivalent sets for JOINs with more than 1 clause.
* 3. TODO: For LEFT/RIGHT JOIN, we can assume that RIGHT/LEFT columns used in filter will be default/NULL constants and
* check if filter will always be false, in those scenario we can transform LEFT/RIGHT JOIN into INNER JOIN and push conditions to both tables.
* 4. TODO: It is possible to pull up filter conditions from LEFT/RIGHT stream and push conditions that use columns from LEFT/RIGHT equivalent sets
* 3. TODO: It is possible to pull up filter conditions from LEFT/RIGHT stream and push conditions that use columns from LEFT/RIGHT equivalent sets
* to RIGHT/LEFT JOIN side.
*/

View File

@ -0,0 +1,22 @@
<test>
<settings>
<join_algorithm>hash</join_algorithm>
</settings>
<create_query>CREATE TABLE test_table_1(id UInt64, value String) ENGINE=MergeTree ORDER BY id</create_query>
<create_query>CREATE TABLE test_table_2(id UInt64, value String) ENGINE=MergeTree ORDER BY id</create_query>
<fill_query>INSERT INTO test_table_1 SELECT (rand64() % 5000000) AS key, toString(key) FROM numbers(5000000)</fill_query>
<fill_query>INSERT INTO test_table_2 SELECT (rand64() % 5000000) AS key, toString(key) FROM numbers(5000000)</fill_query>
<query>SELECT lhs.id, rhs.id, lhs.value, rhs.value FROM test_table_1 AS lhs LEFT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE rhs.value != '' FORMAT Null</query>
<query>SELECT lhs.id, rhs.id, lhs.value, rhs.value FROM test_table_1 AS lhs LEFT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE rhs.value != '' AND rhs.id = 5 FORMAT Null</query>
<query>SELECT lhs.id, rhs.id, lhs.value, rhs.value FROM test_table_1 AS lhs RIGHT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.value != '' FORMAT Null</query>
<query>SELECT lhs.id, rhs.id, lhs.value, rhs.value FROM test_table_1 AS lhs RIGHT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.value != '' AND lhs.id = 5 FORMAT Null</query>
<query>SELECT lhs.id, rhs.id, lhs.value, rhs.value FROM test_table_1 AS lhs FULL JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.value != '' AND rhs.value != ''</query>
<drop_query>DROP TABLE test_table_1</drop_query>
<drop_query>DROP TABLE test_table_2</drop_query>
</test>

View File

@ -1,5 +1,6 @@
SET allow_experimental_analyzer = 1;
SET optimize_move_to_prewhere = 0;
SET query_plan_convert_outer_join_to_inner_join = 0;
DROP TABLE IF EXISTS test_table_1;
CREATE TABLE test_table_1

View File

@ -0,0 +1,225 @@
Expression ((Project names + (Projection + )))
Header: id UInt64
value String
rhs.id UInt64
rhs.value String
Actions: INPUT : 0 -> __table1.id UInt64 : 0
INPUT : 1 -> __table1.value String : 1
INPUT : 2 -> __table2.value String : 2
INPUT : 3 -> __table2.id UInt64 : 3
ALIAS __table1.id :: 0 -> id UInt64 : 4
ALIAS __table1.value :: 1 -> value String : 0
ALIAS __table2.value :: 2 -> rhs.value String : 1
ALIAS __table2.id :: 3 -> rhs.id UInt64 : 2
Positions: 4 0 2 1
Join (JOIN FillRightFirst)
Header: __table1.id UInt64
__table1.value String
__table2.value String
__table2.id UInt64
Type: INNER
Strictness: ALL
Algorithm: HashJoin
Clauses: [(__table1.id) = (__table2.id)]
Expression
Header: __table1.id UInt64
__table1.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table1.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table1.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_1)
Header: __table1.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: notEquals(__table1.id, 0_UInt8) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table1.id UInt64 : 2
FUNCTION notEquals(__table1.id : 2, 0_UInt8 :: 1) -> notEquals(__table1.id, 0_UInt8) UInt8 : 3
Positions: 2 0 3
Expression
Header: __table2.id UInt64
__table2.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table2.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table2.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_2)
Header: __table2.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: notEquals(__table2.id, 0_UInt8) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table2.id UInt64 : 2
FUNCTION notEquals(__table2.id : 2, 0_UInt8 :: 1) -> notEquals(__table2.id, 0_UInt8) UInt8 : 3
Positions: 2 0 3
--
2 Value_2 2 Value_2
--
Expression ((Project names + (Projection + )))
Header: id UInt64
value String
rhs.id UInt64
rhs.value String
Actions: INPUT : 0 -> __table1.id UInt64 : 0
INPUT : 1 -> __table1.value String : 1
INPUT : 2 -> __table2.value String : 2
INPUT : 3 -> __table2.id UInt64 : 3
ALIAS __table1.id :: 0 -> id UInt64 : 4
ALIAS __table1.value :: 1 -> value String : 0
ALIAS __table2.value :: 2 -> rhs.value String : 1
ALIAS __table2.id :: 3 -> rhs.id UInt64 : 2
Positions: 4 0 2 1
Join (JOIN FillRightFirst)
Header: __table1.id UInt64
__table1.value String
__table2.value String
__table2.id UInt64
Type: INNER
Strictness: ALL
Algorithm: HashJoin
Clauses: [(__table1.id) = (__table2.id)]
Expression
Header: __table1.id UInt64
__table1.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table1.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table1.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_1)
Header: __table1.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: notEquals(__table1.id, 0_UInt8) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table1.id UInt64 : 2
FUNCTION notEquals(__table1.id : 2, 0_UInt8 :: 1) -> notEquals(__table1.id, 0_UInt8) UInt8 : 3
Positions: 2 0 3
Expression
Header: __table2.id UInt64
__table2.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table2.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table2.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_2)
Header: __table2.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: notEquals(__table2.id, 0_UInt8) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table2.id UInt64 : 2
FUNCTION notEquals(__table2.id : 2, 0_UInt8 :: 1) -> notEquals(__table2.id, 0_UInt8) UInt8 : 3
Positions: 2 0 3
--
2 Value_2 2 Value_2
--
Expression ((Project names + (Projection + )))
Header: id UInt64
value String
rhs.id UInt64
rhs.value String
Actions: INPUT : 0 -> __table1.id UInt64 : 0
INPUT : 1 -> __table1.value String : 1
INPUT : 2 -> __table2.value String : 2
INPUT : 3 -> __table2.id UInt64 : 3
ALIAS __table1.id :: 0 -> id UInt64 : 4
ALIAS __table1.value :: 1 -> value String : 0
ALIAS __table2.value :: 2 -> rhs.value String : 1
ALIAS __table2.id :: 3 -> rhs.id UInt64 : 2
Positions: 4 0 2 1
Join (JOIN FillRightFirst)
Header: __table1.id UInt64
__table1.value String
__table2.value String
__table2.id UInt64
Type: INNER
Strictness: ALL
Algorithm: HashJoin
Clauses: [(__table1.id) = (__table2.id)]
Expression
Header: __table1.id UInt64
__table1.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table1.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table1.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_1)
Header: __table1.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: and(notEquals(__table1.id, 0_UInt8), notEquals(__table1.id, 0_UInt8)) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table1.id UInt64 : 2
FUNCTION notEquals(__table1.id : 2, 0_UInt8 : 1) -> notEquals(__table1.id, 0_UInt8) UInt8 : 3
FUNCTION notEquals(__table1.id : 2, 0_UInt8 :: 1) -> notEquals(__table1.id, 0_UInt8) UInt8 : 4
FUNCTION and(notEquals(__table1.id, 0_UInt8) :: 4, notEquals(__table1.id, 0_UInt8) :: 3) -> and(notEquals(__table1.id, 0_UInt8), notEquals(__table1.id, 0_UInt8)) UInt8 : 1
Positions: 2 0 1
Expression
Header: __table2.id UInt64
__table2.value String
Actions: INPUT : 1 -> value String : 0
INPUT :: 0 -> __table2.id UInt64 : 1
INPUT :: 2 -> id UInt64 : 2
ALIAS value :: 0 -> __table2.value String : 3
Positions: 1 3
ReadFromMergeTree (default.test_table_2)
Header: __table2.id UInt64
id UInt64
value String
ReadType: Default
Parts: 1
Granules: 1
Prewhere info
Need filter: 1
Prewhere filter
Prewhere filter column: and(notEquals(__table2.id, 0_UInt8), notEquals(__table2.id, 0_UInt8)) (removed)
Actions: INPUT : 0 -> id UInt64 : 0
COLUMN Const(UInt8) -> 0_UInt8 UInt8 : 1
ALIAS id : 0 -> __table2.id UInt64 : 2
FUNCTION notEquals(__table2.id : 2, 0_UInt8 : 1) -> notEquals(__table2.id, 0_UInt8) UInt8 : 3
FUNCTION notEquals(__table2.id : 2, 0_UInt8 :: 1) -> notEquals(__table2.id, 0_UInt8) UInt8 : 4
FUNCTION and(notEquals(__table2.id, 0_UInt8) :: 4, notEquals(__table2.id, 0_UInt8) :: 3) -> and(notEquals(__table2.id, 0_UInt8), notEquals(__table2.id, 0_UInt8)) UInt8 : 1
Positions: 2 0 1
--
2 Value_2 2 Value_2

View File

@ -0,0 +1,44 @@
SET allow_experimental_analyzer = 1;
SET join_algorithm = 'hash';
DROP TABLE IF EXISTS test_table_1;
CREATE TABLE test_table_1
(
id UInt64,
value String
) ENGINE=MergeTree ORDER BY id;
DROP TABLE IF EXISTS test_table_2;
CREATE TABLE test_table_2
(
id UInt64,
value String
) ENGINE=MergeTree ORDER BY id;
INSERT INTO test_table_1 VALUES (1, 'Value_1'), (2, 'Value_2');
INSERT INTO test_table_2 VALUES (2, 'Value_2'), (3, 'Value_3');
EXPLAIN header = 1, actions = 1 SELECT * FROM test_table_1 AS lhs LEFT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE rhs.id != 0;
SELECT '--';
SELECT * FROM test_table_1 AS lhs LEFT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE rhs.id != 0;
SELECT '--';
EXPLAIN header = 1, actions = 1 SELECT * FROM test_table_1 AS lhs RIGHT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.id != 0;
SELECT '--';
SELECT * FROM test_table_1 AS lhs RIGHT JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.id != 0;
SELECT '--';
EXPLAIN header = 1, actions = 1 SELECT * FROM test_table_1 AS lhs FULL JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.id != 0 AND rhs.id != 0;
SELECT '--';
SELECT * FROM test_table_1 AS lhs FULL JOIN test_table_2 AS rhs ON lhs.id = rhs.id WHERE lhs.id != 0 AND rhs.id != 0;
DROP TABLE test_table_1;
DROP TABLE test_table_2;