From 6687a58bfaad16a7647a9142a7e393d16057eaf9 Mon Sep 17 00:00:00 2001 From: Darin Kelkhoff Date: Fri, 13 Dec 2024 10:39:54 -0600 Subject: [PATCH] Add subFilterSetOperator (e.g., UNION, INTERSECT, EXCEPT) to QQueryFilter - along with implementation in RDBMS module, to generate such queries --- .../actions/tables/query/QQueryFilter.java | 54 ++++++ .../rdbms/actions/AbstractRDBMSAction.java | 7 +- .../rdbms/actions/RDBMSQueryAction.java | 143 +++++++++++---- ...MSQueryActionSubFilterSetOperatorTest.java | 171 ++++++++++++++++++ 4 files changed, 339 insertions(+), 36 deletions(-) create mode 100644 qqq-backend-module-rdbms/src/test/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryActionSubFilterSetOperatorTest.java diff --git a/qqq-backend-core/src/main/java/com/kingsrook/qqq/backend/core/model/actions/tables/query/QQueryFilter.java b/qqq-backend-core/src/main/java/com/kingsrook/qqq/backend/core/model/actions/tables/query/QQueryFilter.java index 6006d065..0d18d56d 100644 --- a/qqq-backend-core/src/main/java/com/kingsrook/qqq/backend/core/model/actions/tables/query/QQueryFilter.java +++ b/qqq-backend-core/src/main/java/com/kingsrook/qqq/backend/core/model/actions/tables/query/QQueryFilter.java @@ -55,6 +55,16 @@ public class QQueryFilter implements Serializable, Cloneable private BooleanOperator booleanOperator = BooleanOperator.AND; private List subFilters = new ArrayList<>(); + ////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////// + // initial intent here was - put, e.g., UNION between multiple SELECT (with the individual selects being defined in subFilters) // + // but, actually SQL would let us do, e.g., SELECT UNION SELECT INTERSECT SELECT // + // so - we could see a future implementation where we: // + // - used the top-level subFilterSetOperator to indicate hat we are doing a multi-query set-operation query. // + // - looked within the subFilter, to see if it specified a subFilterSetOperator - and use that operator before that query // + // but - in v0, just using the one at the top-level works // + ////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////// + private SubFilterSetOperator subFilterSetOperator = null; + //////////////////////////////////////////////////////////////////////////////////////////////////////////// // skip & limit are meant to only apply to QueryAction (at least at the initial time they are added here) // // e.g., they are ignored in CountAction, AggregateAction, etc, where their meanings may be less obvious // @@ -75,6 +85,19 @@ public class QQueryFilter implements Serializable, Cloneable + /******************************************************************************* + ** + *******************************************************************************/ + public enum SubFilterSetOperator + { + UNION, + UNION_ALL, + INTERSECT, + EXCEPT + } + + + /******************************************************************************* ** Constructor ** @@ -799,4 +822,35 @@ public class QQueryFilter implements Serializable, Cloneable } } + + /******************************************************************************* + ** Getter for subFilterSetOperator + *******************************************************************************/ + public SubFilterSetOperator getSubFilterSetOperator() + { + return (this.subFilterSetOperator); + } + + + + /******************************************************************************* + ** Setter for subFilterSetOperator + *******************************************************************************/ + public void setSubFilterSetOperator(SubFilterSetOperator subFilterSetOperator) + { + this.subFilterSetOperator = subFilterSetOperator; + } + + + + /******************************************************************************* + ** Fluent setter for subFilterSetOperator + *******************************************************************************/ + public QQueryFilter withSubFilterSetOperator(SubFilterSetOperator subFilterSetOperator) + { + this.subFilterSetOperator = subFilterSetOperator; + return (this); + } + + } diff --git a/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/AbstractRDBMSAction.java b/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/AbstractRDBMSAction.java index dd8fdaa2..68ecce54 100644 --- a/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/AbstractRDBMSAction.java +++ b/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/AbstractRDBMSAction.java @@ -972,10 +972,15 @@ public abstract class AbstractRDBMSAction { sql = Objects.requireNonNullElse(sql, "").toString() .replaceAll("FROM ", "\nFROM\n ") + .replaceAll("UNION ", "\nUNION\n ") + .replaceAll("INTERSECT ", "\nINTERSECT\n ") + .replaceAll("EXCEPT ", "\nEXCEPT\n ") .replaceAll("INNER", "\n INNER") .replaceAll("LEFT", "\n LEFT") .replaceAll("RIGHT", "\n RIGHT") - .replaceAll("WHERE", "\nWHERE\n "); + .replaceAll("WHERE", "\nWHERE\n ") + .replaceAll("ORDER BY", "\nORDER BY\n ") + .replaceAll("GROUP BY", "\nGROUP BY\n "); } if(System.getProperty("qqq.rdbms.logSQL.output", "logger").equalsIgnoreCase("system.out")) diff --git a/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryAction.java b/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryAction.java index 8912f0aa..8ead329e 100644 --- a/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryAction.java +++ b/qqq-backend-module-rdbms/src/main/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryAction.java @@ -36,7 +36,6 @@ import java.util.List; import java.util.Map; import java.util.Set; import java.util.concurrent.TimeUnit; -import java.util.stream.Collectors; import com.kingsrook.qqq.backend.core.actions.interfaces.QueryInterface; import com.kingsrook.qqq.backend.core.actions.tables.helpers.ActionTimeoutHelper; import com.kingsrook.qqq.backend.core.context.QContext; @@ -46,6 +45,7 @@ import com.kingsrook.qqq.backend.core.instances.QMetaDataVariableInterpreter; import com.kingsrook.qqq.backend.core.logging.QLogger; import com.kingsrook.qqq.backend.core.model.actions.tables.QueryHint; import com.kingsrook.qqq.backend.core.model.actions.tables.query.JoinsContext; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QFilterOrderBy; import com.kingsrook.qqq.backend.core.model.actions.tables.query.QQueryFilter; import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryInput; import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryJoin; @@ -95,35 +95,10 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf QTableMetaData table = queryInput.getTable(); String tableName = queryInput.getTableName(); - Selection selection = makeSelection(queryInput); - StringBuilder sql = new StringBuilder(selection.selectClause()); + List params = new ArrayList<>(); + Selection selection = makeSelection(queryInput); - QQueryFilter filter = clonedOrNewFilter(queryInput.getFilter()); - JoinsContext joinsContext = new JoinsContext(QContext.getQInstance(), tableName, queryInput.getQueryJoins(), filter); - - List params = new ArrayList<>(); - sql.append(" FROM ").append(makeFromClause(QContext.getQInstance(), tableName, joinsContext, params)); - sql.append(" WHERE ").append(makeWhereClause(joinsContext, filter, params)); - - if(filter != null && CollectionUtils.nullSafeHasContents(filter.getOrderBys())) - { - sql.append(" ORDER BY ").append(makeOrderByClause(table, filter.getOrderBys(), joinsContext)); - } - - if(filter != null && filter.getLimit() != null) - { - sql.append(" LIMIT ").append(filter.getLimit()); - - if(filter.getSkip() != null) - { - // todo - other sql grammars? - sql.append(" OFFSET ").append(filter.getSkip()); - } - } - - // todo sql customization - can edit sql and/or param list - - setSqlAndJoinsInQueryStat(sql, joinsContext); + StringBuilder sql = makeSQL(queryInput, selection, tableName, params, table); Connection connection; boolean needToCloseConnection = false; @@ -258,6 +233,99 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf + /*************************************************************************** + ** + ***************************************************************************/ + private StringBuilder makeSQL(QueryInput queryInput, Selection selection, String tableName, List params, QTableMetaData table) throws QException + { + QQueryFilter filter = clonedOrNewFilter(queryInput.getFilter()); + JoinsContext joinsContext = new JoinsContext(QContext.getQInstance(), tableName, queryInput.getQueryJoins(), filter); + + StringBuilder sql = new StringBuilder(); + + if(filter != null && filter.getSubFilterSetOperator() != null && CollectionUtils.nullSafeHasContents(filter.getSubFilters())) + { + for(QQueryFilter subFilter : filter.getSubFilters()) + { + if(!sql.isEmpty()) + { + sql.append(" ").append(filter.getSubFilterSetOperator().name().replace('_', ' ')).append(" "); + } + + sql.append(" ("); + sql.append(selection.selectClause()); + sql.append(" FROM ").append(makeFromClause(QContext.getQInstance(), tableName, joinsContext, params)); + sql.append(" WHERE ").append(makeWhereClause(joinsContext, subFilter, params)); + sql.append(") "); + } + + if(CollectionUtils.nullSafeHasContents(filter.getOrderBys())) + { + ///////////////////////////////////////////////////////////////////////////////////////////////////////// + // the base version of makeOrderByClause uses `table`.`column` style references - which don't work for // + // these kinds of queries... so, use this version, which does index-based ones (maybe we could/should // + // switch to always use those? // + // the best here might be, to alias all columns, and then use those aliases in both versions... // + ///////////////////////////////////////////////////////////////////////////////////////////////////////// + sql.append(" ORDER BY ").append(makeOrderByClauseForSubFilterSetOperationQuery(table, filter.getOrderBys(), joinsContext, selection)); + } + } + else + { + sql.append(selection.selectClause()); + sql.append(" FROM ").append(makeFromClause(QContext.getQInstance(), tableName, joinsContext, params)); + sql.append(" WHERE ").append(makeWhereClause(joinsContext, filter, params)); + + if(filter != null && CollectionUtils.nullSafeHasContents(filter.getOrderBys())) + { + sql.append(" ORDER BY ").append(makeOrderByClause(table, filter.getOrderBys(), joinsContext)); + } + } + + if(filter != null && filter.getLimit() != null) + { + sql.append(" LIMIT ").append(filter.getLimit()); + + if(filter.getSkip() != null) + { + // todo - other sql grammars? + sql.append(" OFFSET ").append(filter.getSkip()); + } + } + + // todo sql customization - can edit sql and/or param list + + setSqlAndJoinsInQueryStat(sql, joinsContext); + return sql; + } + + + + /*************************************************************************** + ** + ***************************************************************************/ + private String makeOrderByClauseForSubFilterSetOperationQuery(QTableMetaData table, List orderBys, JoinsContext joinsContext, Selection selection) + { + List clauses = new ArrayList<>(); + + for(QFilterOrderBy orderBy : orderBys) + { + String ascOrDesc = orderBy.getIsAscending() ? "ASC" : "DESC"; + JoinsContext.FieldAndTableNameOrAlias otherFieldAndTableNameOrAlias = joinsContext.getFieldAndTableNameOrAlias(orderBy.getFieldName()); + + QFieldMetaData field = otherFieldAndTableNameOrAlias.field(); + String column = getColumnName(field); + + String qualifiedColumn = escapeIdentifier(otherFieldAndTableNameOrAlias.tableNameOrAlias()) + "." + escapeIdentifier(column); + String columnNo = String.valueOf(selection.qualifiedColumns.indexOf(qualifiedColumn) + 1); + clauses.add(columnNo + " " + ascOrDesc); + + } + return (String.join(", ", clauses)); + } + + + /******************************************************************************* ** *******************************************************************************/ @@ -282,10 +350,11 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf /*************************************************************************** ** output wrapper for makeSelection method. ** - selectClause is everything from SELECT up to (but not including) FROM + ** - qualifiedColumns is a list of the `table`.`column` strings ** - fields are those being selected, in the same order, and with mutated ** names for join fields. ***************************************************************************/ - private record Selection(String selectClause, List fields) + private record Selection(String selectClause, List qualifiedColumns, List fields) { } @@ -318,10 +387,11 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf // map those field names to columns, joined with ", ". // // if a field is heavy, and heavy fields aren't being selected, then replace that field name with a LENGTH function // ////////////////////////////////////////////////////////////////////////////////////////////////////////////////////// - String columns = fieldList.stream() + List qualifiedColumns = new ArrayList<>(fieldList.stream() .map(field -> Pair.of(field, escapeIdentifier(tableName) + "." + escapeIdentifier(getColumnName(field)))) .map(pair -> wrapHeavyFieldsWithLengthFunctionIfNeeded(pair, queryInput.getShouldFetchHeavyFields())) - .collect(Collectors.joining(", ")); + .toList()); + String columns = String.join(", ", qualifiedColumns); /////////////////////////////////////////////////////////////////////////////////////////////////////////// // figure out if distinct is being used. then start building the select clause with the table's columns // @@ -360,10 +430,13 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf ///////////////////////////////////////////////////// // map to columns, wrapping heavy fields as needed // ///////////////////////////////////////////////////// - String joinColumns = joinFieldList.stream() + List qualifiedJoinColumns = joinFieldList.stream() .map(field -> Pair.of(field, escapeIdentifier(tableNameOrAlias) + "." + escapeIdentifier(getColumnName(field)))) .map(pair -> wrapHeavyFieldsWithLengthFunctionIfNeeded(pair, queryInput.getShouldFetchHeavyFields())) - .collect(Collectors.joining(", ")); + .toList(); + + qualifiedColumns.addAll(qualifiedJoinColumns); + String joinColumns = String.join(", ", qualifiedJoinColumns); //////////////////////////////////////////////////////////////////////////////////////////////// // append to output objects. // @@ -380,7 +453,7 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf } } - return (new Selection(selectClause.toString(), selectionFieldList)); + return (new Selection(selectClause.toString(), qualifiedColumns, selectionFieldList)); } diff --git a/qqq-backend-module-rdbms/src/test/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryActionSubFilterSetOperatorTest.java b/qqq-backend-module-rdbms/src/test/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryActionSubFilterSetOperatorTest.java new file mode 100644 index 00000000..85a87611 --- /dev/null +++ b/qqq-backend-module-rdbms/src/test/java/com/kingsrook/qqq/backend/module/rdbms/actions/RDBMSQueryActionSubFilterSetOperatorTest.java @@ -0,0 +1,171 @@ + /* + * QQQ - Low-code Application Framework for Engineers. + * Copyright (C) 2021-2022. Kingsrook, LLC + * 651 N Broad St Ste 205 # 6917 | Middletown DE 19709 | United States + * contact@kingsrook.com + * https://github.com/Kingsrook/ + * + * This program is free software: you can redistribute it and/or modify + * it under the terms of the GNU Affero General Public License as + * published by the Free Software Foundation, either version 3 of the + * License, or (at your option) any later version. + * + * This program is distributed in the hope that it will be useful, + * but WITHOUT ANY WARRANTY; without even the implied warranty of + * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the + * GNU Affero General Public License for more details. + * + * You should have received a copy of the GNU Affero General Public License + * along with this program. If not, see . + */ + +package com.kingsrook.qqq.backend.module.rdbms.actions; + + +import com.kingsrook.qqq.backend.core.context.QContext; +import com.kingsrook.qqq.backend.core.exceptions.QException; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QCriteriaOperator; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QFilterCriteria; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QFilterOrderBy; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QQueryFilter; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryInput; +import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryOutput; +import com.kingsrook.qqq.backend.core.model.session.QSession; +import com.kingsrook.qqq.backend.module.rdbms.TestUtils; +import org.junit.jupiter.api.AfterEach; +import org.junit.jupiter.api.BeforeEach; +import org.junit.jupiter.api.Test; +import static org.junit.jupiter.api.Assertions.assertEquals; + + +/******************************************************************************* + ** test for subfilter set + *******************************************************************************/ +public class RDBMSQueryActionSubFilterSetOperatorTest extends RDBMSActionTest +{ + + /******************************************************************************* + ** + *******************************************************************************/ + @BeforeEach + public void beforeEach() throws Exception + { + super.primeTestDatabase(); + + // AbstractRDBMSAction.setLogSQL(true, true, "system.out"); + } + + + + /******************************************************************************* + ** + *******************************************************************************/ + @AfterEach + void afterEach() + { + AbstractRDBMSAction.setLogSQL(false); + QContext.getQSession().removeValue(QSession.VALUE_KEY_USER_TIMEZONE); + } + + + + /******************************************************************************* + ** + *******************************************************************************/ + private QueryInput initQueryRequest() + { + QueryInput queryInput = new QueryInput(); + queryInput.setTableName(TestUtils.TABLE_NAME_PERSON); + return queryInput; + } + + + + /******************************************************************************* + ** + *******************************************************************************/ + @Test + public void testUnion() throws QException + { + QueryInput queryInput = initQueryRequest(); + queryInput.setFilter(new QQueryFilter() + .withSubFilterSetOperator(QQueryFilter.SubFilterSetOperator.UNION) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 1, 2))) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 2, 3))) + .withOrderBy(new QFilterOrderBy("id", false)) + ); + + QueryOutput queryOutput = new RDBMSQueryAction().execute(queryInput); + assertEquals(3, queryOutput.getRecords().size(), "Expected # of rows"); + assertEquals(3, queryOutput.getRecords().get(0).getValueInteger("id")); + assertEquals(2, queryOutput.getRecords().get(1).getValueInteger("id")); + assertEquals(1, queryOutput.getRecords().get(2).getValueInteger("id")); + } + + + + /******************************************************************************* + ** + *******************************************************************************/ + @Test + public void testUnionAll() throws QException + { + QueryInput queryInput = initQueryRequest(); + queryInput.setFilter(new QQueryFilter() + .withSubFilterSetOperator(QQueryFilter.SubFilterSetOperator.UNION_ALL) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 1, 2))) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 2, 3))) + .withOrderBy(new QFilterOrderBy("id", false)) + ); + + QueryOutput queryOutput = new RDBMSQueryAction().execute(queryInput); + assertEquals(4, queryOutput.getRecords().size(), "Expected # of rows"); + assertEquals(3, queryOutput.getRecords().get(0).getValueInteger("id")); + assertEquals(2, queryOutput.getRecords().get(1).getValueInteger("id")); + assertEquals(2, queryOutput.getRecords().get(2).getValueInteger("id")); + assertEquals(1, queryOutput.getRecords().get(3).getValueInteger("id")); + } + + + + /******************************************************************************* + ** + *******************************************************************************/ + @Test + public void testIntersect() throws QException + { + QueryInput queryInput = initQueryRequest(); + queryInput.setFilter(new QQueryFilter() + .withSubFilterSetOperator(QQueryFilter.SubFilterSetOperator.INTERSECT) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 1, 2))) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 2, 3))) + .withOrderBy(new QFilterOrderBy("id", false)) + ); + + QueryOutput queryOutput = new RDBMSQueryAction().execute(queryInput); + assertEquals(1, queryOutput.getRecords().size(), "Expected # of rows"); + assertEquals(2, queryOutput.getRecords().get(0).getValueInteger("id")); + } + + + /******************************************************************************* + ** + *******************************************************************************/ + @Test + public void testExcept() throws QException + { + QueryInput queryInput = initQueryRequest(); + queryInput.setFilter(new QQueryFilter() + .withSubFilterSetOperator(QQueryFilter.SubFilterSetOperator.EXCEPT) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 1, 2, 3))) + .withSubFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.IN, 2))) + .withOrderBy(new QFilterOrderBy("id", true)) + ); + + QueryOutput queryOutput = new RDBMSQueryAction().execute(queryInput); + assertEquals(2, queryOutput.getRecords().size(), "Expected # of rows"); + assertEquals(1, queryOutput.getRecords().get(0).getValueInteger("id")); + assertEquals(3, queryOutput.getRecords().get(1).getValueInteger("id")); + } + +}