Join Enhancements:

- Moving responsibility for adding security clauses out of AbstractRDBMSAction, into JoinsContext
- Adding QueryJoin securityClauses (helps outer-join security filtering work as expected)
- Add security clauses for all joined tables
- Improved inferring of joinMetaData, especially from ExposedJoins
- Fix processes use of selectDistinct when ordering by a field from a joinTable (by doing the Distinct in the record pipe)
This commit is contained in:
2023-09-07 12:23:12 -05:00
parent d9458ced34
commit 73e826f81d
22 changed files with 2055 additions and 1124 deletions

View File

@ -52,9 +52,7 @@ import com.kingsrook.qqq.backend.core.model.actions.tables.aggregate.Aggregate;
import com.kingsrook.qqq.backend.core.model.actions.tables.aggregate.GroupBy;
import com.kingsrook.qqq.backend.core.model.actions.tables.aggregate.QFilterOrderByAggregate;
import com.kingsrook.qqq.backend.core.model.actions.tables.aggregate.QFilterOrderByGroupBy;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.ImplicitQueryJoinForSecurityLock;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.JoinsContext;
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;
@ -68,12 +66,10 @@ import com.kingsrook.qqq.backend.core.model.metadata.fields.QFieldType;
import com.kingsrook.qqq.backend.core.model.metadata.joins.JoinOn;
import com.kingsrook.qqq.backend.core.model.metadata.joins.JoinType;
import com.kingsrook.qqq.backend.core.model.metadata.joins.QJoinMetaData;
import com.kingsrook.qqq.backend.core.model.metadata.security.QSecurityKeyType;
import com.kingsrook.qqq.backend.core.model.metadata.security.RecordSecurityLock;
import com.kingsrook.qqq.backend.core.model.metadata.security.RecordSecurityLockFilters;
import com.kingsrook.qqq.backend.core.model.metadata.tables.QTableMetaData;
import com.kingsrook.qqq.backend.core.model.querystats.QueryStat;
import com.kingsrook.qqq.backend.core.model.session.QSession;
import com.kingsrook.qqq.backend.core.utils.CollectionUtils;
import com.kingsrook.qqq.backend.core.utils.StringUtils;
import com.kingsrook.qqq.backend.core.utils.ValueUtils;
@ -212,7 +208,7 @@ public abstract class AbstractRDBMSAction implements QActionInterface
/*******************************************************************************
**
*******************************************************************************/
protected String makeFromClause(QInstance instance, String tableName, JoinsContext joinsContext) throws QException
protected String makeFromClause(QInstance instance, String tableName, JoinsContext joinsContext, List<Serializable> params)
{
StringBuilder rs = new StringBuilder(escapeIdentifier(getTableName(instance.getTable(tableName))) + " AS " + escapeIdentifier(tableName));
@ -229,17 +225,9 @@ public abstract class AbstractRDBMSAction implements QActionInterface
////////////////////////////////////////////////////////////
// find the join in the instance, to set the 'on' clause //
////////////////////////////////////////////////////////////
List<String> joinClauseList = new ArrayList<>();
String baseTableName = Objects.requireNonNullElse(joinsContext.resolveTableNameOrAliasToTableName(queryJoin.getBaseTableOrAlias()), tableName);
QJoinMetaData joinMetaData = Objects.requireNonNullElseGet(queryJoin.getJoinMetaData(), () ->
{
QJoinMetaData found = joinsContext.findJoinMetaData(instance, baseTableName, queryJoin.getJoinTable());
if(found == null)
{
throw (new RuntimeException("Could not find a join between tables [" + baseTableName + "][" + queryJoin.getJoinTable() + "]"));
}
return (found);
});
List<String> joinClauseList = new ArrayList<>();
String baseTableName = Objects.requireNonNullElse(joinsContext.resolveTableNameOrAliasToTableName(queryJoin.getBaseTableOrAlias()), tableName);
QJoinMetaData joinMetaData = Objects.requireNonNull(queryJoin.getJoinMetaData(), () -> "Could not find a join between tables [" + baseTableName + "][" + queryJoin.getJoinTable() + "]");
for(JoinOn joinOn : joinMetaData.getJoinOns())
{
@ -270,6 +258,14 @@ public abstract class AbstractRDBMSAction implements QActionInterface
+ " = " + escapeIdentifier(joinTableOrAlias)
+ "." + escapeIdentifier(getColumnName((rightTable.getField(joinOn.getRightField())))));
}
if(CollectionUtils.nullSafeHasContents(queryJoin.getSecurityCriteria()))
{
String securityOnClause = getSqlWhereStringAndPopulateParamsListFromNonNestedFilter(joinsContext, queryJoin.getSecurityCriteria(), QQueryFilter.BooleanOperator.AND, params);
LOG.debug("Wrote securityOnClause", logPair("clause", securityOnClause));
joinClauseList.add(securityOnClause);
}
rs.append(" ON ").append(StringUtils.join(" AND ", joinClauseList));
}
@ -285,34 +281,66 @@ public abstract class AbstractRDBMSAction implements QActionInterface
*******************************************************************************/
private List<QueryJoin> sortQueryJoinsForFromClause(String mainTableName, List<QueryJoin> queryJoins)
{
List<QueryJoin> rs = new ArrayList<>();
////////////////////////////////////////////////////////////////////////////////
// make a copy of the input list that we can feel safe removing elements from //
////////////////////////////////////////////////////////////////////////////////
List<QueryJoin> inputListCopy = new ArrayList<>(queryJoins);
List<QueryJoin> rs = new ArrayList<>();
Set<String> seenTables = new HashSet<>();
seenTables.add(mainTableName);
///////////////////////////////////////////////////////////////////////////////////////////////////
// keep track of the tables (or aliases) that we've seen - that's what we'll "grow" outward from //
///////////////////////////////////////////////////////////////////////////////////////////////////
Set<String> seenTablesOrAliases = new HashSet<>();
seenTablesOrAliases.add(mainTableName);
////////////////////////////////////////////////////////////////////////////////////
// loop as long as there are more tables in the inputList, and the keepGoing flag //
// is set (e.g., indicating that we added something in the last iteration) //
////////////////////////////////////////////////////////////////////////////////////
boolean keepGoing = true;
while(!inputListCopy.isEmpty() && keepGoing)
{
keepGoing = false;
Iterator<QueryJoin> iterator = inputListCopy.iterator();
while(iterator.hasNext())
{
QueryJoin next = iterator.next();
if((StringUtils.hasContent(next.getBaseTableOrAlias()) && seenTables.contains(next.getBaseTableOrAlias())) || seenTables.contains(next.getJoinTable()))
QueryJoin nextQueryJoin = iterator.next();
//////////////////////////////////////////////////////////////////////////
// get the baseTableOrAlias from this join - and if it isn't set in the //
// QueryJoin, then get it from the left-side of the join's metaData //
//////////////////////////////////////////////////////////////////////////
String baseTableOrAlias = nextQueryJoin.getBaseTableOrAlias();
if(baseTableOrAlias == null && nextQueryJoin.getJoinMetaData() != null)
{
rs.add(next);
if(StringUtils.hasContent(next.getBaseTableOrAlias()))
baseTableOrAlias = nextQueryJoin.getJoinMetaData().getLeftTable();
}
//////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// if we have a baseTableOrAlias (would we ever not?), and we've seen it before - OR - we've seen this query join's joinTableOrAlias, //
// then we can add this pair of namesOrAliases to our seen-set, remove this queryJoin from the inputListCopy (iterator), and keep going //
//////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
if((StringUtils.hasContent(baseTableOrAlias) && seenTablesOrAliases.contains(baseTableOrAlias)) || seenTablesOrAliases.contains(nextQueryJoin.getJoinTableOrItsAlias()))
{
rs.add(nextQueryJoin);
if(StringUtils.hasContent(baseTableOrAlias))
{
seenTables.add(next.getBaseTableOrAlias());
seenTablesOrAliases.add(baseTableOrAlias);
}
seenTables.add(next.getJoinTable());
seenTablesOrAliases.add(nextQueryJoin.getJoinTableOrItsAlias());
iterator.remove();
keepGoing = true;
}
}
}
///////////////////////////////////////////////////////////////////////////////////////////////////////////////
// in case any are left, add them all here - does this ever happen? //
// the only time a conditional breakpoint here fires in the RDBMS test suite, is in query designed to throw. //
///////////////////////////////////////////////////////////////////////////////////////////////////////////////
rs.addAll(inputListCopy);
return (rs);
@ -321,35 +349,19 @@ public abstract class AbstractRDBMSAction implements QActionInterface
/*******************************************************************************
** method that sub-classes should call to make a full WHERE clause, including
** security clauses.
** Method to make a full WHERE clause.
**
** Note that criteria for security are assumed to have been added to the filter
** during the construction of the JoinsContext.
*******************************************************************************/
protected String makeWhereClause(QInstance instance, QSession session, QTableMetaData table, JoinsContext joinsContext, QQueryFilter filter, List<Serializable> params) throws IllegalArgumentException, QException
{
String whereClauseWithoutSecurity = makeWhereClauseWithoutSecurity(instance, table, joinsContext, filter, params);
QQueryFilter securityFilter = getSecurityFilter(instance, session, table, joinsContext);
if(!securityFilter.hasAnyCriteria())
{
return (whereClauseWithoutSecurity);
}
String securityWhereClause = makeWhereClauseWithoutSecurity(instance, table, joinsContext, securityFilter, params);
return ("(" + whereClauseWithoutSecurity + ") AND (" + securityWhereClause + ")");
}
/*******************************************************************************
** private method for making the part of a where clause that gets AND'ed to the
** security clause. Recursively handles sub-clauses.
*******************************************************************************/
private String makeWhereClauseWithoutSecurity(QInstance instance, QTableMetaData table, JoinsContext joinsContext, QQueryFilter filter, List<Serializable> params) throws IllegalArgumentException, QException
protected String makeWhereClause(JoinsContext joinsContext, QQueryFilter filter, List<Serializable> params) throws IllegalArgumentException
{
if(filter == null || !filter.hasAnyCriteria())
{
return ("1 = 1");
}
String clause = getSqlWhereStringAndPopulateParamsListFromNonNestedFilter(instance, table, joinsContext, filter.getCriteria(), filter.getBooleanOperator(), params);
String clause = getSqlWhereStringAndPopulateParamsListFromNonNestedFilter(joinsContext, filter.getCriteria(), filter.getBooleanOperator(), params);
if(!CollectionUtils.nullSafeHasContents(filter.getSubFilters()))
{
///////////////////////////////////////////////////////////////
@ -368,7 +380,7 @@ public abstract class AbstractRDBMSAction implements QActionInterface
}
for(QQueryFilter subFilter : filter.getSubFilters())
{
String subClause = makeWhereClauseWithoutSecurity(instance, table, joinsContext, subFilter, params);
String subClause = makeWhereClause(joinsContext, subFilter, params);
if(StringUtils.hasContent(subClause))
{
clauses.add("(" + subClause + ")");
@ -379,146 +391,10 @@ public abstract class AbstractRDBMSAction implements QActionInterface
/*******************************************************************************
** Build a QQueryFilter to apply record-level security to the query.
** Note, it may be empty, if there are no lock fields, or all are all-access.
*******************************************************************************/
private QQueryFilter getSecurityFilter(QInstance instance, QSession session, QTableMetaData table, JoinsContext joinsContext)
{
QQueryFilter securityFilter = new QQueryFilter();
securityFilter.setBooleanOperator(QQueryFilter.BooleanOperator.AND);
for(RecordSecurityLock recordSecurityLock : RecordSecurityLockFilters.filterForReadLocks(CollectionUtils.nonNullList(table.getRecordSecurityLocks())))
{
// todo - uh, if it's a RIGHT (or FULL) join, then, this should be isOuter = true, right?
boolean isOuter = false;
addSubFilterForRecordSecurityLock(instance, session, table, securityFilter, recordSecurityLock, joinsContext, table.getName(), isOuter);
}
for(QueryJoin queryJoin : CollectionUtils.nonNullList(joinsContext.getQueryJoins()))
{
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// for user-added joins, we want to add their security-locks to the query //
// but if a join was implicitly added because it's needed to find a security lock on table being queried, //
// don't add additional layers of locks for each join table. that's the idea here at least. //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
if(queryJoin instanceof ImplicitQueryJoinForSecurityLock)
{
continue;
}
QTableMetaData joinTable = instance.getTable(queryJoin.getJoinTable());
for(RecordSecurityLock recordSecurityLock : RecordSecurityLockFilters.filterForReadLocks(CollectionUtils.nonNullList(joinTable.getRecordSecurityLocks())))
{
boolean isOuter = queryJoin.getType().equals(QueryJoin.Type.LEFT); // todo full?
addSubFilterForRecordSecurityLock(instance, session, joinTable, securityFilter, recordSecurityLock, joinsContext, queryJoin.getJoinTableOrItsAlias(), isOuter);
}
}
return (securityFilter);
}
/*******************************************************************************
**
*******************************************************************************/
private static void addSubFilterForRecordSecurityLock(QInstance instance, QSession session, QTableMetaData table, QQueryFilter securityFilter, RecordSecurityLock recordSecurityLock, JoinsContext joinsContext, String tableNameOrAlias, boolean isOuter)
{
//////////////////////////////////////////////////////////////////////////////////////////////////////////////
// check if the key type has an all-access key, and if so, if it's set to true for the current user/session //
//////////////////////////////////////////////////////////////////////////////////////////////////////////////
QSecurityKeyType securityKeyType = instance.getSecurityKeyType(recordSecurityLock.getSecurityKeyType());
if(StringUtils.hasContent(securityKeyType.getAllAccessKeyName()))
{
if(session.hasSecurityKeyValue(securityKeyType.getAllAccessKeyName(), true, QFieldType.BOOLEAN))
{
///////////////////////////////////////////////////////////////////////////////
// if we have all-access on this key, then we don't need a criterion for it. //
///////////////////////////////////////////////////////////////////////////////
return;
}
}
String fieldName = tableNameOrAlias + "." + recordSecurityLock.getFieldName();
if(CollectionUtils.nullSafeHasContents(recordSecurityLock.getJoinNameChain()))
{
fieldName = recordSecurityLock.getFieldName();
}
///////////////////////////////////////////////////////////////////////////////////////////
// else - get the key values from the session and decide what kind of criterion to build //
///////////////////////////////////////////////////////////////////////////////////////////
QQueryFilter lockFilter = new QQueryFilter();
List<QFilterCriteria> lockCriteria = new ArrayList<>();
lockFilter.setCriteria(lockCriteria);
QFieldType type = QFieldType.INTEGER;
try
{
JoinsContext.FieldAndTableNameOrAlias fieldAndTableNameOrAlias = joinsContext.getFieldAndTableNameOrAlias(fieldName);
type = fieldAndTableNameOrAlias.field().getType();
}
catch(Exception e)
{
LOG.debug("Error getting field type... Trying Integer", e);
}
List<Serializable> securityKeyValues = session.getSecurityKeyValues(recordSecurityLock.getSecurityKeyType(), type);
if(CollectionUtils.nullSafeIsEmpty(securityKeyValues))
{
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// handle user with no values -- they can only see null values, and only iff the lock's null-value behavior is ALLOW //
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
if(RecordSecurityLock.NullValueBehavior.ALLOW.equals(recordSecurityLock.getNullValueBehavior()))
{
lockCriteria.add(new QFilterCriteria(fieldName, QCriteriaOperator.IS_BLANK));
}
else
{
/////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// else, if no user/session values, and null-value behavior is deny, then setup a FALSE condition, to allow no rows. //
// todo - make some explicit contradiction here - maybe even avoid running the whole query - as you're not allowed ANY records //
/////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
lockCriteria.add(new QFilterCriteria(fieldName, QCriteriaOperator.IN, Collections.emptyList()));
}
}
else
{
//////////////////////////////////////////////////////////////////////////////////////////////////////////////
// else, if user/session has some values, build an IN rule - //
// noting that if the lock's null-value behavior is ALLOW, then we actually want IS_NULL_OR_IN, not just IN //
//////////////////////////////////////////////////////////////////////////////////////////////////////////////
if(RecordSecurityLock.NullValueBehavior.ALLOW.equals(recordSecurityLock.getNullValueBehavior()))
{
lockCriteria.add(new QFilterCriteria(fieldName, QCriteriaOperator.IS_NULL_OR_IN, securityKeyValues));
}
else
{
lockCriteria.add(new QFilterCriteria(fieldName, QCriteriaOperator.IN, securityKeyValues));
}
}
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// if this field is on the outer side of an outer join, then if we do a straight filter on it, then we're basically //
// nullifying the outer join... so for an outer join use-case, OR the security field criteria with a primary-key IS NULL //
// which will make missing rows from the join be found. //
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
if(isOuter)
{
lockFilter.setBooleanOperator(QQueryFilter.BooleanOperator.OR);
lockFilter.addCriteria(new QFilterCriteria(tableNameOrAlias + "." + table.getPrimaryKeyField(), QCriteriaOperator.IS_BLANK));
}
securityFilter.addSubFilter(lockFilter);
}
/*******************************************************************************
**
*******************************************************************************/
private String getSqlWhereStringAndPopulateParamsListFromNonNestedFilter(QInstance instance, QTableMetaData table, JoinsContext joinsContext, List<QFilterCriteria> criteria, QQueryFilter.BooleanOperator booleanOperator, List<Serializable> params) throws IllegalArgumentException
private String getSqlWhereStringAndPopulateParamsListFromNonNestedFilter(JoinsContext joinsContext, List<QFilterCriteria> criteria, QQueryFilter.BooleanOperator booleanOperator, List<Serializable> params) throws IllegalArgumentException
{
List<String> clauses = new ArrayList<>();
for(QFilterCriteria criterion : criteria)
@ -1123,4 +999,20 @@ public abstract class AbstractRDBMSAction implements QActionInterface
}
}
/*******************************************************************************
** Either clone the input filter (so we can change it safely), or return a new blank filter.
*******************************************************************************/
protected QQueryFilter clonedOrNewFilter(QQueryFilter filter)
{
if(filter == null)
{
return (new QQueryFilter());
}
else
{
return (filter.clone());
}
}
}

View File

@ -59,6 +59,7 @@ public class RDBMSAggregateAction extends AbstractRDBMSAction implements Aggrega
private ActionTimeoutHelper actionTimeoutHelper;
/*******************************************************************************
**
*******************************************************************************/
@ -68,16 +69,17 @@ public class RDBMSAggregateAction extends AbstractRDBMSAction implements Aggrega
{
QTableMetaData table = aggregateInput.getTable();
JoinsContext joinsContext = new JoinsContext(aggregateInput.getInstance(), table.getName(), aggregateInput.getQueryJoins(), aggregateInput.getFilter());
String fromClause = makeFromClause(aggregateInput.getInstance(), table.getName(), joinsContext);
QQueryFilter filter = clonedOrNewFilter(aggregateInput.getFilter());
JoinsContext joinsContext = new JoinsContext(aggregateInput.getInstance(), table.getName(), aggregateInput.getQueryJoins(), filter);
List<Serializable> params = new ArrayList<>();
String fromClause = makeFromClause(aggregateInput.getInstance(), table.getName(), joinsContext, params);
List<String> selectClauses = buildSelectClauses(aggregateInput, joinsContext);
String sql = "SELECT " + StringUtils.join(", ", selectClauses)
+ " FROM " + fromClause;
QQueryFilter filter = aggregateInput.getFilter();
List<Serializable> params = new ArrayList<>();
sql += " WHERE " + makeWhereClause(aggregateInput.getInstance(), aggregateInput.getSession(), table, joinsContext, filter, params);
+ " FROM " + fromClause
+ " WHERE " + makeWhereClause(joinsContext, filter, params);
if(CollectionUtils.nullSafeHasContents(aggregateInput.getGroupBys()))
{

View File

@ -62,7 +62,8 @@ public class RDBMSCountAction extends AbstractRDBMSAction implements CountInterf
{
QTableMetaData table = countInput.getTable();
JoinsContext joinsContext = new JoinsContext(countInput.getInstance(), countInput.getTableName(), countInput.getQueryJoins(), countInput.getFilter());
QQueryFilter filter = clonedOrNewFilter(countInput.getFilter());
JoinsContext joinsContext = new JoinsContext(countInput.getInstance(), countInput.getTableName(), countInput.getQueryJoins(), filter);
JoinsContext.FieldAndTableNameOrAlias fieldAndTableNameOrAlias = joinsContext.getFieldAndTableNameOrAlias(table.getPrimaryKeyField());
boolean requiresDistinct = doesSelectClauseRequireDistinct(table);
@ -74,12 +75,10 @@ public class RDBMSCountAction extends AbstractRDBMSAction implements CountInterf
clausePrefix = "SELECT COUNT(DISTINCT (" + primaryKeyColumn + ")) AS distinct_count, COUNT(*)";
}
String sql = clausePrefix + " AS record_count FROM "
+ makeFromClause(countInput.getInstance(), table.getName(), joinsContext);
QQueryFilter filter = countInput.getFilter();
List<Serializable> params = new ArrayList<>();
sql += " WHERE " + makeWhereClause(countInput.getInstance(), countInput.getSession(), table, joinsContext, filter, params);
String sql = clausePrefix + " AS record_count "
+ " FROM " + makeFromClause(countInput.getInstance(), table.getName(), joinsContext, params)
+ " WHERE " + makeWhereClause(joinsContext, filter, params);
// todo sql customization - can edit sql and/or param list
setSqlAndJoinsInQueryStat(sql, joinsContext);

View File

@ -268,7 +268,7 @@ public class RDBMSDeleteAction extends AbstractRDBMSAction implements DeleteInte
String tableName = getTableName(table);
JoinsContext joinsContext = new JoinsContext(deleteInput.getInstance(), table.getName(), new ArrayList<>(), deleteInput.getQueryFilter());
String whereClause = makeWhereClause(deleteInput.getInstance(), deleteInput.getSession(), table, joinsContext, filter, params);
String whereClause = makeWhereClause(joinsContext, filter, params);
// todo sql customization - can edit sql and/or param list?
String sql = "DELETE FROM "

View File

@ -79,13 +79,12 @@ public class RDBMSQueryAction extends AbstractRDBMSAction implements QueryInterf
StringBuilder sql = new StringBuilder(makeSelectClause(queryInput));
JoinsContext joinsContext = new JoinsContext(queryInput.getInstance(), tableName, queryInput.getQueryJoins(), queryInput.getFilter());
sql.append(" FROM ").append(makeFromClause(queryInput.getInstance(), tableName, joinsContext));
QQueryFilter filter = clonedOrNewFilter(queryInput.getFilter());
JoinsContext joinsContext = new JoinsContext(queryInput.getInstance(), tableName, queryInput.getQueryJoins(), filter);
QQueryFilter filter = queryInput.getFilter();
List<Serializable> params = new ArrayList<>();
sql.append(" WHERE ").append(makeWhereClause(queryInput.getInstance(), queryInput.getSession(), table, joinsContext, filter, params));
sql.append(" FROM ").append(makeFromClause(queryInput.getInstance(), tableName, joinsContext, params));
sql.append(" WHERE ").append(makeWhereClause(joinsContext, filter, params));
if(filter != null && CollectionUtils.nullSafeHasContents(filter.getOrderBys()))
{

View File

@ -0,0 +1,85 @@
/*
* QQQ - Low-code Application Framework for Engineers.
* Copyright (C) 2021-2023. 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 <https://www.gnu.org/licenses/>.
*/
package com.kingsrook.qqq.backend.core.actions.reporting;
import java.io.ByteArrayOutputStream;
import java.util.List;
import com.kingsrook.qqq.backend.core.context.QContext;
import com.kingsrook.qqq.backend.core.exceptions.QException;
import com.kingsrook.qqq.backend.core.model.actions.reporting.ExportInput;
import com.kingsrook.qqq.backend.core.model.actions.reporting.ExportOutput;
import com.kingsrook.qqq.backend.core.model.actions.reporting.ReportFormat;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.QQueryFilter;
import com.kingsrook.qqq.backend.core.model.session.QSession;
import com.kingsrook.qqq.backend.module.rdbms.TestUtils;
import com.kingsrook.qqq.backend.module.rdbms.actions.RDBMSActionTest;
import org.junit.jupiter.api.BeforeEach;
import org.junit.jupiter.api.Test;
import static org.junit.jupiter.api.Assertions.assertEquals;
import static org.junit.jupiter.api.Assertions.assertNotNull;
/*******************************************************************************
** Test some harder exports, using RDBMS backend.
*******************************************************************************/
public class ExportActionWithinRDBMSTest extends RDBMSActionTest
{
/*******************************************************************************
**
*******************************************************************************/
@BeforeEach
public void beforeEach() throws Exception
{
super.primeTestDatabase();
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testIncludingFieldsFromExposedJoinTableWithTwoJoinsToMainTable() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
ByteArrayOutputStream baos = new ByteArrayOutputStream();
ExportInput exportInput = new ExportInput();
exportInput.setTableName(TestUtils.TABLE_NAME_ORDER);
exportInput.setReportFormat(ReportFormat.CSV);
exportInput.setReportOutputStream(baos);
exportInput.setQueryFilter(new QQueryFilter());
exportInput.setFieldNames(List.of("id", "storeId", "billToPersonId", "currentOrderInstructionsId", TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS + ".id", TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS + ".instructions"));
ExportOutput exportOutput = new ExportAction().execute(exportInput);
assertNotNull(exportOutput);
///////////////////////////////////////////////////////////////////////////
// if there was an exception running the query, we get back 0 records... //
///////////////////////////////////////////////////////////////////////////
assertEquals(3, exportOutput.getRecordCount());
}
}

View File

@ -243,6 +243,7 @@ public class TestUtils
.withRecordSecurityLock(new RecordSecurityLock().withSecurityKeyType(TABLE_NAME_STORE).withFieldName("storeId"))
.withAssociation(new Association().withName("orderLine").withAssociatedTableName(TABLE_NAME_ORDER_LINE).withJoinName("orderJoinOrderLine"))
.withExposedJoin(new ExposedJoin().withJoinTable(TABLE_NAME_ITEM).withJoinPath(List.of("orderJoinOrderLine", "orderLineJoinItem")))
.withExposedJoin(new ExposedJoin().withJoinTable(TABLE_NAME_ORDER_INSTRUCTIONS).withJoinPath(List.of("orderJoinCurrentOrderInstructions")))
.withField(new QFieldMetaData("storeId", QFieldType.INTEGER).withBackendName("store_id").withPossibleValueSourceName(TABLE_NAME_STORE))
.withField(new QFieldMetaData("billToPersonId", QFieldType.INTEGER).withBackendName("bill_to_person_id").withPossibleValueSourceName(TABLE_NAME_PERSON))
.withField(new QFieldMetaData("shipToPersonId", QFieldType.INTEGER).withBackendName("ship_to_person_id").withPossibleValueSourceName(TABLE_NAME_PERSON))

View File

@ -161,10 +161,10 @@ public class RDBMSInsertActionTest extends RDBMSActionTest
insertInput.setRecords(List.of(
new QRecord().withValue("storeId", 1).withValue("billToPersonId", 100).withValue("shipToPersonId", 200)
.withAssociatedRecord("orderLine", new QRecord().withValue("sku", "BASIC1").withValue("quantity", 1)
.withAssociatedRecord("orderLine", new QRecord().withValue("storeId", 1).withValue("sku", "BASIC1").withValue("quantity", 1)
.withAssociatedRecord("extrinsics", new QRecord().withValue("key", "LINE-EXT-1.1").withValue("value", "LINE-VAL-1")))
.withAssociatedRecord("orderLine", new QRecord().withValue("sku", "BASIC2").withValue("quantity", 2)
.withAssociatedRecord("orderLine", new QRecord().withValue("storeId", 1).withValue("sku", "BASIC2").withValue("quantity", 2)
.withAssociatedRecord("extrinsics", new QRecord().withValue("key", "LINE-EXT-2.1").withValue("value", "LINE-VAL-2"))
.withAssociatedRecord("extrinsics", new QRecord().withValue("key", "LINE-EXT-2.2").withValue("value", "LINE-VAL-3")))
));

View File

@ -0,0 +1,987 @@
/*
* 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 <https://www.gnu.org/licenses/>.
*/
package com.kingsrook.qqq.backend.module.rdbms.actions;
import java.util.Collections;
import java.util.List;
import java.util.concurrent.atomic.AtomicInteger;
import com.kingsrook.qqq.backend.core.actions.tables.CountAction;
import com.kingsrook.qqq.backend.core.actions.tables.QueryAction;
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.count.CountInput;
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.QueryJoin;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryOutput;
import com.kingsrook.qqq.backend.core.model.data.QRecord;
import com.kingsrook.qqq.backend.core.model.metadata.QInstance;
import com.kingsrook.qqq.backend.core.model.metadata.security.RecordSecurityLock;
import com.kingsrook.qqq.backend.core.model.session.QSession;
import com.kingsrook.qqq.backend.core.utils.StringUtils;
import com.kingsrook.qqq.backend.core.utils.collections.ListBuilder;
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.assertj.core.api.Assertions.assertThat;
import static org.assertj.core.api.Assertions.assertThatThrownBy;
import static org.junit.jupiter.api.Assertions.assertEquals;
/*******************************************************************************
** Tests on RDBMS - specifically dealing with Joins.
*******************************************************************************/
public class RDBMSQueryActionJoinsTest extends RDBMSActionTest
{
/*******************************************************************************
**
*******************************************************************************/
@BeforeEach
public void beforeEach() throws Exception
{
super.primeTestDatabase();
AbstractRDBMSAction.setLogSQL(true);
AbstractRDBMSAction.setLogSQLOutput("system.out");
}
/*******************************************************************************
**
*******************************************************************************/
@AfterEach
void afterEach()
{
AbstractRDBMSAction.setLogSQL(false);
}
/*******************************************************************************
**
*******************************************************************************/
private QueryInput initQueryRequest()
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_PERSON);
return queryInput;
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testFilterFromJoinTableImplicitly() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("personalIdCard.idNumber", QCriteriaOperator.EQUALS, "19800531")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "Query should find 1 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneLeftJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withType(QueryJoin.Type.LEFT).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(5, queryOutput.getRecords().size(), "Left Join query should find 5 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Garret") && r.getValue("personalIdCard.idNumber") == null);
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tyler") && r.getValue("personalIdCard.idNumber") == null);
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneRightJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withType(QueryJoin.Type.RIGHT).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(6, queryOutput.getRecords().size(), "Right Join query should find 6 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("123123123"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("987987987"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("456456456"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber", QCriteriaOperator.STARTS_WITH, "1980")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(2, queryOutput.getRecords().size(), "Join query should find 2 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithOrderBy() throws QException
{
QInstance qInstance = TestUtils.defineInstance();
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(qInstance.getJoin(TestUtils.TABLE_NAME_PERSON + "Join" + StringUtils.ucFirst(TestUtils.TABLE_NAME_PERSONAL_ID_CARD))).withSelect(true));
queryInput.setFilter(new QQueryFilter().withOrderBy(new QFilterOrderBy(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
List<String> idNumberListFromQuery = queryOutput.getRecords().stream().map(r -> r.getValueString(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")).toList();
assertEquals(List.of("19760528", "19800515", "19800531"), idNumberListFromQuery);
/////////////////////////
// repeat, sorted desc //
/////////////////////////
queryInput.setFilter(new QQueryFilter().withOrderBy(new QFilterOrderBy(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber", false)));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
idNumberListFromQuery = queryOutput.getRecords().stream().map(r -> r.getValueString(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")).toList();
assertEquals(List.of("19800531", "19800515", "19760528"), idNumberListFromQuery);
}
/*******************************************************************************
** In the prime data, we've got 1 order line set up with an item from a different
** store than its order. Write a query to find such a case.
*******************************************************************************/
@Test
void testFiveTableOmsJoinFindMismatchedStoreId() throws Exception
{
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER, TestUtils.TABLE_NAME_STORE).withAlias("orderStore").withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER, TestUtils.TABLE_NAME_ORDER_LINE).withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_LINE, TestUtils.TABLE_NAME_ITEM).withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ITEM, TestUtils.TABLE_NAME_STORE).withAlias("itemStore").withSelect(true));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria().withFieldName("orderStore.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("item.storeId")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
QRecord qRecord = queryOutput.getRecords().get(0);
assertEquals(2, qRecord.getValueInteger("id"));
assertEquals(1, qRecord.getValueInteger("orderStore.id"));
assertEquals(2, qRecord.getValueInteger("itemStore.id"));
//////////////////////////////////////////////////////////////////////////////////////////////////////////
// run the same setup, but this time, use the other-field-name as itemStore.id, instead of item.storeId //
//////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria().withFieldName("orderStore.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("itemStore.id")));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
qRecord = queryOutput.getRecords().get(0);
assertEquals(2, qRecord.getValueInteger("id"));
assertEquals(1, qRecord.getValueInteger("orderStore.id"));
assertEquals(2, qRecord.getValueInteger("itemStore.id"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByOrderLines() throws Exception
{
AtomicInteger orderLineCount = new AtomicInteger();
runTestSql("SELECT COUNT(*) from order_line", (rs) ->
{
rs.next();
orderLineCount.set(rs.getInt(1));
});
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER_LINE);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(orderLineCount.get(), queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(3, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("order.id").equals(1)).count());
assertEquals(1, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("order.id").equals(2)).count());
assertEquals(1, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("orderId").equals(3)).count());
assertEquals(2, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("orderId").equals(4)).count());
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByPersons() throws Exception
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
/////////////////////////////////////////////////////
// inner join on bill-to person should find 6 rows //
/////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(new QueryJoin(TestUtils.TABLE_NAME_PERSON).withJoinMetaData(instance.getJoin("orderJoinBillToPerson")).withSelect(true)));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(6, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////
// inner join on ship-to person should find 7 rows //
/////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withSelect(true)));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(7, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////////////////////////////
// inner join on both bill-to person and ship-to person should find 5 rows //
/////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true)
));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(5, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////////////////////////////
// left join on both bill-to person and ship-to person should find 8 rows //
/////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withType(QueryJoin.Type.LEFT).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withType(QueryJoin.Type.LEFT).withAlias("billToPerson").withSelect(true)
));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(8, queryOutput.getRecords().size(), "# of rows found by query");
//////////////////////////////////////////////////
// now join through to personalIdCard table too //
//////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
queryInput.setFilter(new QQueryFilter()
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// look for billToPersons w/ idNumber starting with 1980 - should only be James and Darin (assert on that below). //
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
.withCriteria(new QFilterCriteria("billToIdCard.idNumber", QCriteriaOperator.STARTS_WITH, "1980"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "# of rows found by query");
assertThat(queryOutput.getRecords().stream().map(r -> r.getValueString("billToPerson.firstName")).toList()).allMatch(p -> p.equals("Darin") || p.equals("James"));
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// ensure we throw if either of the ambiguous joins from person to id-card doesn't specify its left-table //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.rootCause()
.hasMessageContaining("Could not find a join between tables [order][personalIdCard]");
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// ensure we throw if either of the ambiguous joins from person to id-card doesn't specify its left-table //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.rootCause()
.hasMessageContaining("Could not find a join between tables [order][personalIdCard]");
////////////////////////////////////////////////////////////////////////
// ensure we throw if we have a bogus alias name given as a left-side //
////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("notATable", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Could not find a join between tables [notATable][personalIdCard]");
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByPersonsExtraKelkhoffOrder() throws Exception
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// insert a second person w/ last name Kelkhoff, then an order for Darin Kelkhoff and this new Kelkhoff - //
// then query for orders w/ bill to person & ship to person both lastname = Kelkhoff, but different ids. //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
Integer specialOrderId = 1701;
runTestSql("INSERT INTO person (id, first_name, last_name, email) VALUES (6, 'Jimmy', 'Kelkhoff', 'dk@gmail.com')", null);
runTestSql("INSERT INTO `order` (id, store_id, bill_to_person_id, ship_to_person_id) VALUES (" + specialOrderId + ", 1, 1, 6)", null);
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withType(QueryJoin.Type.LEFT).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withType(QueryJoin.Type.LEFT).withAlias("billToPerson").withSelect(true)
));
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("billToPerson.id"))
);
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
////////////////////////////////////////////////////////////
// re-run that query using personIds from the order table //
////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("order.shipToPersonId").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("order.billToPersonId"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
///////////////////////////////////////////////////////////////////////////////////////////////
// re-run that query using personIds from the order table, but not specifying the table name //
///////////////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("shipToPersonId").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("billToPersonId"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testDuplicateAliases()
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson"),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson"),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true) // w/o alias, should get exception here - dupe table.
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Duplicate table name or alias: personalIdCard");
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson"),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson"),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToPerson").withSelect(true), // dupe alias, should get exception here
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToPerson").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Duplicate table name or alias: shipToPerson");
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, also selecting item.
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoin() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ITEM).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("id") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ITEM + ".description") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on item to order
** do a query on item, also selecting order.
** This is a reverse of the above, to make sure join flipping, etc, is good.
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinReversed() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ITEM);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ORDER).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("description") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ORDER + ".id") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, also selecting item, and also selecting orderLine...
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinAlsoSelectingInBetweenTable() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ORDER_LINE).withType(QueryJoin.Type.INNER).withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_ITEM).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("id") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ORDER_LINE + ".quantity") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ITEM + ".description") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, filtered by item
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinWhereClauseOnly() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria(TestUtils.TABLE_NAME_ITEM + ".description", QCriteriaOperator.STARTS_WITH, "Q-Mart")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(4);
assertThat(records).allMatch(r -> r.getValue("id") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, filtered by item
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinWhereClauseBothJoinTables() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria(TestUtils.TABLE_NAME_ITEM + ".description", QCriteriaOperator.STARTS_WITH, "Q-Mart"))
.withCriteria(new QFilterCriteria(TestUtils.TABLE_NAME_ORDER_LINE + ".quantity", QCriteriaOperator.IS_NOT_BLANK))
);
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(4);
assertThat(records).allMatch(r -> r.getValue("id") != null);
}
/*******************************************************************************
** queries on the store table, where the primary key (id) is the security field
*******************************************************************************/
@Test
void testRecordSecurityPrimaryKeyFieldNoFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_STORE);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(3);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.anyMatch(r -> r.getValueInteger("id").equals(1));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.anyMatch(r -> r.getValueInteger("id").equals(2));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, null));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, Collections.emptyList()));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.anyMatch(r -> r.getValueInteger("id").equals(1))
.anyMatch(r -> r.getValueInteger("id").equals(3));
}
/*******************************************************************************
** not really expected to be any different from where we filter on the primary key,
** but just good to make sure
*******************************************************************************/
@Test
void testRecordSecurityForeignKeyFieldNoFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(8);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(2));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, null));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, Collections.emptyList()));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(6)
.allMatch(r -> r.getValueInteger("storeId").equals(1) || r.getValueInteger("storeId").equals(3));
}
/*******************************************************************************
** Error seen in CTLive - query for order join lineItem, where lineItem's security
** key is in order.
**
** Note - in this test-db setup, there happens to be a storeId in both order &
** orderLine tables, so we can't quite reproduce the error we saw in CTL - so
** query on different tables with the structure that'll produce the error.
*******************************************************************************/
@Test
void testRequestedJoinWithTableWhoseSecurityFieldIsInMainTable() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_WAREHOUSE_STORE_INT);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_WAREHOUSE).withSelect(true));
//////////////////////////////////////////////
// with the all-access key, find all 3 rows //
//////////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(3);
///////////////////////////////////////////
// with 1 security key value, find 1 row //
///////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
///////////////////////////////////////////
// with 1 security key value, find 1 row //
///////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.allMatch(r -> r.getValueInteger("storeId").equals(2));
//////////////////////////////////////////////////////////
// with a mis-matching security key value, 0 rows found //
//////////////////////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
///////////////////////////////////////////////
// with no security key values, 0 rows found //
///////////////////////////////////////////////
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
////////////////////////////////////////////////
// with null security key value, 0 rows found //
////////////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, null));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
//////////////////////////////////////////////////////
// with empty-list security key value, 0 rows found //
//////////////////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, Collections.emptyList()));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
////////////////////////////////
// with 2 values, find 2 rows //
////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(1) || r.getValueInteger("storeId").equals(3));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(6);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("storeId", QCriteriaOperator.IN, List.of(1, 2))));
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityFromJoinTableAlsoImplicitlyInQuery() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER_LINE);
///////////////////////////////////////////////////////////////////////////////////////
// orders 1, 2, and 3 are from store 1, so their lines (5 in total) should be found. //
// note, order 2 has the line with mis-matched store id - but, that shouldn't apply //
// here, because the line table's security comes from the order table. //
///////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("order.id", QCriteriaOperator.IN, List.of(1, 2, 3, 4))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(5);
///////////////////////////////////////////////////////////////////
// order 4 should be the only one found this time (with 2 lines) //
///////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("order.id", QCriteriaOperator.IN, List.of(1, 2, 3, 4))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(2);
////////////////////////////////////////////////////////////////
// make sure we're also good if we explicitly join this table //
////////////////////////////////////////////////////////////////
queryInput.withQueryJoin(new QueryJoin().withJoinTable(TestUtils.TABLE_NAME_ORDER).withSelect(true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(2);
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithLockFromJoinTable() throws QException
{
QInstance qInstance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
/////////////////////////////////////////////////////////////////////////////////////////////////
// remove the normal lock on the order table - replace it with one from the joined store table //
/////////////////////////////////////////////////////////////////////////////////////////////////
qInstance.getTable(TestUtils.TABLE_NAME_ORDER).getRecordSecurityLocks().clear();
qInstance.getTable(TestUtils.TABLE_NAME_ORDER).withRecordSecurityLock(new RecordSecurityLock()
.withSecurityKeyType(TestUtils.TABLE_NAME_STORE)
.withJoinNameChain(List.of("orderJoinStore"))
.withFieldName("store.id"));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(6);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("storeId", QCriteriaOperator.IN, List.of(1, 2))));
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithLockFromJoinTableWhereTheKeyIsOnTheManySide() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_WAREHOUSE);
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1);
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testMultipleReversedDirectionJoinsBetweenSameTables() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
Integer noOfOrders = new CountAction().execute(new CountInput(TestUtils.TABLE_NAME_ORDER)).getCount();
Integer noOfOrderInstructions = new CountAction().execute(new CountInput(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS)).getCount();
{
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// make sure we can join on order.current_order_instruction_id = order_instruction.id -- and that we get back 1 row per order //
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS).withJoinMetaData(QContext.getQInstance().getJoin("orderJoinCurrentOrderInstructions")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(noOfOrders, queryOutput.getRecords().size());
}
{
////////////////////////////////////////////////////////////////////////////////////////////////
// assert that the query succeeds (based on exposed join) if the joinMetaData isn't specified //
////////////////////////////////////////////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(noOfOrders, queryOutput.getRecords().size());
}
{
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// make sure we can join on order.id = order_instruction.order_id (e.g., not the exposed one used above) -- and that we get back 1 row per order instruction //
///////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS).withJoinMetaData(QContext.getQInstance().getJoin("orderInstructionsJoinOrder")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(noOfOrderInstructions, queryOutput.getRecords().size());
}
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testSecurityJoinForJoinedTableFromImplicitlyJoinedTable() throws QException
{
/////////////////////////////////////////////////////////////////////////////////////////
// in this test: //
// query on Order, joined with OrderLine. //
// Order has its own security field (storeId), that's always worked fine. //
// We want to change OrderLine's security field to be item.storeId - not order.storeId //
// so that item has to be brought into the query to secure the items. //
// this was originally broken, as it would generate a WHERE clause for item.storeId, //
// but it wouldn't put item in the FROM cluase.
/////////////////////////////////////////////////////////////////////////////////////////
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
QContext.getQInstance().getTable(TestUtils.TABLE_NAME_ORDER_LINE)
.setRecordSecurityLocks(ListBuilder.of(
new RecordSecurityLock()
.withSecurityKeyType(TestUtils.TABLE_NAME_STORE)
.withFieldName("item.storeId")
.withJoinNameChain(List.of("orderLineJoinItem"))));
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_LINE).withSelect(true));
queryInput.withFilter(new QQueryFilter(new QFilterCriteria(TestUtils.TABLE_NAME_ORDER_LINE + ".sku", QCriteriaOperator.IS_NOT_BLANK)));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertEquals(3, records.size(), "expected no of records");
///////////////////////////////////////////////////////////////////////
// we should get the orderLines for orders 4 and 5 - but not the one //
// for order 2, as it has an item from a different store //
///////////////////////////////////////////////////////////////////////
assertThat(records).allMatch(r -> r.getValueInteger("id").equals(4) || r.getValueInteger("id").equals(5));
}
}

