Change order by clause in search query to support MySQL, MSSQL and MariaDB.
This commit is contained in:
parent
84d9854e24
commit
63e0c90023
|
@ -159,7 +159,7 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValueLow(), theAscending);
|
||||
mySqlBuilder.addSortDate(sortPredicateBuilder.getColumnValueLow(), theAscending);
|
||||
}
|
||||
|
||||
public void addSortOnLastUpdated(boolean theAscending) {
|
||||
|
@ -170,7 +170,7 @@ public class QueryStack {
|
|||
} else {
|
||||
resourceTablePredicateBuilder = mySqlBuilder.addResourceTablePredicateBuilder(firstPredicateBuilder.getResourceIdColumn());
|
||||
}
|
||||
mySqlBuilder.addSort(resourceTablePredicateBuilder.getColumnLastUpdated(), theAscending);
|
||||
mySqlBuilder.addSortDate(resourceTablePredicateBuilder.getColumnLastUpdated(), theAscending);
|
||||
}
|
||||
|
||||
|
||||
|
@ -180,7 +180,7 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
mySqlBuilder.addSortNumeric(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
}
|
||||
|
||||
public void addSortOnQuantity(String theResourceName, String theParamName, boolean theAscending) {
|
||||
|
@ -189,18 +189,18 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
mySqlBuilder.addSortNumeric(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
}
|
||||
|
||||
public void addSortOnResourceId(boolean theAscending) {
|
||||
BaseJoiningPredicateBuilder firstPredicateBuilder = mySqlBuilder.getOrCreateFirstPredicateBuilder();
|
||||
ForcedIdPredicateBuilder sortPredicateBuilder = mySqlBuilder.addForcedIdPredicateBuilder(firstPredicateBuilder.getResourceIdColumn());
|
||||
if (!theAscending) {
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnForcedId(), false, OrderObject.NullOrder.FIRST);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnForcedId(), false, OrderObject.NullOrder.FIRST);
|
||||
} else {
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnForcedId(), true);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnForcedId(), true);
|
||||
}
|
||||
mySqlBuilder.addSort(firstPredicateBuilder.getResourceIdColumn(), theAscending);
|
||||
mySqlBuilder.addSortNumeric(firstPredicateBuilder.getResourceIdColumn(), theAscending);
|
||||
|
||||
}
|
||||
|
||||
|
@ -210,7 +210,7 @@ public class QueryStack {
|
|||
|
||||
Condition pathPredicate = sortPredicateBuilder.createPredicateSourcePaths(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(pathPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnTargetResourceId(), theAscending);
|
||||
mySqlBuilder.addSortNumeric(sortPredicateBuilder.getColumnTargetResourceId(), theAscending);
|
||||
}
|
||||
|
||||
|
||||
|
@ -220,7 +220,7 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValueNormalized(), theAscending);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnValueNormalized(), theAscending);
|
||||
}
|
||||
|
||||
public void addSortOnToken(String theResourceName, String theParamName, boolean theAscending) {
|
||||
|
@ -229,8 +229,8 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnSystem(), theAscending);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnSystem(), theAscending);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
}
|
||||
|
||||
public void addSortOnUri(String theResourceName, String theParamName, boolean theAscending) {
|
||||
|
@ -239,7 +239,7 @@ public class QueryStack {
|
|||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate(theResourceName, theParamName);
|
||||
mySqlBuilder.addPredicate(hashIdentityPredicate);
|
||||
mySqlBuilder.addSort(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
mySqlBuilder.addSortString(sortPredicateBuilder.getColumnValue(), theAscending);
|
||||
}
|
||||
|
||||
|
||||
|
|
|
@ -67,6 +67,7 @@ import org.slf4j.LoggerFactory;
|
|||
import javax.annotation.Nonnull;
|
||||
import javax.annotation.Nullable;
|
||||
import java.util.ArrayList;
|
||||
import java.util.Arrays;
|
||||
import java.util.Collection;
|
||||
import java.util.List;
|
||||
import java.util.UUID;
|
||||
|
@ -94,6 +95,9 @@ public class SearchQueryBuilder {
|
|||
private ResourceTablePredicateBuilder myResourceTableRoot;
|
||||
private boolean myHaveAtLeastOnePredicate;
|
||||
private BaseJoiningPredicateBuilder myFirstPredicateBuilder;
|
||||
private boolean dialectIsMsSql;
|
||||
private boolean dialectIsMySql;
|
||||
private boolean dialectIsMariaDb;
|
||||
|
||||
/**
|
||||
* Constructor
|
||||
|
@ -114,6 +118,16 @@ public class SearchQueryBuilder {
|
|||
mySqlBuilderFactory = theSqlBuilderFactory;
|
||||
myCountQuery = theCountQuery;
|
||||
myDialect = theDialect;
|
||||
if (myDialect instanceof org.hibernate.dialect.MySQL57Dialect){
|
||||
dialectIsMySql = true;
|
||||
}
|
||||
if (myDialect instanceof org.hibernate.dialect.MariaDB53Dialect){
|
||||
dialectIsMariaDb = true;
|
||||
}
|
||||
if (myDialect instanceof org.hibernate.dialect.SQLServer2012Dialect){
|
||||
dialectIsMsSql = true;
|
||||
}
|
||||
|
||||
|
||||
mySpec = new DbSpec();
|
||||
mySchema = mySpec.addDefaultSchema();
|
||||
|
@ -495,12 +509,87 @@ public class SearchQueryBuilder {
|
|||
return myHaveAtLeastOnePredicate;
|
||||
}
|
||||
|
||||
public void addSort(DbColumn theColumnValueNormalized, boolean theAscending) {
|
||||
public void addSortString(DbColumn theColumnValueNormalized, boolean theAscending) {
|
||||
OrderObject.NullOrder nullOrder = OrderObject.NullOrder.LAST;
|
||||
addSort(theColumnValueNormalized, theAscending, nullOrder);
|
||||
addSortString(theColumnValueNormalized, theAscending, nullOrder);
|
||||
}
|
||||
|
||||
public void addSort(DbColumn theTheColumnValueNormalized, boolean theTheAscending, OrderObject.NullOrder theNullOrder) {
|
||||
public void addSortNumeric(DbColumn theColumnValueNormalized, boolean theAscending) {
|
||||
OrderObject.NullOrder nullOrder = OrderObject.NullOrder.LAST;
|
||||
addSortNumeric(theColumnValueNormalized, theAscending, nullOrder);
|
||||
}
|
||||
|
||||
public void addSortDate(DbColumn theColumnValueNormalized, boolean theAscending) {
|
||||
OrderObject.NullOrder nullOrder = OrderObject.NullOrder.LAST;
|
||||
addSortDate(theColumnValueNormalized, theAscending, nullOrder);
|
||||
}
|
||||
|
||||
public void addSortString(DbColumn theTheColumnValueNormalized, boolean theTheAscending, OrderObject.NullOrder theNullOrder) {
|
||||
if ((dialectIsMariaDb || dialectIsMySql || dialectIsMsSql)) {
|
||||
// MariaDB, MySQL and MSSQL do not support "NULLS FIRST" and "NULLS LAST" syntax.
|
||||
// Null values are always treated as less than non-null values.
|
||||
// As such special handling is required here.
|
||||
String direction = theTheAscending ? " ASC" : " DESC";
|
||||
String sortColumnName = theTheColumnValueNormalized.getTable().getAlias() + "." + theTheColumnValueNormalized.getName();
|
||||
if ((theTheAscending && theNullOrder == OrderObject.NullOrder.LAST)
|
||||
|| (!theTheAscending && theNullOrder == OrderObject.NullOrder.FIRST)) {
|
||||
// Coalescing the value with a String consisting of 200 'z' characters will ensure that the rows appear
|
||||
// in the correct order with nulls being treated as the highest String values.
|
||||
char[] chars = new char[200];
|
||||
Arrays.fill(chars, 'z');
|
||||
String lastString = new String(chars);
|
||||
sortColumnName = "COALESCE(" + sortColumnName + ", '" + lastString + "')";
|
||||
}
|
||||
mySelect.addCustomOrderings(sortColumnName + direction);
|
||||
} else {
|
||||
addSort(theTheColumnValueNormalized, theTheAscending, theNullOrder);
|
||||
}
|
||||
}
|
||||
|
||||
public void addSortNumeric(DbColumn theTheColumnValueNormalized, boolean theTheAscending, OrderObject.NullOrder theNullOrder) {
|
||||
if ((dialectIsMariaDb || dialectIsMySql || dialectIsMsSql)) {
|
||||
// MariaDB, MySQL and MSSQL do not support "NULLS FIRST" and "NULLS LAST" syntax.
|
||||
// Null values are always treated as less than non-null values.
|
||||
// As such special handling is required here.
|
||||
String direction;
|
||||
String sortColumnName = theTheColumnValueNormalized.getTable().getAlias() + "." + theTheColumnValueNormalized.getName();
|
||||
if ((theTheAscending && theNullOrder == OrderObject.NullOrder.LAST)
|
||||
|| (!theTheAscending && theNullOrder == OrderObject.NullOrder.FIRST)) {
|
||||
// Negating the numeric column value and reversing the sort order will ensure that the rows appear
|
||||
// in the correct order with nulls appearing first or last as needed.
|
||||
direction = theTheAscending ? " DESC" : " ASC";
|
||||
sortColumnName = "-" + sortColumnName;
|
||||
} else {
|
||||
direction = theTheAscending ? " ASC" : " DESC";
|
||||
}
|
||||
mySelect.addCustomOrderings(sortColumnName + direction);
|
||||
} else {
|
||||
addSort(theTheColumnValueNormalized, theTheAscending, theNullOrder);
|
||||
}
|
||||
}
|
||||
|
||||
public void addSortDate(DbColumn theTheColumnValueNormalized, boolean theTheAscending, OrderObject.NullOrder theNullOrder) {
|
||||
if ((dialectIsMariaDb || dialectIsMySql || dialectIsMsSql)) {
|
||||
// MariaDB, MySQL and MSSQL do not support "NULLS FIRST" and "NULLS LAST" syntax.
|
||||
// Null values are always treated as less than non-null values.
|
||||
// As such special handling is required here.
|
||||
String direction = theTheAscending ? " ASC" : " DESC";
|
||||
String sortColumnName = theTheColumnValueNormalized.getTable().getAlias() + "." + theTheColumnValueNormalized.getName();
|
||||
if ((theTheAscending && theNullOrder == OrderObject.NullOrder.LAST)
|
||||
|| (!theTheAscending && theNullOrder == OrderObject.NullOrder.FIRST)) {
|
||||
// Coalescing the value with a date well into the future will ensure that the rows appear
|
||||
// in the correct order with nulls being treated as the highest Date values.
|
||||
sortColumnName = "COALESCE(" + sortColumnName + ", '9000-01-01')";
|
||||
} else {
|
||||
direction = theTheAscending ? " ASC" : " DESC";
|
||||
}
|
||||
mySelect.addCustomOrderings(sortColumnName + direction);
|
||||
} else {
|
||||
addSort(theTheColumnValueNormalized, theTheAscending, theNullOrder);
|
||||
}
|
||||
}
|
||||
|
||||
private void addSort(DbColumn theTheColumnValueNormalized, boolean theTheAscending, OrderObject.NullOrder theNullOrder) {
|
||||
OrderObject.Dir direction = theTheAscending ? OrderObject.Dir.ASCENDING : OrderObject.Dir.DESCENDING;
|
||||
OrderObject orderObject = new OrderObject(direction, theTheColumnValueNormalized);
|
||||
orderObject.setNullOrder(theNullOrder);
|
||||
|
|
|
@ -0,0 +1,179 @@
|
|||
package ca.uhn.fhir.jpa.search.builder.sql;
|
||||
|
||||
import ca.uhn.fhir.context.FhirContext;
|
||||
import ca.uhn.fhir.interceptor.model.RequestPartitionId;
|
||||
import ca.uhn.fhir.jpa.config.HibernateDialectProvider;
|
||||
import ca.uhn.fhir.jpa.model.config.PartitionSettings;
|
||||
import ca.uhn.fhir.jpa.model.entity.ModelConfig;
|
||||
import ca.uhn.fhir.jpa.search.builder.predicate.BaseJoiningPredicateBuilder;
|
||||
import ca.uhn.fhir.jpa.search.builder.predicate.DatePredicateBuilder;
|
||||
import ca.uhn.fhir.jpa.search.builder.predicate.ResourceTablePredicateBuilder;
|
||||
import ca.uhn.fhir.jpa.search.builder.predicate.StringPredicateBuilder;
|
||||
import com.healthmarketscience.sqlbuilder.Condition;
|
||||
import com.healthmarketscience.sqlbuilder.OrderObject;
|
||||
import org.junit.jupiter.api.BeforeEach;
|
||||
import org.junit.jupiter.api.Test;
|
||||
import org.mockito.Mock;
|
||||
import org.mockito.MockitoAnnotations;
|
||||
|
||||
import static org.junit.jupiter.api.Assertions.assertTrue;
|
||||
import static org.mockito.ArgumentMatchers.any;
|
||||
import static org.mockito.Mockito.when;
|
||||
|
||||
public class SearchQueryBuilderMySqlTest {
|
||||
|
||||
@Mock
|
||||
private SqlObjectFactory mySqlObjectFactory;
|
||||
@Mock
|
||||
private HibernateDialectProvider myHibernateDialectProvider;
|
||||
|
||||
private final FhirContext myFhirContext = FhirContext.forR4();
|
||||
|
||||
@BeforeEach
|
||||
public void beforeInitMocks() {
|
||||
MockitoAnnotations.initMocks(this);
|
||||
when(myHibernateDialectProvider.getDialect()).thenReturn(new org.hibernate.dialect.MySQL57Dialect());
|
||||
}
|
||||
|
||||
private SearchQueryBuilder createSearchQueryBuilder() {
|
||||
return new SearchQueryBuilder(myFhirContext, new ModelConfig(), new PartitionSettings(), RequestPartitionId.allPartitions(), "Patient", mySqlObjectFactory, myHibernateDialectProvider, false);
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortNumericNoNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithNumericSort(true,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY -t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithNumericSort(false,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
}
|
||||
|
||||
private GeneratedSql buildSqlWithNumericSort(Boolean theAscending, OrderObject.NullOrder theNullOrder) {
|
||||
SearchQueryBuilder searchQueryBuilder = createSearchQueryBuilder();
|
||||
when(mySqlObjectFactory.resourceTable(any())).thenReturn(new ResourceTablePredicateBuilder(searchQueryBuilder));
|
||||
when(mySqlObjectFactory.dateIndexTable(any())).thenReturn(new DatePredicateBuilder(searchQueryBuilder));
|
||||
|
||||
BaseJoiningPredicateBuilder firstPredicateBuilder = searchQueryBuilder.getOrCreateFirstPredicateBuilder();
|
||||
DatePredicateBuilder sortPredicateBuilder = searchQueryBuilder.addDatePredicateBuilder(firstPredicateBuilder.getResourceIdColumn());
|
||||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate("MolecularSequence", "variant-start");
|
||||
searchQueryBuilder.addPredicate(hashIdentityPredicate);
|
||||
if (theNullOrder == null) {
|
||||
searchQueryBuilder.addSortNumeric(sortPredicateBuilder.getColumnValueLow(), theAscending);
|
||||
} else {
|
||||
searchQueryBuilder.addSortNumeric(sortPredicateBuilder.getColumnValueLow(), theAscending, theNullOrder);
|
||||
}
|
||||
|
||||
return searchQueryBuilder.generate(0,500);
|
||||
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortNumericWithNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithNumericSort(true, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithNumericSort(false, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY -t1.SP_VALUE_LOW ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithNumericSort(true, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY -t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithNumericSort(false, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortStringNoNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithStringSort(true,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_NORMALIZED, \'zzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzz\') ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithStringSort(false,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_NORMALIZED DESC limit ?"));
|
||||
|
||||
}
|
||||
|
||||
private GeneratedSql buildSqlWithStringSort(Boolean theAscending, OrderObject.NullOrder theNullOrder) {
|
||||
SearchQueryBuilder searchQueryBuilder = createSearchQueryBuilder();
|
||||
when(mySqlObjectFactory.resourceTable(any())).thenReturn(new ResourceTablePredicateBuilder(searchQueryBuilder));
|
||||
when(mySqlObjectFactory.stringIndexTable(any())).thenReturn(new StringPredicateBuilder(searchQueryBuilder));
|
||||
|
||||
BaseJoiningPredicateBuilder firstPredicateBuilder = searchQueryBuilder.getOrCreateFirstPredicateBuilder();
|
||||
StringPredicateBuilder sortPredicateBuilder = searchQueryBuilder.addStringPredicateBuilder(firstPredicateBuilder.getResourceIdColumn());
|
||||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate("patient", "family");
|
||||
searchQueryBuilder.addPredicate(hashIdentityPredicate);
|
||||
if (theNullOrder == null) {
|
||||
searchQueryBuilder.addSortString(sortPredicateBuilder.getColumnValueNormalized(), theAscending);
|
||||
} else {
|
||||
searchQueryBuilder.addSortString(sortPredicateBuilder.getColumnValueNormalized(), theAscending, theNullOrder);
|
||||
}
|
||||
|
||||
return searchQueryBuilder.generate(0,500);
|
||||
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortStringWithNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithStringSort(true, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_NORMALIZED ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithStringSort(false, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_NORMALIZED, 'zzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzz') DESC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithStringSort(true, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_NORMALIZED, 'zzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzzz') ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithStringSort(false, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_NORMALIZED DESC limit ?"));
|
||||
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortDateNoNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithDateSort(true,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_LOW, '9000-01-01') ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithDateSort(false,null);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
}
|
||||
|
||||
private GeneratedSql buildSqlWithDateSort(Boolean theAscending, OrderObject.NullOrder theNullOrder) {
|
||||
SearchQueryBuilder searchQueryBuilder = createSearchQueryBuilder();
|
||||
when(mySqlObjectFactory.resourceTable(any())).thenReturn(new ResourceTablePredicateBuilder(searchQueryBuilder));
|
||||
when(mySqlObjectFactory.dateIndexTable(any())).thenReturn(new DatePredicateBuilder(searchQueryBuilder));
|
||||
|
||||
BaseJoiningPredicateBuilder firstPredicateBuilder = searchQueryBuilder.getOrCreateFirstPredicateBuilder();
|
||||
DatePredicateBuilder sortPredicateBuilder = searchQueryBuilder.addDatePredicateBuilder(firstPredicateBuilder.getResourceIdColumn());
|
||||
|
||||
Condition hashIdentityPredicate = sortPredicateBuilder.createHashIdentityPredicate("patient", "birthdate");
|
||||
searchQueryBuilder.addPredicate(hashIdentityPredicate);
|
||||
if (theNullOrder == null) {
|
||||
searchQueryBuilder.addSortDate(sortPredicateBuilder.getColumnValueLow(), theAscending);
|
||||
} else {
|
||||
searchQueryBuilder.addSortDate(sortPredicateBuilder.getColumnValueLow(), theAscending, theNullOrder);
|
||||
}
|
||||
|
||||
return searchQueryBuilder.generate(0,500);
|
||||
|
||||
}
|
||||
|
||||
@Test
|
||||
public void testAddSortDateWithNullOrder() {
|
||||
GeneratedSql generatedSql = buildSqlWithDateSort(true, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithDateSort(false, OrderObject.NullOrder.FIRST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_LOW, '9000-01-01') DESC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithDateSort(true, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY COALESCE(t1.SP_VALUE_LOW, '9000-01-01') ASC limit ?"));
|
||||
|
||||
generatedSql = buildSqlWithDateSort(false, OrderObject.NullOrder.LAST);
|
||||
assertTrue(generatedSql.getSql().endsWith("ORDER BY t1.SP_VALUE_LOW DESC limit ?"));
|
||||
|
||||
}
|
||||
}
|
Loading…
Reference in New Issue