From 3e6d80bdc27d4f2fbb0d9392fa7a119ccc6183a7 Mon Sep 17 00:00:00 2001 From: James Agnew Date: Sat, 2 Jan 2021 11:13:51 -0500 Subject: [PATCH] Fix SQL Server paging with new querybuilder (#2265) * Fix SQL Server paging with new querybuilder * Add changelog --- ...fix-sqlserver-paging-new-querybuilder.yaml | 5 + .../jpa/config/HibernateDialectProvider.java | 6 + .../builder/sql/SearchQueryBuilder.java | 71 ++- .../builder/sql/SearchQueryBuilderTest.java | 443 ++++++++++++++++++ 4 files changed, 517 insertions(+), 8 deletions(-) create mode 100644 hapi-fhir-docs/src/main/resources/ca/uhn/hapi/fhir/changelog/5_3_0/2265-fix-sqlserver-paging-new-querybuilder.yaml create mode 100644 hapi-fhir-jpaserver-base/src/test/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilderTest.java diff --git a/hapi-fhir-docs/src/main/resources/ca/uhn/hapi/fhir/changelog/5_3_0/2265-fix-sqlserver-paging-new-querybuilder.yaml b/hapi-fhir-docs/src/main/resources/ca/uhn/hapi/fhir/changelog/5_3_0/2265-fix-sqlserver-paging-new-querybuilder.yaml new file mode 100644 index 00000000000..62d361924d4 --- /dev/null +++ b/hapi-fhir-docs/src/main/resources/ca/uhn/hapi/fhir/changelog/5_3_0/2265-fix-sqlserver-paging-new-querybuilder.yaml @@ -0,0 +1,5 @@ +--- +type: fix +issue: 2265 +title: "The new optimized SQL Generator introduced in HAPI FHIR 5.2.0 did not correctly bind variables + for SQL Server queries, making the search functionality unusable. This has been corrected." diff --git a/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/config/HibernateDialectProvider.java b/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/config/HibernateDialectProvider.java index f11b0b18a1a..8f04ea43c3e 100644 --- a/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/config/HibernateDialectProvider.java +++ b/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/config/HibernateDialectProvider.java @@ -21,6 +21,7 @@ package ca.uhn.fhir.jpa.config; */ import ca.uhn.fhir.util.ReflectionUtil; +import com.google.common.annotations.VisibleForTesting; import org.apache.commons.lang3.Validate; import org.hibernate.dialect.Dialect; import org.springframework.beans.factory.annotation.Autowired; @@ -32,6 +33,11 @@ public class HibernateDialectProvider { private LocalContainerEntityManagerFactoryBean myEntityManagerFactory; private Dialect myDialect; + @VisibleForTesting + public void setDialectForUnitTest(Dialect theDialect) { + myDialect = theDialect; + } + public Dialect getDialect() { Dialect dialect = myDialect; if (dialect == null) { diff --git a/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilder.java b/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilder.java index 611a5c2ce02..44ecad70e8f 100644 --- a/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilder.java +++ b/hapi-fhir-jpaserver-base/src/main/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilder.java @@ -59,7 +59,8 @@ import com.healthmarketscience.sqlbuilder.dbspec.basic.DbSpec; import com.healthmarketscience.sqlbuilder.dbspec.basic.DbTable; import org.apache.commons.lang3.Validate; import org.hibernate.dialect.Dialect; -import org.hibernate.dialect.pagination.LimitHandler; +import org.hibernate.dialect.SQLServerDialect; +import org.hibernate.dialect.pagination.AbstractLimitHandler; import org.hibernate.engine.spi.RowSelection; import org.slf4j.Logger; import org.slf4j.LoggerFactory; @@ -355,24 +356,78 @@ public class SearchQueryBuilder { maxResultsToFetch = defaultIfNull(maxResultsToFetch, 10000); - LimitHandler limitHandler = myDialect.getLimitHandler(); + AbstractLimitHandler limitHandler = (AbstractLimitHandler) myDialect.getLimitHandler(); RowSelection selection = new RowSelection(); selection.setFirstRow(offset); selection.setMaxRows(maxResultsToFetch); sql = limitHandler.processSql(sql, selection); - if (limitHandler.supportsLimit()) { - bindVariables.add(maxResultsToFetch); - } - if (limitHandler.supportsLimitOffset() && offset != null) { - bindVariables.add(offset); - } + int startOfQueryParameterIndex = 0; + boolean isSqlServer = (myDialect instanceof SQLServerDialect); + if (isSqlServer) { + + // The SQLServerDialect has a bunch of one-off processing to deal with rules on when + // a limit can be used, so we can't rely on the flags that the limithandler exposes since + // the exact structure of the query depends on the parameters + if (sql.contains("TOP(?)")) { + bindVariables.add(0, maxResultsToFetch); + } + if (sql.contains("offset 0 rows fetch next ? rows only")) { + bindVariables.add(maxResultsToFetch); + } + if (sql.contains("offset ? rows fetch next ? rows only")) { + bindVariables.add(theOffset); + bindVariables.add(maxResultsToFetch); + } + if (offset != null && sql.contains("__hibernate_row_nr__")) { + bindVariables.add(theOffset + 1); + bindVariables.add(theOffset + maxResultsToFetch + 1); + } + + } else if (limitHandler.supportsVariableLimit()) { + + boolean bindLimitParametersFirst = limitHandler.bindLimitParametersFirst(); + if (limitHandler.useMaxForLimit() && offset != null) { + maxResultsToFetch = maxResultsToFetch + offset; + } + + if (limitHandler.bindLimitParametersInReverseOrder()) { + startOfQueryParameterIndex = bindCountParameter(bindVariables, maxResultsToFetch, limitHandler, startOfQueryParameterIndex, bindLimitParametersFirst); + bindOffsetParameter(bindVariables, offset, limitHandler, startOfQueryParameterIndex, bindLimitParametersFirst); + } else { + startOfQueryParameterIndex = bindOffsetParameter(bindVariables, offset, limitHandler, startOfQueryParameterIndex, bindLimitParametersFirst); + bindCountParameter(bindVariables, maxResultsToFetch, limitHandler, startOfQueryParameterIndex, bindLimitParametersFirst); + } + + } } return new GeneratedSql(myMatchNothing, sql, bindVariables); } + private int bindCountParameter(List bindVariables, Integer maxResultsToFetch, AbstractLimitHandler limitHandler, int startOfQueryParameterIndex, boolean bindLimitParametersFirst) { + if (limitHandler.supportsLimit()) { + if (bindLimitParametersFirst) { + bindVariables.add(startOfQueryParameterIndex++, maxResultsToFetch); + } else { + bindVariables.add(maxResultsToFetch); + } + } + return startOfQueryParameterIndex; + } + + public int bindOffsetParameter(List theBindVariables, @Nullable Integer theOffset, AbstractLimitHandler theLimitHandler, int theStartOfQueryParameterIndex, boolean theBindLimitParametersFirst) { + if (theLimitHandler.supportsLimitOffset() && theOffset != null) { + if (theBindLimitParametersFirst) { + theBindVariables.add(theStartOfQueryParameterIndex++, theOffset); + } else { + theBindVariables.add(theOffset); + } + } + return theStartOfQueryParameterIndex; + } + /** * If at least one predicate builder already exists, return the last one added to the chain. If none has been selected, create a builder on HFJ_RESOURCE, add it and return it. */ diff --git a/hapi-fhir-jpaserver-base/src/test/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilderTest.java b/hapi-fhir-jpaserver-base/src/test/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilderTest.java new file mode 100644 index 00000000000..e6ba8aabf56 --- /dev/null +++ b/hapi-fhir-jpaserver-base/src/test/java/ca/uhn/fhir/jpa/search/builder/sql/SearchQueryBuilderTest.java @@ -0,0 +1,443 @@ +package ca.uhn.fhir.jpa.search.builder.sql; + +import ca.uhn.fhir.context.FhirContext; +import ca.uhn.fhir.context.FhirVersionEnum; +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.ResourceTablePredicateBuilder; +import com.google.common.collect.Lists; +import org.hibernate.dialect.DerbyTenSevenDialect; +import org.hibernate.dialect.MariaDB103Dialect; +import org.hibernate.dialect.MySQL8Dialect; +import org.hibernate.dialect.MySQLDialect; +import org.hibernate.dialect.Oracle12cDialect; +import org.hibernate.dialect.PostgreSQL95Dialect; +import org.hibernate.dialect.SQLServer2005Dialect; +import org.hibernate.dialect.SQLServer2012Dialect; +import org.junit.jupiter.api.BeforeEach; +import org.junit.jupiter.api.Test; +import org.junit.jupiter.api.extension.ExtendWith; +import org.springframework.beans.factory.annotation.Autowired; +import org.springframework.context.annotation.Bean; +import org.springframework.context.annotation.Configuration; +import org.springframework.context.annotation.Scope; +import org.springframework.test.context.ContextConfiguration; +import org.springframework.test.context.junit.jupiter.SpringExtension; + +import static org.hamcrest.MatcherAssert.assertThat; +import static org.hamcrest.Matchers.contains; +import static org.junit.jupiter.api.Assertions.assertEquals; + +@ExtendWith(SpringExtension.class) +@ContextConfiguration(classes = {SearchQueryBuilderTest.MyConfig.class}) +public class SearchQueryBuilderTest { + + private FhirContext myFhirContext; + private ModelConfig myModelConfig; + private PartitionSettings myPartitionSettings; + private RequestPartitionId myRequestPartitionId; + + @Autowired + private SqlObjectFactory mySqlBuilderFactory; + + @BeforeEach + public void before() { + myFhirContext = FhirContext.forCached(FhirVersionEnum.R4); + myModelConfig = new ModelConfig(); + myPartitionSettings = new PartitionSettings(); + myRequestPartitionId = RequestPartitionId.allPartitions(); + } + + @Test + public void testRangeSqlServer2005_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new SQLServer2005Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT TOP(?) t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains(10, "Patient", 500L, 501L)); + + // Range + generated = builder.generate(10, 5); + assertEquals("WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( SELECT t0.RES_ID as page0_ FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ) inner_query ) SELECT page0_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 11, 16)); + + } + + @Test + public void testRangeSqlServer2005_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new SQLServer2005Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT TOP(?) t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains(10, "Patient", 500L, 501L)); + + // Range + generated = builder.generate(10, 5); + assertEquals("WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( SELECT TOP(?) t0.RES_ID as page0_ FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST ) inner_query ) SELECT page0_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains(5, "Patient", 500L, 501L, 11, 16)); + + } + + + @Test + public void testRangeSqlServer2012_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new SQLServer2012Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT TOP(?) t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains(10, "Patient", 500L, 501L)); + + // Range + generated = builder.generate(10, 5); + assertEquals("WITH query AS (SELECT inner_query.*, ROW_NUMBER() OVER (ORDER BY CURRENT_TIMESTAMP) as __hibernate_row_nr__ FROM ( SELECT t0.RES_ID as page0_ FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ) inner_query ) SELECT page0_ FROM query WHERE __hibernate_row_nr__ >= ? AND __hibernate_row_nr__ < ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 11, 16)); + + } + + @Test + public void testRangeSqlServer2012_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new SQLServer2012Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST offset 0 rows fetch next ? rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST offset ? rows fetch next ? rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10, 5)); + + } + + @Test + public void testRangePostgreSQL95_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new PostgreSQL95Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ? offset ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 5, 10)); + + } + + @Test + public void testRangePostgreSQL95_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new PostgreSQL95Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ? offset ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 5, 10)); + + } + + @Test + public void testRangeOracle12c_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new Oracle12cDialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("select * from ( SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ) where rownum <= ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("select * from ( select row_.*, rownum rownum_ from ( SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ) row_ where rownum <= ?) where rownum_ > ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 15, 10)); + + } + + @Test + public void testRangeOracle12c_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new Oracle12cDialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("select * from ( SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST ) where rownum <= ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("select * from ( select row_.*, rownum rownum_ from ( SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST ) row_ where rownum <= ?) where rownum_ > ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 15, 10)); + + } + + + @Test + public void testRangeMySQL8_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new MySQL8Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ?, ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10, 5)); + + } + + @Test + public void testRangeMySQL8_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new MySQL8Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ?, ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10, 5)); + + } + + + @Test + public void testRangeMariaDB103_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new MariaDB103Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) limit ?, ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10, 5)); + + } + + @Test + public void testRangeMariaDB103_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new MariaDB103Dialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST limit ?, ?", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L, 10, 5)); + + } + + + @Test + public void testRangeDerbyTenSeven_NoSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new DerbyTenSevenDialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) ))", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) fetch first 10 rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) offset 10 rows fetch next 5 rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + } + + @Test + public void testRangeDerbyTenSeven_WithSort() { + + HibernateDialectProvider dialectProvider = new HibernateDialectProvider(); + dialectProvider.setDialectForUnitTest(new DerbyTenSevenDialect()); + SearchQueryBuilder builder = new SearchQueryBuilder(myFhirContext, myModelConfig, myPartitionSettings, myRequestPartitionId, "Patient", mySqlBuilderFactory, dialectProvider, false); + builder.addResourceIdsPredicate(Lists.newArrayList(500L, 501L)); + builder.addSort(builder.getOrCreateResourceTablePredicateBuilder().getColumnLastUpdated(), true); + GeneratedSql generated; + + // No range + generated = builder.generate(null, null); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Max only + generated = builder.generate(null, 10); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST fetch first 10 rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + // Range + generated = builder.generate(10, 5); + assertEquals("SELECT t0.RES_ID FROM HFJ_RESOURCE t0 WHERE (((t0.RES_TYPE = ?) AND (t0.RES_DELETED_AT IS NULL)) AND (t0.RES_ID IN (?,?) )) ORDER BY t0.RES_UPDATED ASC NULLS LAST offset 10 rows fetch next 5 rows only", generated.getSql()); + assertThat(generated.getBindVariables().toString(), generated.getBindVariables(), contains("Patient", 500L, 501L)); + + } + + @Configuration + public static class MyConfig { + + @Bean + @Scope("prototype") + public ResourceTablePredicateBuilder ResourceTablePredicateBuilder(SearchQueryBuilder theSearchQueryBuilder) { + return new ResourceTablePredicateBuilder(theSearchQueryBuilder); + } + + @Bean + public SqlObjectFactory sqlObjectFactory() { + return new SqlObjectFactory(); + } + + } +}