diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/pom.xml b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/pom.xml
index e07d9d1561a..f3774b43e51 100644
--- a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/pom.xml
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/pom.xml
@@ -71,6 +71,11 @@
legend-engine-pure-runtime-java-extension-compiled-functions-relationalStore-postgresSql-parser
${project.version}
+
+ org.finos.legend.engine
+ legend-engine-xt-relationalStore-sqlDialectTranslation-pure
+ ${project.version}
+
@@ -114,6 +119,11 @@
legend-engine-pure-runtime-java-extension-compiled-functions-relationalStore-postgresSql-parser
${project.version}
+
+ org.finos.legend.engine
+ legend-engine-xt-relationalStore-sqlDialectTranslation-pure
+ ${project.version}
+
@@ -140,6 +150,10 @@
+
+ org.finos.legend.engine
+ legend-engine-pure-runtime-java-extension-compiled-functions-unclassified
+
org.finos.legend.engine
legend-engine-pure-code-compiled-core
@@ -151,7 +165,10 @@
org.finos.legend.engine
legend-engine-pure-runtime-java-extension-compiled-functions-relationalStore-postgresSql-parser
- runtime
+
+
+ org.finos.legend.engine
+ legend-engine-xt-relationalStore-sqlDialectTranslation-pure
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning.definition.json b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning.definition.json
index 88e9192781c..99d20fcd669 100644
--- a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning.definition.json
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning.definition.json
@@ -3,8 +3,18 @@
"pattern": "(meta::external::store::relational::sqlPlanning)(::.*)?",
"dependencies": [
"platform",
+ "platform_dsl_store",
+ "platform_dsl_mapping",
+ "platform_dsl_path",
+ "platform_dsl_graph",
+ "platform_dsl_diagram",
+ "platform_store_relational",
+ "core_functions_standard",
+ "core_functions_unclassified",
+ "core_functions_json",
"core",
"core_external_store_relational_postgres_sql_model",
- "core_external_store_relational_postgres_sql_parser"
+ "core_external_store_relational_postgres_sql_parser",
+ "core_external_store_relational_sql_dialect_translation"
]
}
\ No newline at end of file
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/multiRuleTests.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/multiRuleTests.pure
new file mode 100644
index 00000000000..614276566a4
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/multiRuleTests.pure
@@ -0,0 +1,104 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::pure::extension::*;
+
+
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::multiRuleTests::testJoinAndSubQueryFilterPushDown(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.ProductName AS ProductName\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.TradeDate AS TradeDate,\n' +
+ ' tradetable_3.ProductName AS ProductName\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.tradeDate AS TradeDate\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' ) AS tradetable_3\n' +
+ ' ON (tradetable_1.TradeID = tradetable_3.TradeID)\n' +
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.ProductName AS ProductName\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.TradeDate AS TradeDate,\n' +
+ ' tradetable_3.ProductName AS ProductName\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.tradeDate AS TradeDate\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' WHERE\n' +
+ ' root.ID = 1\n' +
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' WHERE\n' +
+ ' root.ID = 1\n' +
+ ' ) AS tradetable_3\n' +
+ ' ON (tradetable_1.TradeID = tradetable_3.TradeID AND tradetable_3.TradeID = 1)\n' +
+ ' WHERE\n' +
+ ' tradetable_1.TradeID = 1\n' +
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ [
+ meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::subQueryFilterPushDownRule(),
+ meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::joinFilterPushDownRule()
+ ]
+ );
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/ruleBasedTransformation.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/ruleBasedTransformation.pure
new file mode 100644
index 00000000000..5622356ec02
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/ruleBasedTransformation.pure
@@ -0,0 +1,151 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::postgresSql::parser::*;
+import meta::external::store::relational::sqlDialectTranslation::*;
+import meta::external::store::relational::sqlDialectTranslation::postgres::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::utils::*;
+import meta::pure::extension::*;
+
+Class meta::external::store::relational::sqlPlanning::ruleBasedTransformation::TransformedQuery
+{
+ hasChanged: Boolean[1];
+ query: Query[1];
+}
+
+Class <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::RuleBasedSqlTransformer
+{
+ name : String[1];
+ enabledByDefault : Boolean[1];
+ databaseSupport : DatabaseSupport[1];
+
+ transformSqlQuery(query: Query[1], config: SqlPlanningConfig[1], debug: DebugContext[1], extensions: Extension[*])
+ {
+ fail('Needs to be implemented in sub classes'); ^TransformedQuery(hasChanged = false, query = $query);
+ }: TransformedQuery[1];
+}
+
+Class <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::DatabaseSupport
+{
+ isDatabaseTypeSupported(dbType: String[1]) { fail('Needs to be implemented in sub classes'); false; }: Boolean[1];
+}
+
+Class meta::external::store::relational::sqlPlanning::ruleBasedTransformation::AllDatabaseSupport extends DatabaseSupport
+{
+ isDatabaseTypeSupported(dbType: String[1]) { true }: Boolean[1];
+}
+
+Class meta::external::store::relational::sqlPlanning::ruleBasedTransformation::LimitedDatabaseSupport extends DatabaseSupport
+{
+ supportedDatabaseTypes: String[*];
+ isDatabaseTypeSupported(dbType: String[1]) { $dbType->in($this.supportedDatabaseTypes) }: Boolean[1];
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::executeRuleBasedTransformersOnQuery(query: Query[1], config: SqlPlanningConfig[1], debug: DebugContext[1], extensions: Extension[*]): Query[1]
+{
+ let ruleBasedTransformers = $config->fetchInScopeRuleBasedTransformers($extensions);
+ $query->executeRuleBasedTransformersOnQuery($config, $ruleBasedTransformers, $debug, $extensions);
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::executeRuleBasedTransformersOnQuery(query: Query[1], config: SqlPlanningConfig[1], rules: RuleBasedSqlTransformer[*], debug: DebugContext[1], extensions: Extension[*]): Query[1]
+{
+ $query->executeRuleBasedTransformersOnQueryTillFixedPointOrMaxIterations($config, $rules, 1, 10, $debug, $extensions).query
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::executeRuleBasedTransformersOnQueryTillFixedPointOrMaxIterations(query: Query[1], config: SqlPlanningConfig[1], rules: RuleBasedSqlTransformer[*], currentIteration: Integer[1], maxIterations: Integer[1], debug: DebugContext[1], extensions: Extension[*]): TransformedQuery[1]
+{
+ if ($currentIteration > $maxIterations,
+ | ^TransformedQuery(hasChanged = false, query = $query),
+ |
+ let debugPrefix = '[RuleBasedTransformation] Iteration (' + $currentIteration->toString() + '/' + $maxIterations->toString() + ')';
+ print(if(!$debug.debug, |'', | $debug.space + range(40)->map(x | '-')->joinStrings() + $debugPrefix + format(' (%t{yyyy-MM-dd HH:mm::ss.SSS})', now()) + range(40)->map(x | '-')->joinStrings() + '\n'));
+ print(if(!$debug.debug, |'', | $debug.space + 'Rules: ' + $rules.name->joinStrings('[', ', ', ']') + '\n'));
+ print(if(!$debug.debug, |'', | $debug.space + 'Starting Query: ' + $query->printDebugQuery($config, $extensions) + '\n'));
+
+ let transformed = $rules->fold({t, agg |
+ print(if(!$debug.debug, |'', | $debug->indent().space + range(50)->map(x | '-')->joinStrings() + '\n'));
+ print(if(!$debug.debug, |'', | $debug->indent().space + 'Running rule: ' + $t.name + '\n'));
+ let res = $t->executeSubTypeQualifierAndCast('transformSqlQuery', [list($agg.query), list($config), list($debug->indent()), list($extensions)], @TransformedQuery);
+ if ($res.hasChanged,
+ | print(if(!$debug.debug, |'', | $debug->indent().space + 'Rule Result: Query Changed\n'));
+ print(if(!$debug.debug, |'', | $debug->indent().space + 'Updated Query: ' + $res.query->printDebugQuery($config, $extensions) + '\n'));,
+ | print(if(!$debug.debug, |'', | $debug->indent().space + 'Rule Result: Query Unchanged\n'));
+ );
+ ^TransformedQuery(hasChanged = $res.hasChanged || $agg.hasChanged, query = $res.query);
+ }, ^TransformedQuery(hasChanged = false, query = $query));
+
+ print(if(!$debug.debug, |'', | $debug->indent().space + range(50)->map(x | '-')->joinStrings() + '\n'));
+ if ($transformed.hasChanged,
+ | print(if(!$debug.debug, |'', | $debug.space + 'Iteration Result: Query Changed\n'));
+ print(if(!$debug.debug, |'', | $debug.space + 'Updated Query: ' + $transformed.query->printDebugQuery($config, $extensions) + '\n'));,
+ | print(if(!$debug.debug, |'', | $debug.space + 'Iteration Result: Query Unchanged\n'));
+ );
+ print(if(!$debug.debug, |'', | $debug.space + range(40)->map(x | '-')->joinStrings() + $debugPrefix + format(' (%t{yyyy-MM-dd HH:mm::ss.SSS})', now()) + range(40)->map(x | '-')->joinStrings() + '\n\n'));
+
+ if ($transformed.hasChanged,
+ | $transformed.query->executeRuleBasedTransformersOnQueryTillFixedPointOrMaxIterations($config, $rules, $currentIteration + 1, $maxIterations, $debug, $extensions),
+ | $transformed
+ );
+ )
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::fetchInScopeRuleBasedTransformers(config: SqlPlanningConfig[1], extensions: Extension[*]): RuleBasedSqlTransformer[*]
+{
+ let defaultTransformers = meta::external::store::relational::sqlPlanning::ruleBasedTransformation::defaultRuleBasedSqlTransformers();
+ let extensionTransformers = $extensions->map(e | $e.moduleExtension('SqlPlanning')->cast(@SqlPlanningModuleExtension).sqlPlanning_ruleBasedTransformation_extraRuleBasedSqlTransformers);
+
+ let allTransformers = $defaultTransformers->concatenate($extensionTransformers);
+
+ let filteredTransformers = $allTransformers->filter({t |
+ if ($t.databaseSupport->meta::external::store::relational::sqlPlanning::utils::executeSubTypeQualifierAndCast('isDatabaseTypeSupported', list($config.dbType), @Boolean) == true,
+ | // Transformer supported for database type
+ if ($t.enabledByDefault,
+ | // TODO: Check if excluded in connection
+ true,
+ | // TODO: Check if included in connection
+ false
+ ),
+ | false
+ )
+ });
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::defaultRuleBasedSqlTransformers(): RuleBasedSqlTransformer[*]
+{
+ [
+ // meta::external::store::relational::sqlPlanning::ruleBasedTransformation::filterPushDown::filterPushDownSqlTransformer()
+ ]
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::runSqlRuleBasedTransformationTest(originalQuery: String[1], expectedQuery: String[1], rules: RuleBasedSqlTransformer[*]): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest($originalQuery, $expectedQuery, $rules, ^SqlPlanningConfig(dbType = 'Postgres'), postgresSqlDialectExtension())
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::runSqlRuleBasedTransformationTest(originalQuery: String[1], expectedQuery: String[1], rules: RuleBasedSqlTransformer[*], config: SqlPlanningConfig[1], extensions: Extension[*]): Boolean[1]
+{
+ let debug = noDebug();
+
+ let parsedQuery = parseSqlStatement($originalQuery)->cast(@Query);
+ print(if(!$debug.debug, |'', | $debug.space + '>[RuleBasedTransformationTest] Original Query: \n' + $parsedQuery->printDebugQuery($config, true, $extensions) + '\n'));
+
+ let transformedQuery = $parsedQuery->executeRuleBasedTransformersOnQuery($config, $rules, $debug, $extensions);
+ let resultSqlString = $transformedQuery->printDebugQuery($config, true, $extensions);
+ print(if(!$debug.debug, |'', | $debug.space + '>[RuleBasedTransformationTest] Transformed Query: \n' + $resultSqlString + '\n'));
+
+ assertEquals($expectedQuery, $resultSqlString);
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDown.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDown.pure
new file mode 100644
index 00000000000..839cd47d1b5
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDown.pure
@@ -0,0 +1,167 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::*;
+import meta::pure::extension::*;
+
+Class meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::JoinFilterPushDownRule extends RuleBasedSqlTransformer
+[
+ $this.name == 'JoinFilterPushDown'
+]
+{
+ transformSqlQuery(query: Query[1], config: SqlPlanningConfig[1], debug: DebugContext[1], extensions: Extension[*])
+ {
+ $query->pushFiltersIntoJoins()
+ }: TransformedQuery[1];
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::joinFilterPushDownRule(): JoinFilterPushDownRule[1]
+{
+ ^JoinFilterPushDownRule
+ (
+ name = 'JoinFilterPushDown',
+ enabledByDefault = true,
+ databaseSupport = ^AllDatabaseSupport()
+ )
+}
+
+// ---------------------------------------------------------------------------------------------------------------------------
+
+###Pure
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::*;
+import meta::external::store::relational::sqlPlanning::utils::*;
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::pushFiltersIntoJoins(query: Query[1]): TransformedQuery[1]
+{
+ let transformed = $query->transformNodeRecursivelyWithChangeTracking(pushFiltersIntoJoinsTransformFunction());
+ ^TransformedQuery
+ (
+ hasChanged = $transformed.hasChanged,
+ query = $transformed.result->cast(@Query)
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::pushFiltersIntoJoinsTransformFunction(): Function<{Node[1]->NodeTransformationWithChangeTracking[1]}>[1]
+{
+ {node: Node[1] |
+ $node->match([
+ {qs: QuerySpecification[1] |
+ if ($qs->isFromSupportedForJoinFilterPushDown(),
+ | let joins = $qs->extractOrderedJoins();
+ let filterPairs = $qs.where->map(e | $e->identifySingleColumnFilterGroups());
+ let result = $joins->fold({join, agg | $join->tryAddFiltersToJoin($agg)}, ^JoinFilterPushDownIntermediateResult(filterPairs = $filterPairs));
+ let changed = $result.joins.hasChanged->or();
+ if ($changed,
+ | let newFrom = $result.joins.result->tail()->cast(@Join)->fold({j, agg | ^$j(left = $agg)}, $result.joins.result->at(0)->cast(@Join));
+ changed(^$qs(from = $newFrom));,
+ | unchanged($qs)
+ );,
+ | unchanged($qs)
+ )
+ },
+ {n: Node[1] | unchanged($n)}
+ ])
+ }
+}
+
+Class <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::JoinFilterPushDownIntermediateResult
+{
+ joins: NodeTransformationWithChangeTracking[*];
+ filterPairs: Pair[*];
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tryAddFiltersToJoin(join: Join[1], current: JoinFilterPushDownIntermediateResult[1]): JoinFilterPushDownIntermediateResult[1]
+{
+ let joinCriteria = $join.criteria->toOne()->cast(@JoinOn);
+ let joinExpr = $joinCriteria.expression;
+ let targetAlias = $join.right->cast(@AliasedRelation).alias;
+ let inScopeFilterPairs = $current.filterPairs->filter(fp | $fp.first.name.parts->size() == 2)->filter(fp | $fp.first.name.parts->at(0) != $targetAlias); // Filter pairs for not target alias columns
+ let updatedExprWithNewFilterPairs = $joinExpr->tryAddFiltersToJoinExpression($inScopeFilterPairs);
+ if ($updatedExprWithNewFilterPairs.second.values->isEmpty(),
+ | // No update happened
+ ^$current(joins += unchanged($join)),
+ | // Expression updated
+ let newJoin = ^$join(criteria = ^$joinCriteria(expression = $updatedExprWithNewFilterPairs.first));
+ ^$current(joins += changed($newJoin), filterPairs += $updatedExprWithNewFilterPairs.second.values);
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tryAddFiltersToJoinExpression(expr: meta::external::query::sql::metamodel::Expression[1], filterPairs: Pair[*]): Pair>>[1]
+{
+ $expr->tryAddFiltersToJoinExpression($expr, $filterPairs)
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tryAddFiltersToJoinExpression(expr: meta::external::query::sql::metamodel::Expression[1], fullJoinExpr: meta::external::query::sql::metamodel::Expression[1], filterPairs: Pair[*]): Pair>>[1]
+{
+ if ($expr->isEqualsExpression(),
+ | let equals = $expr->cast(@ComparisonExpression);
+ [pair($equals.left, $equals.right), pair($equals.right, $equals.left)]
+ ->filter(p | $p.first->instanceOf(QualifiedNameReference) && $p.second->instanceOf(QualifiedNameReference))
+ ->fold({p, agg1 |
+ $filterPairs
+ ->filter(fp | $fp.first == $p.first)
+ ->fold({fp, agg2 |
+ let transformFunc = {n: Node[1] | if($n == $p.first, | changed($p.second), | unchanged($n))};
+ let newExpr = $fp.second->transformNodeRecursivelyWithChangeTracking($transformFunc).result->cast(@meta::external::query::sql::metamodel::Expression);
+ let joinAlreadyHasExpr = $fullJoinExpr->addClauseIfNotExisting($newExpr).hasChanged;
+ if ($joinAlreadyHasExpr,
+ | let updatedExpr = ^LogicalBinaryExpression(left = $agg2.first, right = $newExpr, type = LogicalBinaryType.AND);
+ pair($updatedExpr, $agg2.second.values->concatenate(pair($p.second->cast(@QualifiedNameReference), $newExpr))->list());,
+ | pair($expr, list([]->cast(@Pair)))
+ );
+ }, $agg1)
+ }, pair($expr, list([]->cast(@Pair))));,
+ |
+
+ if ($expr->isAndExpression(),
+ | let andExpr = $expr->cast(@LogicalBinaryExpression);
+ let updatedLeft = $andExpr.left->tryAddFiltersToJoinExpression($fullJoinExpr, $filterPairs);
+ let updatedRight = $andExpr.right->tryAddFiltersToJoinExpression($fullJoinExpr, $filterPairs);
+ pair(^$andExpr(left = $updatedLeft.first, right = $updatedRight.first), $updatedLeft.second.values->concatenate($updatedRight.second.values)->list());,
+
+ | pair($expr, list([]->cast(@Pair)))
+ ))
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::isFromSupportedForJoinFilterPushDown(qs: QuerySpecification[1]): Boolean[1]
+{
+ ($qs.from->size() == 1) && $qs.from->toOne()->instanceOf(Join) && $qs.from->toOne()->cast(@Join)->isJoinSupportedForJoinFilterPushDown()
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::isJoinSupportedForJoinFilterPushDown(j: Join[1]): Boolean[1]
+{
+ $j.criteria->isNotEmpty() && $j.criteria->toOne()->instanceOf(JoinOn) &&
+ $j.type->in([JoinType.INNER, JoinType.LEFT]) &&
+ $j.left->match([a: AliasedRelation[1] | true, sj: Join[1] | $sj->isJoinSupportedForJoinFilterPushDown(), a: Any[*] | false]) &&
+ $j.right->instanceOf(AliasedRelation)
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::extractOrderedJoins(qs: QuerySpecification[1]): Join[1..*]
+{
+ extractOrderedJoins($qs.from->toOne()->cast(@Join))
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::extractOrderedJoins(j: Join[1]): Join[1..*]
+{
+ $j.left->match([
+ l: Join[1] | $l->extractOrderedJoins(),
+ a: Any[*] | []
+ ])->concatenate($j)->toOneMany()
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDownTests.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDownTests.pure
new file mode 100644
index 00000000000..cbd1bf17531
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/joinFilterPushDown/joinFilterPushDownTests.pure
@@ -0,0 +1,277 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::*;
+import meta::pure::extension::*;
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testSimplePushDown(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' personTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' addressTable AS address\n' +
+ ' ON (root.ID = address.PERSON_ID)\n' +
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' personTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' addressTable AS address\n' +
+ ' ON (root.ID = address.PERSON_ID AND address.PERSON_ID = 2)\n' + // Filter pushed into join condition
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ joinFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testPushDownOfComplexOps(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id)\n' +
+ 'WHERE\n' +
+ ' (root.ID > 100 + 2 OR root.ID < 50) AND root.QUANTITY > 22',
+
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id AND (v.trade_id > 100 + 2 OR v.trade_id < 50))\n' + // Complex filters pushed into join condition
+ 'WHERE\n' +
+ ' (root.ID > 100 + 2 OR root.ID < 50) AND root.QUANTITY > 22',
+
+ joinFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testNoPushDownWithOrInFilter(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id)\n' +
+ 'WHERE\n' +
+ ' (root.ID > 100 + 2 OR root.ID < 50) OR root.QUANTITY > 22',
+
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id)\n' + // No push down
+ 'WHERE\n' +
+ ' root.ID > 100 + 2 OR root.ID < 50 OR root.QUANTITY > 22',
+
+ joinFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testNoPushDownWithOrInJoin(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id OR root.ID = 2)\n' +
+ 'WHERE\n' +
+ ' root.ID = 100',
+
+ 'SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.quantity AS Quantity,\n' +
+ ' v.maxTradeEventDate AS LastEventDate\n' +
+ 'FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.trade_id AS trade_id,\n' +
+ ' max(root.eventDate) AS maxTradeEventDate\n' +
+ ' FROM\n' +
+ ' tradeEventTable AS root\n' +
+ ' GROUP BY\n' +
+ ' root.trade_id\n' +
+ ' ) AS v\n' +
+ ' ON (root.ID = v.trade_id OR root.ID = 2)\n' + // No push down
+ 'WHERE\n' +
+ ' root.ID = 100',
+
+ joinFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testMultiJoinPushDown(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' firmTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' personTable AS person\n' +
+ ' ON (root.ID = person.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' personAddressTable AS personAddress\n' +
+ ' ON (person.ID = personAddress.PERSON_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressTable AS firmAddress\n' +
+ ' ON (root.ID = firmAddress.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressStreetTable AS firmAddressStreet\n' +
+ ' ON (firmAddress.FIRM_ID = firmAddressStreet.FIRM_ID)\n' +
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' firmTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' personTable AS person\n' +
+ ' ON (root.ID = person.FIRM_ID AND person.FIRM_ID = 2)\n' + // Push down
+ ' LEFT OUTER JOIN\n' +
+ ' personAddressTable AS personAddress\n' +
+ ' ON (person.ID = personAddress.PERSON_ID)\n' + // No push down
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressTable AS firmAddress\n' +
+ ' ON (root.ID = firmAddress.FIRM_ID AND firmAddress.FIRM_ID = 2)\n' + // Push down
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressStreetTable AS firmAddressStreet\n' +
+ ' ON (firmAddress.FIRM_ID = firmAddressStreet.FIRM_ID AND firmAddressStreet.FIRM_ID = 2)\n' + // Push down
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ joinFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::joinFilterPushDown::tests::testNoPushDownWithRightOrFullJoin(): Boolean[1]
+{
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' firmTable AS root\n' +
+ ' RIGHT OUTER JOIN\n' +
+ ' personTable AS person\n' +
+ ' ON (root.ID = person.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' personAddressTable AS personAddress\n' +
+ ' ON (person.ID = personAddress.PERSON_ID)\n' +
+ ' FULL OUTER JOIN\n' +
+ ' firmAddressTable AS firmAddress\n' +
+ ' ON (root.ID = firmAddress.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressStreetTable AS firmAddressStreet\n' +
+ ' ON (firmAddress.FIRM_ID = firmAddressStreet.FIRM_ID)\n' +
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' firmTable AS root\n' +
+ ' RIGHT OUTER JOIN\n' +
+ ' personTable AS person\n' +
+ ' ON (root.ID = person.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' personAddressTable AS personAddress\n' +
+ ' ON (person.ID = personAddress.PERSON_ID)\n' +
+ ' FULL OUTER JOIN\n' +
+ ' firmAddressTable AS firmAddress\n' +
+ ' ON (root.ID = firmAddress.FIRM_ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmAddressStreetTable AS firmAddressStreet\n' +
+ ' ON (firmAddress.FIRM_ID = firmAddressStreet.FIRM_ID)\n' +
+ 'WHERE\n' +
+ ' root.ID = 2',
+
+ joinFilterPushDownRule()
+ );
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDown.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDown.pure
new file mode 100644
index 00000000000..2ee36e39598
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDown.pure
@@ -0,0 +1,205 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::*;
+import meta::pure::extension::*;
+
+Class meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::SubQueryFilterPushDownRule extends RuleBasedSqlTransformer
+[
+ $this.name == 'SubQueryFilterPushDown'
+]
+{
+ transformSqlQuery(query: Query[1], config: SqlPlanningConfig[1], debug: DebugContext[1], extensions: Extension[*])
+ {
+ $query->pushFiltersIntoSubQueries()
+ }: TransformedQuery[1];
+}
+
+function meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::subQueryFilterPushDownRule(): SubQueryFilterPushDownRule[1]
+{
+ ^SubQueryFilterPushDownRule
+ (
+ name = 'SubQueryFilterPushDown',
+ enabledByDefault = true,
+ databaseSupport = ^AllDatabaseSupport()
+ )
+}
+
+// ---------------------------------------------------------------------------------------------------------------------------
+
+###Pure
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::*;
+import meta::external::store::relational::sqlPlanning::utils::*;
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::pushFiltersIntoSubQueries(query: Query[1]): TransformedQuery[1]
+{
+ let transformed = $query->transformNodeRecursivelyWithChangeTracking(pushFiltersIntoSubQueriesTransformFunction());
+ ^TransformedQuery
+ (
+ hasChanged = $transformed.hasChanged,
+ query = $transformed.result->cast(@Query)
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::pushFiltersIntoSubQueriesTransformFunction(): Function<{Node[1]->NodeTransformationWithChangeTracking[1]}>[1]
+{
+ {node: Node[1] |
+ $node->match([
+ {qs: QuerySpecification[1] |
+ // Try pushing filters into root subquery
+ if ($qs.where->isNotEmpty() && ($qs.from->size() == 1),
+ | let rootRelationWithAlias = $qs.from->toOne()->findRootRelationWithAlias();
+ $rootRelationWithAlias.relation->match([
+ {s: TableSubquery[1] |
+ let res = $s->pushFiltersIntoTableSubquery($rootRelationWithAlias.alias, $qs.where->toOne());
+ if ($res.first,
+ | changed(^$qs(from = $qs.from->toOne()->replaceRootTableSubquery($res.second))),
+ | unchanged($qs)
+ );
+ },
+ r: Relation[1] | unchanged($qs)
+ ]);,
+ | unchanged($qs)
+ )
+ },
+ {join: Join[1] |
+ // Try pushing filters into joined subquery
+ if ($join.criteria->isNotEmpty() && $join.criteria->toOne()->instanceOf(JoinOn) && $join.type->in([JoinType.INNER, JoinType.LEFT]),
+ | let rightRelationWithAlias = $join.right->match([
+ a: AliasedRelation[1] | ^RelationWithAlias(relation = $a.relation, alias = $a.alias),
+ r: Relation[1] | ^RelationWithAlias(relation = $r, alias = [])
+ ]);
+ $rightRelationWithAlias.relation->match([
+ {s: TableSubquery[1] |
+ let res = $s->pushFiltersIntoTableSubquery($rightRelationWithAlias.alias, $join.criteria->toOne()->cast(@JoinOn).expression);
+ if ($res.first,
+ | let rightTransformed = $join.right->match([
+ a: AliasedRelation[1] | ^$a(relation = $res.second),
+ r: Relation[1] | $res.second
+ ]);
+ changed(^$join(right = $rightTransformed));,
+ | unchanged($join)
+ );
+ },
+ r: Relation[1] | unchanged($join)
+ ]);,
+ | unchanged($join)
+ )
+ },
+ {n: Node[1] | unchanged($n)}
+ ])
+ }
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::pushFiltersIntoTableSubquery(t: TableSubquery[1], alias: String[0..1], filterClause: meta::external::query::sql::metamodel::Expression[1]): Pair[1]
+{
+ if ($alias->isNotEmpty(),
+ | let singleColumnFilterGroups = $filterClause->identifySingleColumnFilterGroups();
+ let filterGroupsForAlias = $singleColumnFilterGroups->filter(fg | ($fg.first.name.parts->size() == 2) && ($fg.first.name.parts->at(0) == $alias->toOne()));
+ if ($filterGroupsForAlias->isNotEmpty(),
+ | if ($t.query->isQueryPlainQuerySpecification(),
+ | let subQuery = $t.query;
+ let subQuerySpec = $subQuery.queryBody->cast(@QuerySpecification);
+ let subQuerySpecHasLimitOrOffset = $subQuerySpec.limit->isNotEmpty() || $subQuerySpec.offset->isNotEmpty();
+ let subQuerySpecHasWindowColumns = $subQuerySpec->fetchAllNodesRecursivelyExcludeSubQueries()->get($subQuerySpec)->exists(n | $n->instanceOf(meta::external::query::sql::metamodel::Window));
+ let cannotPushFiltersIntoSubQuery = $subQuerySpecHasLimitOrOffset || $subQuerySpecHasWindowColumns;
+ if ($cannotPushFiltersIntoSubQuery,
+ | pair(false, $t),
+ | let newSubQuerySpec = $filterGroupsForAlias->fold({fg, agg | let res = $agg.second->pushSingleFilter($fg); pair($agg.first || $res.first, $res.second);}, pair(false, $subQuerySpec));
+ if ($newSubQuerySpec.first,
+ | pair(true, ^$t(query = ^$subQuery(queryBody = $newSubQuerySpec.second))),
+ | pair(false, $t)
+ );
+ );,
+ | pair(false, $t)
+ ),
+ | pair(false, $t)
+ );,
+ | pair(false, $t)
+ )
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::pushSingleFilter(qs: QuerySpecification[1], filterGroup: Pair[1]): Pair[1]
+{
+ let filterColumnName = $filterGroup.first.name.parts->at(1);
+
+ let groupByExists = $qs.groupBy->isNotEmpty();
+
+ let selectCol = $qs.select.selectItems->filter(x | $x->match([
+ a:SingleColumn[1] | ($a.alias == $filterColumnName) && $a.expression->instanceOf(QualifiedNameReference), // Can relax the check for expression just being a reference?
+ a:Any[*] | false
+ ]));
+
+ let groupByNames = $qs.groupBy
+ ->filter(column | $column->instanceOf(QualifiedNameReference) && ($column->cast(@QualifiedNameReference).name.parts->size() == 1))
+ ->map(column | $column->cast(@QualifiedNameReference).name.parts->at(0));
+
+ let isGroupingColumn = or(
+ $groupByNames->contains($filterColumnName),
+ ($selectCol->size() == 1) && $qs.groupBy->exists(x | $x == $selectCol->toOne()->cast(@SingleColumn).expression)
+ );
+
+ let opToUpdate = if ($groupByExists && (!$isGroupingColumn), | $qs.having, | $qs.where);
+
+ let newFilter = if ($selectCol->size() == 1,
+ | let toReplaceWith = $selectCol->toOne()->cast(@SingleColumn).expression;
+ let transformFunc = {n: Node[1] | if($n == $filterGroup.first, | changed($toReplaceWith), | unchanged($n))};
+ $filterGroup.second->transformNodeRecursivelyWithChangeTracking($transformFunc).result->cast(@meta::external::query::sql::metamodel::Expression);,
+ | []
+ );
+
+ if ($newFilter->isEmpty(),
+ | pair(false, $qs),
+ | let updatedOp = if($opToUpdate->size() == 1, | $opToUpdate->toOne()->addClauseIfNotExisting($newFilter->toOne()), | changed($newFilter->toOne()));
+ if ($updatedOp.hasChanged,
+ | if ($groupByExists && (!$isGroupingColumn),
+ | pair(true, ^$qs(having = $updatedOp.result->cast(@meta::external::query::sql::metamodel::Expression))),
+ | pair(true, ^$qs(where = $updatedOp.result->cast(@meta::external::query::sql::metamodel::Expression)))
+ ),
+ | pair(false, $qs)
+ );
+ );
+}
+
+Class <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::RelationWithAlias
+{
+ relation: Relation[1];
+ alias: String[0..1];
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::findRootRelationWithAlias(rel: Relation[1]): RelationWithAlias[1]
+{
+ // Needs to be in sync with below function
+ $rel->match([
+ a: AliasedRelation[1] | ^RelationWithAlias(relation = $a.relation, alias = $a.alias),
+ j: Join[1] | $j.left->findRootRelationWithAlias(),
+ r: Relation[1] | ^RelationWithAlias(relation = $r)
+ ])
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::replaceRootTableSubquery(rel: Relation[1], replacement: TableSubquery[1]): Relation[1]
+{
+ // Needs to be in sync with above function
+ $rel->match([
+ a: AliasedRelation[1] | ^$a(relation = $replacement),
+ j: Join[1] | ^$j(left = $j.left->replaceRootTableSubquery($replacement)),
+ r: TableSubquery[1] | $replacement
+ ])
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDownTests.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDownTests.pure
new file mode 100644
index 00000000000..ba5f8aeeac8
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/ruleBasedTransformation/rules/subQueryFilterPushDown/subQueryFilterPushDownTests.pure
@@ -0,0 +1,717 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::*;
+import meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::*;
+import meta::pure::extension::*;
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testSimplePushDown(): Boolean[1]
+{
+ // Simple filter push down
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.AGE = 22\n' + // Filter pushed into subquery
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownWithDifferentColumnNameInSubQuery(): Boolean[1]
+{
+ // Different column names in subquery
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.first_name AS FIRSTNAME,\n' +
+ ' root.last_name AS LASTNAME,\n' +
+ ' root.age_int AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.first_name AS FIRSTNAME,\n' +
+ ' root.last_name AS LASTNAME,\n' +
+ ' root.age_int AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.age_int = 22\n' + // Filter pushed into subquery with changed column name
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownWithExistingFilterInSubQuery(): Boolean[1]
+{
+ // Filter push down with existing filter
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.FIRSTNAME = \'Peter\'\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.FIRSTNAME = \'Peter\' AND root.AGE = 22\n' + // Filter pushed into subquery with AND operation
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testNoPushDownWithWildcardInSubQuery(): Boolean[1]
+{
+ // No filter pushdown with * columns in subquery
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' *\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' *\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownWithJoin(): Boolean[1]
+{
+ // Additional joins
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.first_name AS FIRSTNAME,\n' +
+ ' root.last_name AS LASTNAME,\n' +
+ ' root.age_int AS AGE,\n' +
+ ' root.firm_id AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmTable AS firm\n' +
+ ' ON (root.FIRMID = firm.ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' addressTable AS address\n' +
+ ' ON (firm.ADDRESSID = address.ID)\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.first_name AS FIRSTNAME,\n' +
+ ' root.last_name AS LASTNAME,\n' +
+ ' root.age_int AS AGE,\n' +
+ ' root.firm_id AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.age_int = 22\n' + // Filter pushed into subquery
+ ' ) AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' firmTable AS firm\n' +
+ ' ON (root.FIRMID = firm.ID)\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' addressTable AS address\n' +
+ ' ON (firm.ADDRESSID = address.ID)\n' +
+ 'WHERE\n' +
+ ' root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownOfComplexOperations(): Boolean[1]
+{
+ // Filter push down of complex operations
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)\n' + // Complex Filter pushed into subquery
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownOfOperationsOnMultipleColumns(): Boolean[1]
+{
+ // Filter push down of operations on multiple columns
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' (len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)) AND root.AGE = 22 AND len(root.FIRSTNAME) >= 0',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' (len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)) AND root.AGE = 22 AND len(root.FIRSTNAME) >= 0\n' + // Filters on multiple columns pushed into subquery
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' (len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10)) AND root.AGE = 22 AND len(root.FIRSTNAME) >= 0',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testNoPushdownForOrClauses(): Boolean[1]
+{
+ // No push down for OR clauses
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10) OR root.AGE = 22',
+
+ 'SELECT\n' +
+ ' root.*\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS root\n' +
+ 'WHERE\n' +
+ ' len(root.FIRSTNAME) = 0 OR (root.FIRSTNAME ~~ \'J%\' AND len(root.FIRSTNAME) < 10) OR root.AGE = 22',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownIntoJoinedSubQuery(): Boolean[1]
+{
+ // Filter push down into joined subquery (left join)
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.AGE = 22\n' + // Filter push into joined subquery
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ subQueryFilterPushDownRule()
+ );
+
+ // Filter push down into joined subquery (inner join)
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' WHERE\n' +
+ ' root.AGE = 22\n' + // Filter push into joined subquery
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testNoPushDownIntoJoinedSubQueryForRightFullJoins(): Boolean[1]
+{
+ // No push down into joined subquery (right join)
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' RIGHT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' RIGHT OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ subQueryFilterPushDownRule()
+ );
+
+ // No push down into joined subquery (full outer join)
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' FULL OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ 'SELECT\n' +
+ ' *\n' +
+ 'FROM\n' +
+ ' firmTable AS firm\n' +
+ ' FULL OUTER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.FIRSTNAME AS FIRSTNAME,\n' +
+ ' root.LASTNAME AS LASTNAME,\n' +
+ ' root.AGE AS AGE,\n' +
+ ' root.FIRMID AS FIRMID\n' +
+ ' FROM\n' +
+ ' personTable AS root\n' +
+ ' ) AS person\n' +
+ ' ON (firm.ID = person.FIRMID AND person.AGE = 22)',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownOnRootAndJoinedSubQueries(): Boolean[1]
+{
+ // Filter push down on both root and joined subqueries
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.ProductName AS ProductName\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.TradeDate AS TradeDate,\n' +
+ ' tradetable_3.ProductName AS ProductName\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.tradeDate AS TradeDate\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' ) AS tradetable_3\n' +
+ ' ON (tradetable_1.TradeID = tradetable_3.TradeID AND tradetable_3.TradeID = 1)\n' +
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.ProductName AS ProductName\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.TradeDate AS TradeDate,\n' +
+ ' tradetable_3.ProductName AS ProductName\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' root.tradeDate AS TradeDate\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' WHERE\n' +
+ ' root.ID = 1\n' + // Added filter
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' WHERE\n' +
+ ' root.ID = 1\n' + // Added filter
+ ' ) AS tradetable_3\n' +
+ ' ON (tradetable_1.TradeID = tradetable_3.TradeID AND tradetable_3.TradeID = 1)\n' +
+ ' WHERE\n' +
+ ' tradetable_1.TradeID = 1\n' + // Added filter
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownPartialRootAndJoinedSubQueries(): Boolean[1]
+{
+ // Filter push down partial with root and joined subqueries
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.ProductName AS ProductName,\n' +
+ ' tradetable_0.CUSIP AS CUSIP\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.ProductName AS ProductName,\n' +
+ ' producttable_1.CUSIP AS CUSIP\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.NAME AS ProductName,\n' +
+ ' synonymtable_0.NAME AS CUSIP\n' +
+ ' FROM\n' +
+ ' productSchema.productTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.synonymTable AS synonymtable_0\n' +
+ ' ON (synonymtable_0.PRODID = root.ID AND synonymtable_0.TYPE = \'CUSIP\')\n' +
+ ' ) AS producttable_1\n' +
+ ' ON (tradetable_1.ProductName = producttable_1.ProductName)\n' +
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ 'SELECT\n' +
+ ' tradetable_0.TradeID AS TradeID,\n' +
+ ' tradetable_0.ProductName AS ProductName,\n' +
+ ' tradetable_0.CUSIP AS CUSIP\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' tradetable_1.TradeID AS TradeID,\n' +
+ ' tradetable_1.ProductName AS ProductName,\n' +
+ ' producttable_1.CUSIP AS CUSIP\n' +
+ ' FROM\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.ID AS TradeID,\n' +
+ ' producttable_0.NAME AS ProductName\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' WHERE\n' +
+ ' root.ID = 1\n' + // Added filter
+ ' ) AS tradetable_1\n' +
+ ' INNER JOIN\n' +
+ ' (\n' +
+ ' SELECT\n' +
+ ' root.NAME AS ProductName,\n' +
+ ' synonymtable_0.NAME AS CUSIP\n' +
+ ' FROM\n' +
+ ' productSchema.productTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.synonymTable AS synonymtable_0\n' +
+ ' ON (synonymtable_0.PRODID = root.ID AND synonymtable_0.TYPE = \'CUSIP\')\n' +
+ ' ) AS producttable_1\n' +
+ ' ON (tradetable_1.ProductName = producttable_1.ProductName)\n' +
+ ' WHERE\n' +
+ ' tradetable_1.TradeID = 1\n' + // Added filter
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeID = 1',
+
+ subQueryFilterPushDownRule()
+ );
+}
+
+function <> meta::external::store::relational::sqlPlanning::ruleBasedTransformation::subQueryFilterPushDown::tests::testPushDownWithGroupBy(): Boolean[1]
+{
+ // Filter push down with group by (filters to where clause)
+ runSqlRuleBasedTransformationTest(
+ 'SELECT\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.Product AS Product,\n' +
+ ' tradetable_0.TradeCount AS TradeCount,\n' +
+ ' tradetable_0.QtySum AS QtySum\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT DISTINCT\n' +
+ ' root.tradeDate AS TradeDate,\n' +
+ ' producttable_0.NAME AS Product,\n' +
+ ' count(root.ID) AS TradeCount,\n' +
+ ' sum(root.quantity) AS QtySum\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' GROUP BY\n' +
+ ' TradeDate,\n' +
+ ' Product\n' +
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeDate IS NOT NULL AND tradetable_0.Product = \'Product A\' AND tradetable_0.TradeCount > 2 AND tradetable_0.QtySum > 20',
+
+ 'SELECT\n' +
+ ' tradetable_0.TradeDate AS TradeDate,\n' +
+ ' tradetable_0.Product AS Product,\n' +
+ ' tradetable_0.TradeCount AS TradeCount,\n' +
+ ' tradetable_0.QtySum AS QtySum\n' +
+ 'FROM\n' +
+ ' (\n' +
+ ' SELECT DISTINCT\n' +
+ ' root.tradeDate AS TradeDate,\n' +
+ ' producttable_0.NAME AS Product,\n' +
+ ' count(root.ID) AS TradeCount,\n' +
+ ' sum(root.quantity) AS QtySum\n' +
+ ' FROM\n' +
+ ' tradeTable AS root\n' +
+ ' LEFT OUTER JOIN\n' +
+ ' productSchema.productTable AS producttable_0\n' +
+ ' ON (root.prodId = producttable_0.ID)\n' +
+ ' WHERE\n' +
+ ' root.tradeDate IS NOT NULL AND producttable_0.NAME = \'Product A\'\n' + // Filters on group by columns added
+ ' GROUP BY\n' +
+ ' TradeDate,\n' +
+ ' Product\n' + // having clause not added as there is a check to see column expression is only a reference (which is not the case with aggregations)
+ ' ) AS tradetable_0\n' +
+ 'WHERE\n' +
+ ' tradetable_0.TradeDate IS NOT NULL AND tradetable_0.Product = \'Product A\' AND tradetable_0.TradeCount > 2 AND tradetable_0.QtySum > 20',
+
+ subQueryFilterPushDownRule()
+ );
+}
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/sqlPlanner.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/sqlPlanner.pure
index bd4e1f85afa..de5c7951490 100644
--- a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/sqlPlanner.pure
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/sqlPlanner.pure
@@ -16,6 +16,14 @@ import meta::external::query::sql::metamodel::*;
import meta::external::store::relational::sqlPlanning::*;
import meta::pure::extension::*;
+Class meta::external::store::relational::sqlPlanning::SqlPlanningModuleExtension extends ModuleExtension
+[
+ $this.module == 'SqlPlanning'
+]
+{
+ sqlPlanning_ruleBasedTransformation_extraRuleBasedSqlTransformers : meta::external::store::relational::sqlPlanning::ruleBasedTransformation::RuleBasedSqlTransformer[*];
+}
+
Class meta::external::store::relational::sqlPlanning::SqlPlanningConfig
{
dbType : String[1];
diff --git a/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/utils.pure b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/utils.pure
new file mode 100644
index 00000000000..9857b48476b
--- /dev/null
+++ b/legend-engine-xts-relationalStore/legend-engine-xt-relationalStore-generation/legend-engine-xt-relationalStore-pure/legend-engine-xt-relationalStore-sqlPlanning-pure/src/main/resources/core_external_store_relational_sql_planning/utils.pure
@@ -0,0 +1,167 @@
+// Copyright 2024 Goldman Sachs
+//
+// Licensed under the Apache License, Version 2.0 (the "License");
+// you may not use this file except in compliance with the License.
+// You may obtain a copy of the License at
+//
+// http://www.apache.org/licenses/LICENSE-2.0
+//
+// Unless required by applicable law or agreed to in writing, software
+// distributed under the License is distributed on an "AS IS" BASIS,
+// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
+// See the License for the specific language governing permissions and
+// limitations under the License.
+
+import meta::external::query::sql::metamodel::*;
+import meta::external::store::relational::sqlDialectTranslation::*;
+import meta::external::store::relational::sqlPlanning::*;
+import meta::external::store::relational::sqlPlanning::utils::*;
+import meta::pure::extension::*;
+
+function meta::external::store::relational::sqlPlanning::utils::executeSubTypeQualifierAndCast(instance: Any[1], qualifierName: String[1], params: List[*], castTo: T[1]): T[1]
+{
+ let instanceType = $instance->genericType().rawType->toOne()->cast(@Class);
+ let subTypeQualifierFunctions = $instanceType.qualifiedProperties->filter(q | $q.name == $qualifierName);
+
+ assert($subTypeQualifierFunctions->size() > 0, | 'Found no qualifier with name "' + $qualifierName + '" in the class "' + $instanceType->elementToPath() + '"');
+ assert($subTypeQualifierFunctions->size() == 1, | 'Found multiple qualifiers with name "' + $qualifierName + '" in the class "' + $instanceType->elementToPath() + '"');
+
+ $subTypeQualifierFunctions->toOne()->evaluate(list($instance)->concatenate($params))->toOne('Executing qualifiers returning multiple objects not supported')->cast(@T);
+}
+
+Class meta::external::store::relational::sqlPlanning::utils::NodeTransformationWithChangeTracking
+{
+ hasChanged: Boolean[1];
+ result: Node[1];
+}
+
+function meta::external::store::relational::sqlPlanning::utils::changed(result: Node[1]): NodeTransformationWithChangeTracking[1]
+{
+ ^NodeTransformationWithChangeTracking(hasChanged = true, result = $result)
+}
+
+function meta::external::store::relational::sqlPlanning::utils::unchanged(result: Node[1]): NodeTransformationWithChangeTracking[1]
+{
+ ^NodeTransformationWithChangeTracking(hasChanged = false, result = $result)
+}
+
+function meta::external::store::relational::sqlPlanning::utils::transformNodeRecursivelyWithChangeTracking(node: Node[1], transformFunction: Function<{Node[1]->NodeTransformationWithChangeTracking[1]}>[1]): NodeTransformationWithChangeTracking[1]
+{
+ let transformedNodeWithChangeTracking = $transformFunction->eval($node);
+ let transformedNode = $transformedNodeWithChangeTracking.result;
+ let nodeType = $transformedNode->type()->cast(@Class);
+ let allProperties = $nodeType->hierarchicalAllProperties()->filter(x | $x->instanceOf(Property))->cast(@Property);
+
+ let transformedKeyValuesWithChangeTracking = $allProperties->map({p |
+ let propValues = $p->eval($transformedNode);
+ let propReturnType = $p->functionReturnType().rawType->toOne();
+ let transformedValues = if ($propReturnType->_subTypeOf(Node),
+ | $propValues->cast(@Node)->map({v |
+ $v->transformNodeRecursivelyWithChangeTracking($transformFunction)->map({x |
+ assert(
+ $x.result->type()->_subTypeOf($propReturnType),
+ | 'Transform function sets incompatible value of type "' + $x->type()->elementToPath() + '" to property "' + $p.name->toOne() +
+ '" in the class "' + $nodeType->elementToPath() + '". Expected type is "' + $propReturnType->elementToPath() + '"'
+ );
+ pair($x.hasChanged, $x.result);
+ })
+ }),
+ | $propValues->map(v | pair(false, $v))
+ );
+ pair($transformedValues.first->isNotEmpty() && $transformedValues.first->or(), ^KeyValue(key = $p.name->toOne(), value = $transformedValues.second));
+ });
+
+ if ($transformedNodeWithChangeTracking.hasChanged->concatenate($transformedKeyValuesWithChangeTracking.first)->or(),
+ | changed($nodeType->dynamicNew($transformedKeyValuesWithChangeTracking.second)->cast(@Node)),
+ | unchanged($node)
+ );
+}
+
+function meta::external::store::relational::sqlPlanning::utils::fetchAllNodes(node: Node[1]): Node[*]
+{
+ $node->fetchAllNodesRecursively()->get($node)->toOne().values;
+}
+
+function meta::external::store::relational::sqlPlanning::utils::fetchAllNodesRecursively(node: Node[1]): Map>[1]
+{
+ let allProperties = $node->type()->cast(@Class)->hierarchicalAllProperties()->filter(x | $x->instanceOf(Property))->cast(@Property);
+ let subResults = $allProperties->filter(p | $p->functionReturnType().rawType->toOne()->_subTypeOf(Node))->map(p | $p->eval($node)->cast(@Node))->map(n | $n->fetchAllNodesRecursively()->keyValues());
+ newMap($subResults)->put($node, list($node->concatenate($subResults.second.values)));
+}
+
+function meta::external::store::relational::sqlPlanning::utils::fetchAllNodesRecursivelyExcludeSubQueries(node: Node[1]): Map>[1]
+{
+ let allProperties = $node->type()->cast(@Class)->hierarchicalAllProperties()->filter(x | $x->instanceOf(Property))->cast(@Property);
+ let subResults = if ($node->instanceOf(TableSubquery),
+ | $allProperties->filter(p | $p->functionReturnType().rawType->toOne()->_subTypeOf(Node))->map(p | $p->eval($node)->cast(@Node))->map(n | $n->fetchAllNodesRecursivelyExcludeSubQueries()->keyValues()),
+ | []);
+ newMap($subResults)->put($node, list($node->concatenate($subResults.second.values)));
+}
+
+function meta::external::store::relational::sqlPlanning::utils::isAndExpression(expr: meta::external::query::sql::metamodel::Expression[1]): Boolean[1]
+{
+ $expr->match([l: LogicalBinaryExpression[1] | $l.type == LogicalBinaryType.AND, a: Any[*] | false])
+}
+
+function meta::external::store::relational::sqlPlanning::utils::isOrExpression(expr: meta::external::query::sql::metamodel::Expression[1]): Boolean[1]
+{
+ $expr->match([l: LogicalBinaryExpression[1] | $l.type == LogicalBinaryType.OR, a: Any[*] | false])
+}
+
+function meta::external::store::relational::sqlPlanning::utils::isEqualsExpression(expr: meta::external::query::sql::metamodel::Expression[1]): Boolean[1]
+{
+ $expr->match([c: ComparisonExpression[1] | $c.operator == ComparisonOperator.EQUAL, a: Any[*] | false])
+}
+
+function meta::external::store::relational::sqlPlanning::utils::identifySingleColumnFilterGroups(expr: meta::external::query::sql::metamodel::Expression[1]): Pair[*]
+{
+ let subNodeMap = $expr->fetchAllNodesRecursively();
+ $expr->identifySingleColumnFilterGroups_internal($subNodeMap);
+}
+
+function <> meta::external::store::relational::sqlPlanning::utils::identifySingleColumnFilterGroups_internal(expr: meta::external::query::sql::metamodel::Expression[1], subNodeMap: Map>[1]): Pair[*]
+{
+ let exprSubNodes = $subNodeMap->get($expr).values;
+ let columns = $exprSubNodes->filter(n | $n->instanceOf(QualifiedNameReference))->removeDuplicates();
+
+ let isSubNodeValidForColumnGrouping = {e: meta::external::query::sql::metamodel::Expression[1] |
+ $e->match([
+ s: SubqueryExpression[1] | false,
+ a: Any[*] | true
+ ])
+ };
+
+ if ($columns->size() == 1,
+ | if($exprSubNodes->forAll(e | $isSubNodeValidForColumnGrouping->eval($e)), | pair($columns->toOne()->cast(@QualifiedNameReference), $expr), | []),
+ | if ($expr->isAndExpression(),
+ | $expr->cast(@LogicalBinaryExpression)->map(b | [$b.left, $b.right])->map(e | $e->identifySingleColumnFilterGroups_internal($subNodeMap)),
+ | []
+ )
+ );
+}
+
+function meta::external::store::relational::sqlPlanning::utils::isQueryPlainQuerySpecification(query: Query[1]): Boolean[1]
+{
+ $query.limit->isEmpty() && $query.orderBy->isEmpty() && $query.offset->isEmpty() && $query.queryBody->instanceOf(QuerySpecification)
+}
+
+function meta::external::store::relational::sqlPlanning::utils::addClauseIfNotExisting(expr: meta::external::query::sql::metamodel::Expression[1], toAdd: meta::external::query::sql::metamodel::Expression[1]): NodeTransformationWithChangeTracking[1]
+{
+ let toAddType = $toAdd->type()->elementToPath();
+ let notExisting = $expr->fetchAllNodes()->filter(x | $x->type()->elementToPath() == $toAddType)->filter(x | $x == $toAdd)->isEmpty();
+ if ($notExisting,
+ | changed(^LogicalBinaryExpression(left = $expr, right = $toAdd, type = LogicalBinaryType.AND)),
+ | unchanged($expr)
+ );
+}
+
+function meta::external::store::relational::sqlPlanning::utils::printDebugQuery(query: Query[1], config: SqlPlanningConfig[1], extensions: Extension[*]): String[1]
+{
+ $query->printDebugQuery($config, false, $extensions)
+}
+
+function meta::external::store::relational::sqlPlanning::utils::printDebugQuery(query: Query[1], config: SqlPlanningConfig[1], pretty: Boolean[1], extensions: Extension[*]): String[1]
+{
+ let sqlDialectTranslationConfig = ^SqlDialectTranslationConfig(dbConfig = ^DbConfig(dbType = $config.dbType), formatConfig = ^FormatConfig(pretty = $pretty, upperCaseKeywords = true));
+ $query->generateSqlDialectForStatement($sqlDialectTranslationConfig, $extensions);
+}