Skip to content

Commit

Permalink
Adapt H2PagingQueryProvider for H2 v2.x
Browse files Browse the repository at this point in the history
Issue #4047
  • Loading branch information
hpoettker authored and fmbenhassine committed Jan 18, 2022
1 parent 4dddb10 commit db2d622
Show file tree
Hide file tree
Showing 3 changed files with 129 additions and 20 deletions.
@@ -1,5 +1,5 @@
/*
* Copyright 2006-2008 the original author or authors.
* Copyright 2006-2022 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
Expand All @@ -20,22 +20,23 @@
* H2 implementation of a {@link org.springframework.batch.item.database.PagingQueryProvider} using database specific features.
*
* @author Dave Syer
* @author Henning Pöttker
* @since 2.1
*/
public class H2PagingQueryProvider extends AbstractSqlPagingQueryProvider {

@Override
public String generateFirstPageQuery(int pageSize) {
return SqlPagingQueryUtils.generateTopSqlQuery(this, false, buildTopClause(pageSize));
return SqlPagingQueryUtils.generateLimitSqlQuery(this, false, buildLimitClause(pageSize));
}

@Override
public String generateRemainingPagesQuery(int pageSize) {
return SqlPagingQueryUtils.generateTopSqlQuery(this, true, buildTopClause(pageSize));
return SqlPagingQueryUtils.generateLimitSqlQuery(this, true, buildLimitClause(pageSize));
}

private String buildTopClause(int pageSize) {
return new StringBuilder().append("TOP ").append(pageSize).toString();
private String buildLimitClause(int pageSize) {
return new StringBuilder().append("FETCH NEXT ").append(pageSize).append(" ROWS ONLY").toString();
}

@Override
Expand All @@ -44,8 +45,10 @@ public String generateJumpToItemQuery(int itemIndex, int pageSize) {
int offset = (page * pageSize) - 1;
offset = offset<0 ? 0 : offset;

String topClause = new StringBuilder().append("LIMIT ").append(offset).append(" 1").toString();
return SqlPagingQueryUtils.generateTopJumpToQuery(this, topClause);
String limitClause = new StringBuilder().append("OFFSET ")
.append(offset).append(" ROWS FETCH NEXT 1 ROWS ONLY")
.toString();
return SqlPagingQueryUtils.generateLimitJumpToQuery(this, limitClause);
}

}
@@ -0,0 +1,102 @@
/*
* Copyright 2022 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
* You may obtain a copy of the License at
*
* https://www.apache.org/licenses/LICENSE-2.0
*
* Unless required by applicable law or agreed to in writing, software
* distributed under the License is distributed on an "AS IS" BASIS,
* WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
* See the License for the specific language governing permissions and
* limitations under the License.
*/
package org.springframework.batch.item.database.support;

import java.util.Arrays;
import java.util.HashMap;
import java.util.List;
import java.util.Map;
import java.util.UUID;
import java.util.stream.Collectors;

import javax.sql.DataSource;

import org.junit.Test;
import org.junit.runner.RunWith;
import org.junit.runners.Parameterized;
import org.junit.runners.Parameterized.Parameters;

import org.springframework.batch.item.database.Order;
import org.springframework.jdbc.core.JdbcTemplate;
import org.springframework.jdbc.datasource.DataSourceTransactionManager;
import org.springframework.jdbc.datasource.SimpleDriverDataSource;
import org.springframework.transaction.PlatformTransactionManager;
import org.springframework.transaction.support.TransactionTemplate;

import static org.junit.Assert.assertArrayEquals;
import static org.junit.Assert.assertEquals;

/**
* @author Henning Pöttker
*/
@RunWith(Parameterized.class)
public class H2PagingQueryProviderIntegrationTests {

private final String compatibilityMode;

public H2PagingQueryProviderIntegrationTests(String compatibilityMode) {
this.compatibilityMode = compatibilityMode;
}

@Test
public void testQueryProvider() {
String connectionUrl = String.format("jdbc:h2:mem:%s;MODE=%s", UUID.randomUUID(), compatibilityMode);
DataSource dataSource = new SimpleDriverDataSource(new org.h2.Driver(), connectionUrl, "sa", "");
JdbcTemplate jdbcTemplate = new JdbcTemplate(dataSource);
PlatformTransactionManager transactionManager = new DataSourceTransactionManager(dataSource);
TransactionTemplate transactionTemplate = new TransactionTemplate(transactionManager);

transactionTemplate.executeWithoutResult(status -> {
jdbcTemplate.execute("CREATE TABLE TEST_TABLE (ID BIGINT NOT NULL, STRING VARCHAR(16) NOT NULL)");
jdbcTemplate.execute("INSERT INTO TEST_TABLE (ID, STRING) VALUES (1, 'Spring')");
jdbcTemplate.execute("INSERT INTO TEST_TABLE (ID, STRING) VALUES (2, 'Batch')");
jdbcTemplate.execute("INSERT INTO TEST_TABLE (ID, STRING) VALUES (3, 'Infrastructure')");

H2PagingQueryProvider queryProvider = new H2PagingQueryProvider();
queryProvider.setSelectClause("STRING");
queryProvider.setFromClause("TEST_TABLE");
Map<String, Order> sortKeys = new HashMap<>();
sortKeys.put("ID", Order.ASCENDING);
queryProvider.setSortKeys(sortKeys);

List<String> firstPage = jdbcTemplate.queryForList(
queryProvider.generateFirstPageQuery(2),
String.class
);
assertArrayEquals("firstPage", new String[]{"Spring", "Batch"}, firstPage.toArray());

List<String> secondPage = jdbcTemplate.queryForList(
queryProvider.generateRemainingPagesQuery(2),
String.class,
2
);
assertArrayEquals("secondPage", new String[]{"Infrastructure"}, secondPage.toArray());

Integer secondItem = jdbcTemplate.queryForObject(
queryProvider.generateJumpToItemQuery(3, 2),
Integer.class
);
assertEquals(Integer.valueOf(2), secondItem);
});
}

@Parameters
public static List<Object[]> data() throws Exception {
return Arrays.stream(org.h2.engine.Mode.ModeEnum.values())
.map(mode -> new Object[]{mode.toString()})
.collect(Collectors.toList());
}
}
@@ -1,5 +1,5 @@
/*
* Copyright 2006-2015 the original author or authors.
* Copyright 2006-2022 the original author or authors.
*
* Licensed under the Apache License, Version 2.0 (the "License");
* you may not use this file except in compliance with the License.
Expand All @@ -23,6 +23,7 @@
* @author Thomas Risberg
* @author Dave Syer
* @author Michael Minella
* @author Henning Pöttker
*/
public class H2PagingQueryProviderTests extends AbstractSqlPagingQueryProviderTests {

Expand All @@ -33,28 +34,29 @@ public H2PagingQueryProviderTests() {
@Test
@Override
public void testGenerateFirstPageQuery() {
String sql = "SELECT TOP 100 id, name, age FROM foo WHERE bar = 1 ORDER BY id ASC";
String sql = "SELECT id, name, age FROM foo WHERE bar = 1 ORDER BY id ASC FETCH NEXT 100 ROWS ONLY";
String s = pagingQueryProvider.generateFirstPageQuery(pageSize);
assertEquals(sql, s);
}

@Test @Override
public void testGenerateRemainingPagesQuery() {
String sql = "SELECT TOP 100 id, name, age FROM foo WHERE (bar = 1) AND ((id > ?)) ORDER BY id ASC";
String sql = "SELECT id, name, age FROM foo WHERE (bar = 1) AND ((id > ?)) "
+ "ORDER BY id ASC FETCH NEXT 100 ROWS ONLY";
String s = pagingQueryProvider.generateRemainingPagesQuery(pageSize);
assertEquals(sql, s);
}

@Test @Override
public void testGenerateJumpToItemQuery() {
String sql = "SELECT LIMIT 99 1 id FROM foo WHERE bar = 1 ORDER BY id ASC";
String sql = "SELECT id FROM foo WHERE bar = 1 ORDER BY id ASC OFFSET 99 ROWS FETCH NEXT 1 ROWS ONLY";
String s = pagingQueryProvider.generateJumpToItemQuery(145, pageSize);
assertEquals(sql, s);
}

@Test @Override
public void testGenerateJumpToItemQueryForFirstPage() {
String sql = "SELECT LIMIT 0 1 id FROM foo WHERE bar = 1 ORDER BY id ASC";
String sql = "SELECT id FROM foo WHERE bar = 1 ORDER BY id ASC OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY";
String s = pagingQueryProvider.generateJumpToItemQuery(45, pageSize);
assertEquals(sql, s);
}
Expand All @@ -63,7 +65,7 @@ public void testGenerateJumpToItemQueryForFirstPage() {
@Test
public void testGenerateFirstPageQueryWithGroupBy() {
pagingQueryProvider.setGroupClause("dep");
String sql = "SELECT TOP 100 id, name, age FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC";
String sql = "SELECT id, name, age FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC FETCH NEXT 100 ROWS ONLY";
String s = pagingQueryProvider.generateFirstPageQuery(pageSize);
assertEquals(sql, s);
}
Expand All @@ -72,7 +74,8 @@ public void testGenerateFirstPageQueryWithGroupBy() {
@Test
public void testGenerateRemainingPagesQueryWithGroupBy() {
pagingQueryProvider.setGroupClause("dep");
String sql = "SELECT TOP 100 id, name, age FROM foo WHERE (bar = 1) AND ((id > ?)) GROUP BY dep ORDER BY id ASC";
String sql = "SELECT id, name, age FROM foo WHERE (bar = 1) AND ((id > ?)) GROUP BY dep "
+ "ORDER BY id ASC FETCH NEXT 100 ROWS ONLY";
String s = pagingQueryProvider.generateRemainingPagesQuery(pageSize);
assertEquals(sql, s);
}
Expand All @@ -81,7 +84,7 @@ public void testGenerateRemainingPagesQueryWithGroupBy() {
@Test
public void testGenerateJumpToItemQueryWithGroupBy() {
pagingQueryProvider.setGroupClause("dep");
String sql = "SELECT LIMIT 99 1 id FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC";
String sql = "SELECT id FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC OFFSET 99 ROWS FETCH NEXT 1 ROWS ONLY";
String s = pagingQueryProvider.generateJumpToItemQuery(145, pageSize);
assertEquals(sql, s);
}
Expand All @@ -90,28 +93,29 @@ public void testGenerateJumpToItemQueryWithGroupBy() {
@Test
public void testGenerateJumpToItemQueryForFirstPageWithGroupBy() {
pagingQueryProvider.setGroupClause("dep");
String sql = "SELECT LIMIT 0 1 id FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC";
String sql = "SELECT id FROM foo WHERE bar = 1 GROUP BY dep ORDER BY id ASC OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY";
String s = pagingQueryProvider.generateJumpToItemQuery(45, pageSize);
assertEquals(sql, s);
}

@Override
public String getFirstPageSqlWithMultipleSortKeys() {
return "SELECT TOP 100 id, name, age FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC";
return "SELECT id, name, age FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC FETCH NEXT 100 ROWS ONLY";
}

@Override
public String getRemainingSqlWithMultipleSortKeys() {
return "SELECT TOP 100 id, name, age FROM foo WHERE (bar = 1) AND ((name > ?) OR (name = ? AND id < ?)) ORDER BY name ASC, id DESC";
return "SELECT id, name, age FROM foo WHERE (bar = 1) AND ((name > ?) OR (name = ? AND id < ?)) "
+ "ORDER BY name ASC, id DESC FETCH NEXT 100 ROWS ONLY";
}

@Override
public String getJumpToItemQueryWithMultipleSortKeys() {
return "SELECT LIMIT 99 1 name, id FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC";
return "SELECT name, id FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC OFFSET 99 ROWS FETCH NEXT 1 ROWS ONLY";
}

@Override
public String getJumpToItemQueryForFirstPageWithMultipleSortKeys() {
return "SELECT LIMIT 0 1 name, id FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC";
return "SELECT name, id FROM foo WHERE bar = 1 ORDER BY name ASC, id DESC OFFSET 0 ROWS FETCH NEXT 1 ROWS ONLY";
}
}

0 comments on commit db2d622

Please sign in to comment.