HHH-12704 - MSSQL executing StoredProcedure on different DB using dot notation throws error

Add test case proving the issue is caused by the SQL Server JDBC Driver
This commit is contained in:
Vlad Mihalcea 2018-06-21 17:48:51 +03:00
parent cdef29b09b
commit ffa5eb0e1d
5 changed files with 435 additions and 193 deletions

View File

@ -108,7 +108,7 @@ ext {
mariadb: 'org.mariadb.jdbc:mariadb-java-client:2.2.3',
oracle: 'com.oracle.jdbc:ojdbc8:12.2.0.1',
mssql: 'com.microsoft.sqlserver:mssql-jdbc:6.1.0.jre8',
mssql: 'com.microsoft.sqlserver:mssql-jdbc:6.4.0.jre8',
db2: 'com.ibm.db2:db2jcc:10.5',
hana: 'com.sap.cloud.db.jdbc:ngdbc:2.2.16', // for HANA 1 the minimum required client version is 1.120.20

View File

@ -0,0 +1,63 @@
/*
* Hibernate, Relational Persistence for Idiomatic Java
*
* License: GNU Lesser General Public License (LGPL), version 2.1 or later.
* See the lgpl.txt file in the root directory or <http://www.gnu.org/licenses/lgpl-2.1.html>.
*/
package org.hibernate.test.procedure;
import java.sql.Connection;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.Map;
import java.util.function.Consumer;
import javax.persistence.EntityManager;
import javax.persistence.ParameterMode;
import javax.persistence.StoredProcedureQuery;
import org.hibernate.boot.registry.StandardServiceRegistry;
import org.hibernate.boot.registry.StandardServiceRegistryBuilder;
import org.hibernate.dialect.SQLServer2012Dialect;
import org.hibernate.engine.jdbc.spi.JdbcServices;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.testing.RequiresDialect;
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
/**
* @author Vlad Mihalcea
*/
public class AbstractStoredProcedureTest extends BaseEntityManagerFunctionalTestCase {
protected void doInAutoCommit(Consumer<Statement> consumer, Map settings) {
StandardServiceRegistryBuilder ssrb = new StandardServiceRegistryBuilder();
if ( settings != null ) {
ssrb.applySettings( settings );
}
StandardServiceRegistry ssr = ssrb.build();
try {
try (Connection connection = ssr.getService( JdbcServices.class )
.getBootstrapJdbcConnectionAccess()
.obtainConnection();
Statement statement = connection.createStatement()) {
connection.setAutoCommit( true );
consumer.accept( statement );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
}
finally {
StandardServiceRegistryBuilder.destroy( ssr );
}
}
protected void doInAutoCommit(Consumer<Statement> consumer) {
doInAutoCommit( consumer, null );
}
}

View File

@ -0,0 +1,167 @@
/*
* Hibernate, Relational Persistence for Idiomatic Java
*
* License: GNU Lesser General Public License (LGPL), version 2.1 or later.
* See the lgpl.txt file in the root directory or <http://www.gnu.org/licenses/lgpl-2.1.html>.
*/
package org.hibernate.test.procedure;
import java.sql.CallableStatement;
import java.sql.Connection;
import java.sql.SQLException;
import java.sql.Statement;
import java.sql.Timestamp;
import java.sql.Types;
import java.time.LocalDateTime;
import java.time.ZoneOffset;
import java.util.Collections;
import javax.persistence.EntityManager;
import javax.persistence.ParameterMode;
import javax.persistence.StoredProcedureQuery;
import org.hibernate.Session;
import org.hibernate.boot.registry.StandardServiceRegistry;
import org.hibernate.boot.registry.StandardServiceRegistryBuilder;
import org.hibernate.cfg.AvailableSettings;
import org.hibernate.cfg.Environment;
import org.hibernate.dialect.SQLServer2012Dialect;
import org.hibernate.engine.jdbc.spi.JdbcServices;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.testing.FailureExpected;
import org.hibernate.testing.RequiresDialect;
import org.hibernate.testing.TestForIssue;
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
/**
* @author Vlad Mihalcea
*/
@RequiresDialect(SQLServer2012Dialect.class)
@TestForIssue( jiraKey = "HHH-12704" )
public class SQLServerStoredProcedureCrossDatabaseTest extends AbstractStoredProcedureTest {
private final String DATABASE_NAME_TOKEN = "databaseName=";
private final String DATABASE_NAME = "hibernate_orm_test_sp";
@Override
protected Class<?>[] getAnnotatedClasses() {
return new Class<?>[] {
Person.class,
Phone.class,
};
}
@Before
public void init() {
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP DATABASE " + DATABASE_NAME );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "CREATE DATABASE " + DATABASE_NAME );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
String url = (String) Environment.getProperties().get( AvailableSettings.URL );
String[] tokens = url.split( DATABASE_NAME_TOKEN );
url = tokens[0] + DATABASE_NAME_TOKEN + DATABASE_NAME;
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP PROCEDURE sp_square_number" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
}, Collections.singletonMap( AvailableSettings.URL, url ));
doInAutoCommit( statement -> {
try {
statement.executeUpdate(
"CREATE PROCEDURE sp_square_number " +
" @inputNumber INT, " +
" @outputNumber INT OUTPUT " +
"AS " +
"BEGIN " +
" SELECT @outputNumber = @inputNumber * @inputNumber; " +
"END"
);
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
}, Collections.singletonMap( AvailableSettings.URL, url ));
}
@Test
@FailureExpected( jiraKey = "HHH-12704", message = "SQL Server JDBC Driver does not support registering name parameters properly")
public void testStoredProcedureViaJPANamedParameters() {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( DATABASE_NAME + ".dbo.sp_square_number" );
query.registerStoredProcedureParameter( "inputNumber", Integer.class, ParameterMode.IN );
query.registerStoredProcedureParameter( "outputNumber", Integer.class, ParameterMode.OUT );
query.setParameter( "inputNumber", 7 );
query.execute();
int result = (int) query.getOutputParameterValue( "outputNumber" );
assertEquals( 49, result );
} );
}
@Test
public void testStoredProcedureViaJPA() {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( DATABASE_NAME + ".dbo.sp_square_number" );
query.registerStoredProcedureParameter( 1, Integer.class, ParameterMode.IN );
query.registerStoredProcedureParameter( 2, Integer.class, ParameterMode.OUT );
query.setParameter( 1, 7 );
query.execute();
int result = (int) query.getOutputParameterValue( 2 );
assertEquals( 49, result );
} );
}
@Test
public void testStoredProcedureViaJDBC() {
doInJPA( this::entityManagerFactory, entityManager -> {
entityManager.unwrap( Session.class ).doWork( connection -> {
try (CallableStatement storedProcedure = connection.prepareCall(
"{ call " + DATABASE_NAME + ".dbo.sp_square_number(?, ?) }" )) {
try {
storedProcedure.registerOutParameter( 2, Types.INTEGER );
storedProcedure.setInt( 1, 7 );
storedProcedure.execute();
int result = storedProcedure.getInt( 2 );
assertEquals( 49, result );
}
finally {
if ( storedProcedure != null ) {
storedProcedure.close();
}
}
}
} );
} );
}
}