View File

@ -25,26 +25,20 @@ package com.kingsrook.qqq.backend.module.rdbms.actions;
import java.io.Serializable;
import java.time.Instant;
import java.time.temporal.ChronoUnit;
import java.util.Collections;
import java.util.List;
import java.util.Map;
import java.util.Objects;
import java.util.concurrent.atomic.AtomicInteger;
import java.util.function.Predicate;
import com.kingsrook.qqq.backend.core.actions.QBackendTransaction;
import com.kingsrook.qqq.backend.core.actions.tables.CountAction;
import com.kingsrook.qqq.backend.core.actions.tables.InsertAction;
import com.kingsrook.qqq.backend.core.actions.tables.QueryAction;
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.count.CountInput;
import com.kingsrook.qqq.backend.core.model.actions.tables.insert.InsertInput;
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.QueryJoin;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.QueryOutput;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.expressions.Now;
import com.kingsrook.qqq.backend.core.model.actions.tables.query.expressions.NowWithOffset;
@ -52,14 +46,12 @@ import com.kingsrook.qqq.backend.core.model.data.QRecord;
import com.kingsrook.qqq.backend.core.model.metadata.QInstance;
import com.kingsrook.qqq.backend.core.model.metadata.security.RecordSecurityLock;
import com.kingsrook.qqq.backend.core.model.session.QSession;
import com.kingsrook.qqq.backend.core.utils.StringUtils;
import com.kingsrook.qqq.backend.module.rdbms.TestUtils;
import org.junit.jupiter.api.AfterEach;
import org.junit.jupiter.api.Assertions;
import org.junit.jupiter.api.BeforeEach;
import org.junit.jupiter.api.Test;
import static org.assertj.core.api.Assertions.assertThat;
import static org.assertj.core.api.Assertions.assertThatThrownBy;
import static org.junit.jupiter.api.Assertions.assertEquals;
@ -783,675 +775,6 @@ public class RDBMSQueryActionTest extends RDBMSActionTest
/*******************************************************************************
**
*******************************************************************************/
@Test
void testFilterFromJoinTableImplicitly() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("personalIdCard.idNumber", QCriteriaOperator.EQUALS, "19800531")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "Query should find 1 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneLeftJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withType(QueryJoin.Type.LEFT).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(5, queryOutput.getRecords().size(), "Left Join query should find 5 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Garret") && r.getValue("personalIdCard.idNumber") == null);
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tyler") && r.getValue("personalIdCard.idNumber") == null);
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneRightJoinWithoutWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withType(QueryJoin.Type.RIGHT).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(6, queryOutput.getRecords().size(), "Right Join query should find 6 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Tim") && r.getValueString("personalIdCard.idNumber").equals("19760528"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("123123123"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("987987987"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValue("firstName") == null && r.getValueString("personalIdCard.idNumber").equals("456456456"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithWhere() throws QException
{
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber", QCriteriaOperator.STARTS_WITH, "1980")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(2, queryOutput.getRecords().size(), "Join query should find 2 rows");
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("Darin") && r.getValueString("personalIdCard.idNumber").equals("19800531"));
assertThat(queryOutput.getRecords()).anyMatch(r -> r.getValueString("firstName").equals("James") && r.getValueString("personalIdCard.idNumber").equals("19800515"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOneToOneInnerJoinWithOrderBy() throws QException
{
QInstance qInstance = TestUtils.defineInstance();
QueryInput queryInput = initQueryRequest();
queryInput.withQueryJoin(new QueryJoin(qInstance.getJoin(TestUtils.TABLE_NAME_PERSON + "Join" + StringUtils.ucFirst(TestUtils.TABLE_NAME_PERSONAL_ID_CARD))).withSelect(true));
queryInput.setFilter(new QQueryFilter().withOrderBy(new QFilterOrderBy(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
List<String> idNumberListFromQuery = queryOutput.getRecords().stream().map(r -> r.getValueString(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")).toList();
assertEquals(List.of("19760528", "19800515", "19800531"), idNumberListFromQuery);
/////////////////////////
// repeat, sorted desc //
/////////////////////////
queryInput.setFilter(new QQueryFilter().withOrderBy(new QFilterOrderBy(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber", false)));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "Join query should find 3 rows");
idNumberListFromQuery = queryOutput.getRecords().stream().map(r -> r.getValueString(TestUtils.TABLE_NAME_PERSONAL_ID_CARD + ".idNumber")).toList();
assertEquals(List.of("19800531", "19800515", "19760528"), idNumberListFromQuery);
}
/*******************************************************************************
** In the prime data, we've got 1 order line set up with an item from a different
** store than its order. Write a query to find such a case.
*******************************************************************************/
@Test
void testFiveTableOmsJoinFindMismatchedStoreId() throws Exception
{
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER, TestUtils.TABLE_NAME_STORE).withAlias("orderStore").withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER, TestUtils.TABLE_NAME_ORDER_LINE).withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_LINE, TestUtils.TABLE_NAME_ITEM).withSelect(true));
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ITEM, TestUtils.TABLE_NAME_STORE).withAlias("itemStore").withSelect(true));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria().withFieldName("orderStore.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("item.storeId")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
QRecord qRecord = queryOutput.getRecords().get(0);
assertEquals(2, qRecord.getValueInteger("id"));
assertEquals(1, qRecord.getValueInteger("orderStore.id"));
assertEquals(2, qRecord.getValueInteger("itemStore.id"));
//////////////////////////////////////////////////////////////////////////////////////////////////////////
// run the same setup, but this time, use the other-field-name as itemStore.id, instead of item.storeId //
//////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria().withFieldName("orderStore.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("itemStore.id")));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
qRecord = queryOutput.getRecords().get(0);
assertEquals(2, qRecord.getValueInteger("id"));
assertEquals(1, qRecord.getValueInteger("orderStore.id"));
assertEquals(2, qRecord.getValueInteger("itemStore.id"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByOrderLines() throws Exception
{
AtomicInteger orderLineCount = new AtomicInteger();
runTestSql("SELECT COUNT(*) from order_line", (rs) ->
{
rs.next();
orderLineCount.set(rs.getInt(1));
});
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER_LINE);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER).withSelect(true));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(orderLineCount.get(), queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(3, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("order.id").equals(1)).count());
assertEquals(1, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("order.id").equals(2)).count());
assertEquals(1, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("orderId").equals(3)).count());
assertEquals(2, queryOutput.getRecords().stream().filter(r -> r.getValueInteger("orderId").equals(4)).count());
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByPersons() throws Exception
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
/////////////////////////////////////////////////////
// inner join on bill-to person should find 6 rows //
/////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(new QueryJoin(TestUtils.TABLE_NAME_PERSON).withJoinMetaData(instance.getJoin("orderJoinBillToPerson")).withSelect(true)));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(6, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////
// inner join on ship-to person should find 7 rows //
/////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withSelect(true)));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(7, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////////////////////////////
// inner join on both bill-to person and ship-to person should find 5 rows //
/////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true)
));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(5, queryOutput.getRecords().size(), "# of rows found by query");
/////////////////////////////////////////////////////////////////////////////
// left join on both bill-to person and ship-to person should find 8 rows //
/////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withType(QueryJoin.Type.LEFT).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withType(QueryJoin.Type.LEFT).withAlias("billToPerson").withSelect(true)
));
queryOutput = new QueryAction().execute(queryInput);
assertEquals(8, queryOutput.getRecords().size(), "# of rows found by query");
//////////////////////////////////////////////////
// now join through to personalIdCard table too //
//////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
queryInput.setFilter(new QQueryFilter()
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// look for billToPersons w/ idNumber starting with 1980 - should only be James and Darin (assert on that below). //
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
.withCriteria(new QFilterCriteria("billToIdCard.idNumber", QCriteriaOperator.STARTS_WITH, "1980"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(3, queryOutput.getRecords().size(), "# of rows found by query");
assertThat(queryOutput.getRecords().stream().map(r -> r.getValueString("billToPerson.firstName")).toList()).allMatch(p -> p.equals("Darin") || p.equals("James"));
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// ensure we throw if either of the ambiguous joins from person to id-card doesn't specify its left-table //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.rootCause()
.hasMessageContaining("Could not find a join between tables [order][personalIdCard]");
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// ensure we throw if either of the ambiguous joins from person to id-card doesn't specify its left-table //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.rootCause()
.hasMessageContaining("Could not find a join between tables [order][personalIdCard]");
////////////////////////////////////////////////////////////////////////
// ensure we throw if we have a bogus alias name given as a left-side //
////////////////////////////////////////////////////////////////////////
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson").withSelect(true),
new QueryJoin("notATable", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToIdCard").withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToIdCard").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Could not find a join between tables [notATable][personalIdCard]");
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testOmsQueryByPersonsExtraKelkhoffOrder() throws Exception
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
////////////////////////////////////////////////////////////////////////////////////////////////////////////
// insert a second person w/ last name Kelkhoff, then an order for Darin Kelkhoff and this new Kelkhoff - //
// then query for orders w/ bill to person & ship to person both lastname = Kelkhoff, but different ids. //
////////////////////////////////////////////////////////////////////////////////////////////////////////////
Integer specialOrderId = 1701;
runTestSql("INSERT INTO person (id, first_name, last_name, email) VALUES (6, 'Jimmy', 'Kelkhoff', 'dk@gmail.com')", null);
runTestSql("INSERT INTO `order` (id, store_id, bill_to_person_id, ship_to_person_id) VALUES (" + specialOrderId + ", 1, 1, 6)", null);
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withType(QueryJoin.Type.LEFT).withAlias("shipToPerson").withSelect(true),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withType(QueryJoin.Type.LEFT).withAlias("billToPerson").withSelect(true)
));
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.id").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("billToPerson.id"))
);
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
////////////////////////////////////////////////////////////
// re-run that query using personIds from the order table //
////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("order.shipToPersonId").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("order.billToPersonId"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
///////////////////////////////////////////////////////////////////////////////////////////////
// re-run that query using personIds from the order table, but not specifying the table name //
///////////////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria().withFieldName("shipToPerson.lastName").withOperator(QCriteriaOperator.EQUALS).withOtherFieldName("billToPerson.lastName"))
.withCriteria(new QFilterCriteria().withFieldName("shipToPersonId").withOperator(QCriteriaOperator.NOT_EQUALS).withOtherFieldName("billToPersonId"))
);
queryOutput = new QueryAction().execute(queryInput);
assertEquals(1, queryOutput.getRecords().size(), "# of rows found by query");
assertEquals(specialOrderId, queryOutput.getRecords().get(0).getValueInteger("id"));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testDuplicateAliases()
{
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson"),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson"),
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withSelect(true) // w/o alias, should get exception here - dupe table.
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Duplicate table name or alias: personalIdCard");
queryInput.withQueryJoins(List.of(
new QueryJoin(instance.getJoin("orderJoinShipToPerson")).withAlias("shipToPerson"),
new QueryJoin(instance.getJoin("orderJoinBillToPerson")).withAlias("billToPerson"),
new QueryJoin("shipToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("shipToPerson").withSelect(true), // dupe alias, should get exception here
new QueryJoin("billToPerson", TestUtils.TABLE_NAME_PERSONAL_ID_CARD).withAlias("billToPerson").withSelect(true)
));
assertThatThrownBy(() -> new QueryAction().execute(queryInput))
.hasRootCauseMessage("Duplicate table name or alias: shipToPerson");
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, also selecting item.
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoin() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ITEM).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("id") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ITEM + ".description") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on item to order
** do a query on item, also selecting order.
** This is a reverse of the above, to make sure join flipping, etc, is good.
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinReversed() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ITEM);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ORDER).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("description") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ORDER + ".id") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, also selecting item, and also selecting orderLine...
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinAlsoSelectingInBetweenTable() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoins(List.of(
new QueryJoin(TestUtils.TABLE_NAME_ORDER_LINE).withType(QueryJoin.Type.INNER).withSelect(true),
new QueryJoin(TestUtils.TABLE_NAME_ITEM).withType(QueryJoin.Type.INNER).withSelect(true)
));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(11); // one per line item
assertThat(records).allMatch(r -> r.getValue("id") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ORDER_LINE + ".quantity") != null);
assertThat(records).allMatch(r -> r.getValue(TestUtils.TABLE_NAME_ITEM + ".description") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, filtered by item
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinWhereClauseOnly() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria(TestUtils.TABLE_NAME_ITEM + ".description", QCriteriaOperator.STARTS_WITH, "Q-Mart")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(4);
assertThat(records).allMatch(r -> r.getValue("id") != null);
}
/*******************************************************************************
** Given tables:
** order - orderLine - item
** with exposedJoin on order to item
** do a query on order, filtered by item
*******************************************************************************/
@Test
void testTwoTableAwayExposedJoinWhereClauseBothJoinTables() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QInstance instance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter()
.withCriteria(new QFilterCriteria(TestUtils.TABLE_NAME_ITEM + ".description", QCriteriaOperator.STARTS_WITH, "Q-Mart"))
.withCriteria(new QFilterCriteria(TestUtils.TABLE_NAME_ORDER_LINE + ".quantity", QCriteriaOperator.IS_NOT_BLANK))
);
QueryOutput queryOutput = new QueryAction().execute(queryInput);
List<QRecord> records = queryOutput.getRecords();
assertThat(records).hasSize(4);
assertThat(records).allMatch(r -> r.getValue("id") != null);
}
/*******************************************************************************
** queries on the store table, where the primary key (id) is the security field
*******************************************************************************/
@Test
void testRecordSecurityPrimaryKeyFieldNoFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_STORE);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(3);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.anyMatch(r -> r.getValueInteger("id").equals(1));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1)
.anyMatch(r -> r.getValueInteger("id").equals(2));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, null));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, Collections.emptyList()));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.anyMatch(r -> r.getValueInteger("id").equals(1))
.anyMatch(r -> r.getValueInteger("id").equals(3));
}
/*******************************************************************************
** not really expected to be any different from where we filter on the primary key,
** but just good to make sure
*******************************************************************************/
@Test
void testRecordSecurityForeignKeyFieldNoFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(8);
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(2));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, null));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, Collections.emptyList()));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(6)
.allMatch(r -> r.getValueInteger("storeId").equals(1) || r.getValueInteger("storeId").equals(3));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithFilters() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(6);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("storeId", QCriteriaOperator.IN, List.of(1, 2))));
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityFromJoinTableAlsoImplicitlyInQuery() throws QException
{
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER_LINE);
///////////////////////////////////////////////////////////////////////////////////////////
// orders 1, 2, and 3 are from store 1, so their lines (5 in total) should be found. //
// note, order 2 has the line with mis-matched store id - but, that shouldn't apply here //
///////////////////////////////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("order.id", QCriteriaOperator.IN, List.of(1, 2, 3, 4))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(5);
///////////////////////////////////////////////////////////////////
// order 4 should be the only one found this time (with 2 lines) //
///////////////////////////////////////////////////////////////////
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("order.id", QCriteriaOperator.IN, List.of(1, 2, 3, 4))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 2));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(2);
////////////////////////////////////////////////////////////////
// make sure we're also good if we explicitly join this table //
////////////////////////////////////////////////////////////////
queryInput.withQueryJoin(new QueryJoin().withJoinTable(TestUtils.TABLE_NAME_ORDER).withSelect(true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(2);
}
/*******************************************************************************
**
*******************************************************************************/
@ -1606,68 +929,6 @@ public class RDBMSQueryActionTest extends RDBMSActionTest
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithLockFromJoinTable() throws QException
{
QInstance qInstance = TestUtils.defineInstance();
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
/////////////////////////////////////////////////////////////////////////////////////////////////
// remove the normal lock on the order table - replace it with one from the joined store table //
/////////////////////////////////////////////////////////////////////////////////////////////////
qInstance.getTable(TestUtils.TABLE_NAME_ORDER).getRecordSecurityLocks().clear();
qInstance.getTable(TestUtils.TABLE_NAME_ORDER).withRecordSecurityLock(new RecordSecurityLock()
.withSecurityKeyType(TestUtils.TABLE_NAME_STORE)
.withJoinNameChain(List.of("orderJoinStore"))
.withFieldName("store.id"));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
assertThat(new QueryAction().execute(queryInput).getRecords()).hasSize(6);
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 1));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(2)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.TABLE_NAME_STORE, 5));
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("id", QCriteriaOperator.BETWEEN, List.of(2, 7))));
QContext.setQSession(new QSession());
assertThat(new QueryAction().execute(queryInput).getRecords()).isEmpty();
queryInput.setFilter(new QQueryFilter(new QFilterCriteria("storeId", QCriteriaOperator.IN, List.of(1, 2))));
QContext.setQSession(new QSession().withSecurityKeyValues(TestUtils.TABLE_NAME_STORE, List.of(1, 3)));
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(3)
.allMatch(r -> r.getValueInteger("storeId").equals(1));
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testRecordSecurityWithLockFromJoinTableWhereTheKeyIsOnTheManySide() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_WAREHOUSE);
assertThat(new QueryAction().execute(queryInput).getRecords())
.hasSize(1);
}
/*******************************************************************************
**
*******************************************************************************/
@ -1697,51 +958,4 @@ public class RDBMSQueryActionTest extends RDBMSActionTest
}
/*******************************************************************************
**
*******************************************************************************/
@Test
void testMultipleReversedDirectionJoinsBetweenSameTables() throws QException
{
QContext.setQSession(new QSession().withSecurityKeyValue(TestUtils.SECURITY_KEY_STORE_ALL_ACCESS, true));
{
/////////////////////////////////////////////////////////
// assert a failure if the join to use isn't specified //
/////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS));
assertThatThrownBy(() -> new QueryAction().execute(queryInput)).rootCause().hasMessageContaining("More than 1 join was found");
}
Integer noOfOrders = new CountAction().execute(new CountInput(TestUtils.TABLE_NAME_ORDER)).getCount();
Integer noOfOrderInstructions = new CountAction().execute(new CountInput(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS)).getCount();
{
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// make sure we can join on order.current_order_instruction_id = order_instruction.id -- and that we get back 1 row per order //
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS).withJoinMetaData(QContext.getQInstance().getJoin("orderJoinCurrentOrderInstructions")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(noOfOrders, queryOutput.getRecords().size());
}
{
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
// make sure we can join on order.id = order_instruction.order_id -- and that we get back 1 row per order instruction //
////////////////////////////////////////////////////////////////////////////////////////////////////////////////////////
QueryInput queryInput = new QueryInput();
queryInput.setTableName(TestUtils.TABLE_NAME_ORDER);
queryInput.withQueryJoin(new QueryJoin(TestUtils.TABLE_NAME_ORDER_INSTRUCTIONS).withJoinMetaData(QContext.getQInstance().getJoin("orderInstructionsJoinOrder")));
QueryOutput queryOutput = new QueryAction().execute(queryInput);
assertEquals(noOfOrderInstructions, queryOutput.getRecords().size());
}
}
}