View File

@ -0,0 +1,99 @@
/*
* Hibernate, Relational Persistence for Idiomatic Java
*
* License: GNU Lesser General Public License (LGPL), version 2.1 or later.
* See the lgpl.txt file in the root directory or <http://www.gnu.org/licenses/lgpl-2.1.html>.
*/
package org.hibernate.test.procedure;
import java.sql.SQLException;
import javax.persistence.ParameterMode;
import javax.persistence.StoredProcedureQuery;
import org.hibernate.dialect.SQLServer2012Dialect;
import org.hibernate.testing.RequiresDialect;
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
/**
* @author Vlad Mihalcea
*/
@RequiresDialect(SQLServer2012Dialect.class)
public class SQLServerStoredProcedureCrossSchemaTest extends AbstractStoredProcedureTest {
@Override
protected Class<?>[] getAnnotatedClasses() {
return new Class<?>[] {
Person.class,
Phone.class,
};
}
@Before
public void init() {
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP PROCEDURE sp_test.sp_square_number" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP SCHEMA sp_test" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "CREATE SCHEMA sp_test" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
doInAutoCommit( statement -> {
try {
statement.executeUpdate(
"CREATE PROCEDURE sp_test.sp_square_number " +
" @inputNumber INT, " +
" @outputNumber INT OUTPUT " +
"AS " +
"BEGIN " +
" SELECT @outputNumber = @inputNumber * @inputNumber; " +
"END"
);
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
}
@Test
public void testStoredProcedureViaJPA() {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_test.sp_square_number");
query.registerStoredProcedureParameter("inputNumber", Integer.class, ParameterMode.IN);
query.registerStoredProcedureParameter("outputNumber", Integer.class, ParameterMode.OUT);
query.setParameter("inputNumber", 7);
query.execute();
int result = (int) query.getOutputParameterValue("outputNumber");
assertEquals( 49, result );
} );
}
}

View File

@ -29,6 +29,7 @@
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
import static org.junit.Assert.assertNotNull;
import static org.junit.Assert.assertTrue;
@ -37,7 +38,7 @@
* @author Vlad Mihalcea
*/
@RequiresDialect(SQLServer2012Dialect.class)
public class SQLServerStoredProcedureTest extends BaseEntityManagerFunctionalTestCase {
public class SQLServerStoredProcedureTest extends AbstractStoredProcedureTest {
@Override
protected Class<?>[] getAnnotatedClasses() {
@ -49,171 +50,102 @@ protected Class<?>[] getAnnotatedClasses() {
@Before
public void init() {
EntityManager entityManager = createEntityManager();
entityManager.getTransaction().begin();
Session session = entityManager.unwrap( Session.class );
session.doWork( new Work() {
@Override
public void execute(Connection connection) throws SQLException {
Statement statement = null;
try {
statement = connection.createStatement();
statement.executeUpdate( "DROP PROCEDURE sp_count_phones" );
}
catch (SQLException ignore) {
}
finally {
if ( statement != null ) {
statement.close();
}
}
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP PROCEDURE sp_count_phones" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
entityManager.getTransaction().commit();
entityManager.close();
entityManager = createEntityManager();
entityManager.getTransaction().begin();
session = entityManager.unwrap( Session.class );
session.doWork( new Work() {
@Override
public void execute(Connection connection) throws SQLException {
Statement statement = null;
try {
statement = connection.createStatement();
statement.executeUpdate( "DROP FUNCTION fn_count_phones" );
}
catch (SQLException ignore) {
}
finally {
if ( statement != null ) {
statement.close();
}
}
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP FUNCTION fn_count_phones" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
entityManager.getTransaction().commit();
entityManager.close();
entityManager = createEntityManager();
entityManager.getTransaction().begin();
session = entityManager.unwrap( Session.class );
session.doWork( new Work() {
@Override
public void execute(Connection connection) throws SQLException {
Statement statement = null;
try {
statement = connection.createStatement();
statement.executeUpdate( "DROP PROCEDURE sp_phones" );
}
catch (SQLException ignore) {
}
finally {
if ( statement != null ) {
statement.close();
}
}
doInAutoCommit( statement -> {
try {
statement.executeUpdate( "DROP PROCEDURE sp_phones" );
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
entityManager.getTransaction().commit();
entityManager.close();
doInAutoCommit( statement -> {
try {
statement.executeUpdate(
"CREATE PROCEDURE sp_count_phones " +
" @personId INT, " +
" @phoneCount INT OUTPUT " +
"AS " +
"BEGIN " +
" SELECT @phoneCount = COUNT(*) " +
" FROM Phone " +
" WHERE person_id = @personId " +
"END"
);
entityManager = createEntityManager();
entityManager.getTransaction().begin();
session = entityManager.unwrap( Session.class );
statement.executeUpdate(
"CREATE FUNCTION fn_count_phones (@personId INT) " +
"RETURNS INT " +
"AS " +
"BEGIN " +
" DECLARE @phoneCount int; " +
" SELECT @phoneCount = COUNT(*) " +
" FROM Phone " +
" WHERE person_id = @personId; " +
" RETURN(@phoneCount); " +
"END"
);
session.doWork( new Work() {
@Override
public void execute(Connection connection) throws SQLException {
Statement statement = null;
try {
statement = connection.createStatement();
statement.executeUpdate(
"CREATE PROCEDURE sp_count_phones " +
" @personId INT, " +
" @phoneCount INT OUTPUT " +
"AS " +
"BEGIN " +
" SELECT @phoneCount = COUNT(*) " +
" FROM Phone " +
" WHERE person_id = @personId " +
"END"
);
statement.executeUpdate(
"CREATE FUNCTION fn_count_phones (@personId INT) " +
"RETURNS INT " +
"AS " +
"BEGIN " +
" DECLARE @phoneCount int; " +
" SELECT @phoneCount = COUNT(*) " +
" FROM Phone " +
" WHERE person_id = @personId; " +
" RETURN(@phoneCount); " +
"END"
);
statement.executeUpdate(
"CREATE PROCEDURE sp_phones " +
" @personId INT, " +
" @phones CURSOR VARYING OUTPUT " +
"AS " +
" SET NOCOUNT ON; " +
" SET @phones = CURSOR " +
" FORWARD_ONLY STATIC FOR " +
" SELECT * " +
" FROM Phone " +
" WHERE person_id = @personId; " +
" OPEN @phones;"
);
}
finally {
if ( statement != null ) {
statement.close();
}
}
statement.executeUpdate(
"CREATE PROCEDURE sp_phones " +
" @personId INT, " +
" @phones CURSOR VARYING OUTPUT " +
"AS " +
" SET NOCOUNT ON; " +
" SET @phones = CURSOR " +
" FORWARD_ONLY STATIC FOR " +
" SELECT * " +
" FROM Phone " +
" WHERE person_id = @personId; " +
" OPEN @phones;"
);
}
catch (SQLException e) {
log.debug( e.getMessage() );
}
} );
entityManager.getTransaction().commit();
entityManager.close();
doInJPA( this::entityManagerFactory, entityManager -> {
Person person1 = new Person( "John Doe" );
person1.setNickName( "JD" );
person1.setAddress( "Earth" );
person1.setCreatedOn( Timestamp.from( LocalDateTime.of( 2000, 1, 1, 0, 0, 0 ).toInstant( ZoneOffset.UTC ) ) );
entityManager = createEntityManager();
entityManager.getTransaction().begin();
entityManager.persist( person1 );
Person person1 = new Person( "John Doe" );
person1.setNickName( "JD" );
person1.setAddress( "Earth" );
person1.setCreatedOn( Timestamp.from( LocalDateTime.of( 2000, 1, 1, 0, 0, 0 ).toInstant( ZoneOffset.UTC ) ) );
Phone phone1 = new Phone( "123-456-7890" );
phone1.setId( 1L );
entityManager.persist( person1 );
person1.addPhone( phone1 );
Phone phone1 = new Phone( "123-456-7890" );
phone1.setId( 1L );
Phone phone2 = new Phone( "098_765-4321" );
phone2.setId( 2L );
person1.addPhone( phone1 );
Phone phone2 = new Phone( "098_765-4321" );
phone2.setId( 2L );
person1.addPhone( phone2 );
entityManager.getTransaction().commit();
entityManager.close();
person1.addPhone( phone2 );
} );
}
@Test
public void testStoredProcedureOutParameter() {
EntityManager entityManager = createEntityManager();
entityManager.getTransaction().begin();
try {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_count_phones");
query.registerStoredProcedureParameter("personId", Long.class, ParameterMode.IN);
query.registerStoredProcedureParameter("phoneCount", Long.class, ParameterMode.OUT);
@ -223,67 +155,48 @@ public void testStoredProcedureOutParameter() {
query.execute();
Long phoneCount = (Long) query.getOutputParameterValue("phoneCount");
assertEquals(Long.valueOf(2), phoneCount);
}
finally {
entityManager.getTransaction().rollback();
entityManager.close();
}
} );
}
@Test
public void testStoredProcedureRefCursor() {
EntityManager entityManager = createEntityManager();
entityManager.getTransaction().begin();
doInJPA( this::entityManagerFactory, entityManager -> {
try {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_phones");
query.registerStoredProcedureParameter(1, Long.class, ParameterMode.IN);
query.registerStoredProcedureParameter(2, Class.class, ParameterMode.REF_CURSOR);
query.setParameter(1, 1L);
try {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_phones");
query.registerStoredProcedureParameter(1, Long.class, ParameterMode.IN);
query.registerStoredProcedureParameter(2, Class.class, ParameterMode.REF_CURSOR);
query.setParameter(1, 1L);
query.execute();
List<Object[]> postComments = query.getResultList();
assertNotNull(postComments);
}
catch (Exception e) {
assertTrue( Pattern.compile( "Dialect .*? not known to support REF_CURSOR parameters").matcher( e.getCause().getMessage()).matches());
}
finally {
entityManager.getTransaction().rollback();
entityManager.close();
}
query.execute();
List<Object[]> postComments = query.getResultList();
assertNotNull(postComments);
}
catch (Exception e) {
assertTrue( Pattern.compile( "Dialect .*? not known to support REF_CURSOR parameters").matcher( e.getCause().getMessage()).matches());
}
} );
}
@Test
public void testStoredProcedureReturnValue() {
EntityManager entityManager = createEntityManager();
entityManager.getTransaction().begin();
try {
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( new Work() {
@Override
public void execute(Connection connection) throws SQLException {
CallableStatement function = null;
try {
function = connection.prepareCall("{ ? = call fn_count_phones(?) }");
function.registerOutParameter(1, Types.INTEGER);
function.setInt(2, 1);
function.execute();
int phoneCount = function.getInt(1);
assertEquals(2, phoneCount);
}
finally {
if ( function != null ) {
function.close();
}
session.doWork( connection -> {
CallableStatement function = null;
try {
function = connection.prepareCall("{ ? = call fn_count_phones(?) }");
function.registerOutParameter(1, Types.INTEGER);
function.setInt(2, 1);
function.execute();
int phoneCount = function.getInt(1);
assertEquals(2, phoneCount);
}
finally {
if ( function != null ) {
function.close();
}
}
} );
}
finally {
entityManager.getTransaction().rollback();
entityManager.close();
}
} );
}
}