From c5704dbafafa07ca79c5edc996134c7073853196 Mon Sep 17 00:00:00 2001 From: Vlad Mihalcea Date: Thu, 14 Apr 2016 13:04:32 +0300 Subject: [PATCH] HHH-10750 - Add stored procedure unit tests for Oracle, MySQL, PostgreSQL, and SQL Server --- build.gradle | 6 +- databases.gradle | 2 +- .../procedure/MySQLStoredProcedureTest.java | 339 +++++++++++++++++ .../procedure/OracleStoredProcedureTest.java | 353 ++++++++++++++++++ .../org/hibernate/test/procedure/Person.java | 138 +++++++ .../org/hibernate/test/procedure/Phone.java | 62 +++ .../PostgreSQLStoredProcedureTest.java | 282 ++++++++++++++ .../SQLServerStoredProcedureTest.java | 283 ++++++++++++++ 8 files changed, 1461 insertions(+), 4 deletions(-) create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/MySQLStoredProcedureTest.java create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/OracleStoredProcedureTest.java create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/Person.java create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/Phone.java create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/PostgreSQLStoredProcedureTest.java create mode 100644 hibernate-core/src/test/java/org/hibernate/test/procedure/SQLServerStoredProcedureTest.java diff --git a/build.gradle b/build.gradle index 8eecde2451..99c2537e42 100644 --- a/build.gradle +++ b/build.gradle @@ -142,19 +142,19 @@ subprojects { subProject -> testRuntime( libraries.log4j ) testRuntime( libraries.javassist ) + testRuntime( libraries.woodstox ) + + //Databases testRuntime( libraries.h2 ) testRuntime( libraries.hsqldb ) testRuntime( libraries.postgresql ) testRuntime( libraries.mysql ) testRuntime( libraries.mariadb ) - testRuntime( libraries.woodstox ) - if (db.equalsIgnoreCase("oracle")) { dependencies { testRuntime( libraries.oracle ) } } - if (db.equalsIgnoreCase("mssql")) { dependencies { testRuntime( libraries.mssql ) diff --git a/databases.gradle b/databases.gradle index 0e6b7c5654..ae3bbb79c2 100644 --- a/databases.gradle +++ b/databases.gradle @@ -63,7 +63,7 @@ ext { 'jdbc.driver': 'com.microsoft.sqlserver.jdbc.SQLServerDriver', 'jdbc.user' : 'hibernate_orm_test', 'jdbc.pass' : 'hibernate_orm_test', - 'jdbc.url' : 'jdbc:sqlserver://localhost;instance=SQLEXPRESS;databaseName=hibernate_orm_test;user=sa;password=adm1n' + 'jdbc.url' : 'jdbc:sqlserver://localhost;instance=SQLEXPRESS;databaseName=hibernate_orm_test' ] ] } diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/MySQLStoredProcedureTest.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/MySQLStoredProcedureTest.java new file mode 100644 index 0000000000..87f01bf255 --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/MySQLStoredProcedureTest.java @@ -0,0 +1,339 @@ +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.List; +import java.util.concurrent.atomic.AtomicReference; +import java.util.regex.Pattern; +import javax.persistence.EntityManager; +import javax.persistence.ParameterMode; +import javax.persistence.StoredProcedureQuery; + +import org.hibernate.Session; +import org.hibernate.dialect.MySQL5Dialect; +import org.hibernate.jdbc.Work; +import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase; +import org.hibernate.procedure.ProcedureCall; +import org.hibernate.result.Output; +import org.hibernate.result.ResultSetOutput; + +import org.hibernate.testing.RequiresDialect; +import org.junit.After; +import org.junit.Before; +import org.junit.Test; + +import static org.junit.Assert.assertEquals; +import static org.junit.Assert.assertTrue; + +/** + * @author Vlad Mihalcea + */ +@RequiresDialect(MySQL5Dialect.class) +public class MySQLStoredProcedureTest extends BaseEntityManagerFunctionalTestCase { + + @Override + protected Class[] getAnnotatedClasses() { + return new Class[] { + Person.class, + Phone.class, + }; + } + + @Before + public void init() { + destroy(); + + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + 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( + "CREATE PROCEDURE sp_count_phones (" + + " IN personId INT, " + + " OUT phoneCount INT " + + ") " + + "BEGIN " + + " SELECT COUNT(*) INTO phoneCount " + + " FROM phone " + + " WHERE phone.person_id = personId; " + + "END" + ); + statement.executeUpdate( + "CREATE PROCEDURE sp_phones(IN personId INT) " + + "BEGIN " + + " SELECT * " + + " FROM phone " + + " WHERE person_id = personId; " + + "END" + ); + statement.executeUpdate( + "CREATE FUNCTION fn_count_phones(personId integer) " + + "RETURNS integer " + + "DETERMINISTIC " + + "READS SQL DATA " + + "BEGIN " + + " DECLARE phoneCount integer; " + + " SELECT COUNT(*) INTO phoneCount " + + " FROM phone " + + " WHERE phone.person_id = personId; " + + " RETURN phoneCount; " + + "END" + ); + } finally { + if ( statement != null ) { + statement.close(); + } + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + 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.persist( person1 ); + + Phone phone1 = new Phone( "123-456-7890" ); + phone1.setId( 1L ); + + person1.addPhone( phone1 ); + + Phone phone2 = new Phone( "098_765-4321" ); + phone2.setId( 2L ); + + person1.addPhone( phone2 ); + + entityManager.getTransaction().commit(); + } + finally { + entityManager.close(); + } + } + + @After + public void destroy() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( new Work() { + @Override + public void execute(Connection connection) throws SQLException { + try (Statement statement = connection.createStatement()) { + statement.executeUpdate( "DROP PROCEDURE IF EXISTS sp_count_phones" ); + } + catch (SQLException ignore) { + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( new Work() { + @Override + public void execute(Connection connection) throws SQLException { + try (Statement statement = connection.createStatement()) { + statement.executeUpdate( "DROP PROCEDURE IF EXISTS sp_phones" ); + } + catch (SQLException ignore) { + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( new Work() { + @Override + public void execute(Connection connection) throws SQLException { + try (Statement statement = connection.createStatement()) { + statement.executeUpdate( "DROP FUNCTION IF EXISTS fn_count_phones" ); + } + catch (SQLException ignore) { + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testStoredProcedureOutParameter() { + + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "sp_count_phones" ); + query.registerStoredProcedureParameter( "personId", Long.class, ParameterMode.IN ); + query.registerStoredProcedureParameter( "phoneCount", Long.class, ParameterMode.OUT ); + + query.setParameter( "personId", 1L ); + + query.execute(); + Long phoneCount = (Long) query.getOutputParameterValue( "phoneCount" ); + assertEquals( Long.valueOf( 2 ), phoneCount ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testHibernateProcedureCallOutParameter() { + + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + + ProcedureCall call = session.createStoredProcedureCall( "sp_count_phones" ); + call.registerParameter( "personId", Long.class, ParameterMode.IN ).bindValue( 1L ); + call.registerParameter( "phoneCount", Long.class, ParameterMode.OUT ); + + Long phoneCount = (Long) call.getOutputs().getOutputParameterValue( "phoneCount" ); + assertEquals( Long.valueOf( 2 ), phoneCount ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testStoredProcedureRefCursor() { + + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "sp_phones" ); + query.registerStoredProcedureParameter( 1, void.class, ParameterMode.REF_CURSOR ); + query.registerStoredProcedureParameter( 2, Long.class, ParameterMode.IN ); + + query.setParameter( 2, 1L ); + + List personComments = query.getResultList(); + assertEquals( 2, personComments.size() ); + } + 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(); + } + } + + @Test + public void testStoredProcedureReturnValue() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "sp_phones" ); + query.registerStoredProcedureParameter( 1, Long.class, ParameterMode.IN ); + + query.setParameter( 1, 1L ); + + List personComments = query.getResultList(); + assertEquals( 2, personComments.size() ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testHibernateProcedureCallReturnValueParameter() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + + ProcedureCall call = session.createStoredProcedureCall( "sp_phones" ); + call.registerParameter( 1, Long.class, ParameterMode.IN ).bindValue( 1L ); + + Output output = call.getOutputs().getCurrent(); + + List personComments = ( (ResultSetOutput) output ).getResultList(); + assertEquals( 2, personComments.size() ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testFunctionWithJDBC() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + final AtomicReference phoneCount = new AtomicReference<>(); + Session session = entityManager.unwrap( Session.class ); + session.doWork( connection -> { + try (CallableStatement function = connection.prepareCall( + "{ ? = call fn_count_phones(?) }" )) { + function.registerOutParameter( 1, Types.INTEGER ); + function.setInt( 2, 1 ); + function.execute(); + phoneCount.set( function.getInt( 1 ) ); + } + } ); + assertEquals( Integer.valueOf( 2 ), phoneCount.get() ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } +} diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/OracleStoredProcedureTest.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/OracleStoredProcedureTest.java new file mode 100644 index 0000000000..b2c2820a4d --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/OracleStoredProcedureTest.java @@ -0,0 +1,353 @@ +package org.hibernate.test.procedure; + +import java.math.BigDecimal; +import java.sql.CallableStatement; +import java.sql.Connection; +import java.sql.ResultSet; +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.List; +import javax.persistence.EntityManager; +import javax.persistence.ParameterMode; +import javax.persistence.StoredProcedureQuery; + +import org.hibernate.Session; +import org.hibernate.dialect.Oracle8iDialect; +import org.hibernate.jdbc.Work; +import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase; +import org.hibernate.procedure.ProcedureCall; +import org.hibernate.result.Output; +import org.hibernate.result.ResultSetOutput; + +import org.hibernate.testing.RequiresDialect; +import org.junit.After; +import org.junit.Before; +import org.junit.Ignore; +import org.junit.Test; + +import static org.junit.Assert.assertEquals; +import static org.junit.Assert.assertNotNull; + +/** + * @author Vlad Mihalcea + */ +@RequiresDialect(Oracle8iDialect.class) +public class OracleStoredProcedureTest extends BaseEntityManagerFunctionalTestCase { + + @Override + protected Class[] getAnnotatedClasses() { + return new Class[] { + Person.class, + Phone.class, + }; + } + + @Before + public void init() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + 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( + "CREATE OR REPLACE PROCEDURE sp_count_phones ( " + + " personId IN NUMBER, " + + " phoneCount OUT NUMBER ) " + + "AS " + + "BEGIN " + + " SELECT COUNT(*) INTO phoneCount " + + " FROM phone " + + " WHERE person_id = personId; " + + "END;" + ); + statement.executeUpdate( + "CREATE OR REPLACE PROCEDURE sp_person_phones ( " + + " personId IN NUMBER, " + + " personPhones OUT SYS_REFCURSOR ) " + + "AS " + + "BEGIN " + + " OPEN personPhones FOR " + + " SELECT *" + + " FROM phone " + + " WHERE person_id = personId; " + + "END;" + ); + statement.executeUpdate( + "CREATE OR REPLACE FUNCTION fn_count_phones ( " + + " personId IN NUMBER ) " + + " RETURN NUMBER " + + "IS " + + " phoneCount NUMBER; " + + "BEGIN " + + " SELECT COUNT(*) INTO phoneCount " + + " FROM phone " + + " WHERE person_id = personId; " + + " RETURN( phoneCount ); " + + "END;" + ); + statement.executeUpdate( + "CREATE OR REPLACE FUNCTION fn_person_and_phones ( " + + " personId IN NUMBER ) " + + " RETURN SYS_REFCURSOR " + + "IS " + + " personAndPhones SYS_REFCURSOR; " + + "BEGIN " + + " OPEN personAndPhones FOR " + + " SELECT " + + " pr.id AS \"pr.id\", " + + " pr.name AS \"pr.name\", " + + " pr.nickName AS \"pr.nickName\", " + + " pr.address AS \"pr.address\", " + + " pr.createdOn AS \"pr.createdOn\", " + + " pr.version AS \"pr.version\", " + + " ph.id AS \"ph.id\", " + + " ph.person_id AS \"ph.person_id\", " + + " ph.phone_number AS \"ph.phone_number\" " + + " FROM person pr " + + " JOIN phone ph ON pr.id = ph.person_id " + + " WHERE pr.id = personId; " + + " RETURN personAndPhones; " + + "END;" + ); + } finally { + if ( statement != null ) { + statement.close(); + } + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + 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.persist(person1); + + Phone phone1 = new Phone( "123-456-7890" ); + phone1.setId( 1L ); + + person1.addPhone( phone1 ); + + Phone phone2 = new Phone( "098_765-4321" ); + phone2.setId( 2L ); + + person1.addPhone( phone2 ); + + entityManager.getTransaction().commit(); + } + finally { + entityManager.close(); + } + } + + @After + public void destroy() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( connection -> { + try(Statement statement = connection.createStatement()) { + statement.executeUpdate("DROP PROCEDURE sp_count_phones"); + } + catch (SQLException ignore) { + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( connection -> { + try(Statement statement = connection.createStatement()) { + statement.executeUpdate("DROP PROCEDURE sp_person_phones"); + } + catch (SQLException ignore) { + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( connection -> { + try(Statement statement = connection.createStatement()) { + statement.executeUpdate("DROP FUNCTION fn_count_phones"); + } + catch (SQLException ignore) { + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testStoredProcedureOutParameter() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_count_phones"); + query.registerStoredProcedureParameter(1, Long.class, ParameterMode.IN); + query.registerStoredProcedureParameter(2, Long.class, ParameterMode.OUT); + + query.setParameter(1, 1L); + + query.execute(); + Long phoneCount = (Long) query.getOutputParameterValue(2); + assertEquals(Long.valueOf(2), phoneCount); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testStoredProcedureRefCursor() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "sp_person_phones" ); + query.registerStoredProcedureParameter( 1, Long.class, ParameterMode.IN ); + query.registerStoredProcedureParameter( 2, Class.class, ParameterMode.REF_CURSOR ); + query.setParameter( 1, 1L ); + + query.execute(); + List postComments = query.getResultList(); + assertNotNull( postComments ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testHibernateProcedureCallRefCursor() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap(Session.class); + + ProcedureCall call = session.createStoredProcedureCall( "sp_person_phones"); + call.registerParameter(1, Long.class, ParameterMode.IN).bindValue(1L); + call.registerParameter(2, Class.class, ParameterMode.REF_CURSOR); + + Output output = call.getOutputs().getCurrent(); + List postComments = ( (ResultSetOutput) output ).getResultList(); + assertEquals(2, postComments.size()); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testStoredProcedureReturnValue() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + BigDecimal phoneCount = (BigDecimal) entityManager + .createNativeQuery("SELECT fn_count_phones(:personId) FROM DUAL") + .setParameter("personId", 1) + .getSingleResult(); + assertEquals(BigDecimal.valueOf(2), phoneCount); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testNamedNativeQueryStoredProcedureRefCursor() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + List postAndComments = entityManager + .createNamedQuery( + "fn_person_and_phones") + .setParameter(1, 1L) + .getResultList(); + Object[] postAndComment = postAndComments.get(0); + Person person = (Person) postAndComment[0]; + Phone phone = (Phone) postAndComment[1]; + assertEquals(2, postAndComments.size()); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testNamedNativeQueryStoredProcedureRefCursorWithJDBC() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + session.doWork( connection -> { + try (CallableStatement function = connection.prepareCall( + "{ ? = call fn_person_and_phones( ? ) }" )) { + function.registerOutParameter( 1, Types.REF_CURSOR ); + function.setInt( 2, 1 ); + function.execute(); + try (ResultSet resultSet = (ResultSet) function.getObject( 1);) { + while (resultSet.next()) { + Long postCommentId = resultSet.getLong(1); + String review = resultSet.getString(2); + } + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } +} diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/Person.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/Person.java new file mode 100644 index 0000000000..ab771f7f12 --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/Person.java @@ -0,0 +1,138 @@ +/* + * 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 . + */ +package org.hibernate.test.procedure; + +import java.util.ArrayList; +import java.util.Date; +import java.util.List; +import javax.persistence.CascadeType; +import javax.persistence.Entity; +import javax.persistence.EntityResult; +import javax.persistence.FieldResult; +import javax.persistence.GeneratedValue; +import javax.persistence.Id; +import javax.persistence.OneToMany; +import javax.persistence.OrderColumn; +import javax.persistence.SqlResultSetMapping; +import javax.persistence.SqlResultSetMappings; +import javax.persistence.Temporal; +import javax.persistence.TemporalType; +import javax.persistence.Version; + +import org.hibernate.annotations.NamedNativeQuery; + +/** + * @author Vlad Mihalcea + */ +@NamedNativeQuery( + name = "fn_person_and_phones", + query = "{ ? = call fn_person_and_phones( ? ) }", + callable = true, + resultSetMapping = "person_with_phones" +) +@SqlResultSetMappings({ + @SqlResultSetMapping( + name = "person_with_phones", + entities = { + @EntityResult( + entityClass = Person.class, + fields = { + @FieldResult( name = "id", column = "pr.id" ), + @FieldResult( name = "name", column = "pr.name" ), + @FieldResult( name = "nickName", column = "pr.nickName" ), + @FieldResult( name = "address", column = "pr.address" ), + @FieldResult( name = "createdOn", column = "pr.createdOn" ), + @FieldResult( name = "version", column = "pr.version" ), + } + ), + @EntityResult( + entityClass = Phone.class, + fields = { + @FieldResult( name = "id", column = "ph.id" ), + @FieldResult( name = "person", column = "ph.person_id" ), + @FieldResult( name = "number", column = "ph.phone_number" ) + } + ) + } + ), +}) +@Entity +public class Person { + + @Id + @GeneratedValue + private Long id; + + private String name; + + private String nickName; + + private String address; + + @Temporal(TemporalType.TIMESTAMP ) + private Date createdOn; + + @OneToMany(mappedBy = "person", cascade = CascadeType.ALL) + @OrderColumn(name = "order_id") + private List phones = new ArrayList<>(); + + @Version + private int version; + + //Getters and setters are omitted for brevity + +//end::hql-examples-domain-model-example[] + + public Person() {} + + public Person(String name) { + this.name = name; + } + + public Long getId() { + return id; + } + + public String getName() { + return name; + } + + public String getNickName() { + return nickName; + } + + public void setNickName(String nickName) { + this.nickName = nickName; + } + + public String getAddress() { + return address; + } + + public void setAddress(String address) { + this.address = address; + } + + public Date getCreatedOn() { + return createdOn; + } + + public void setCreatedOn(Date createdOn) { + this.createdOn = createdOn; + } + + public List getPhones() { + return phones; + } + + public void addPhone(Phone phone) { + phones.add( phone ); + phone.setPerson( this ); + } +//tag::hql-examples-domain-model-example[] +} +//end::hql-examples-domain-model-example[] diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/Phone.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/Phone.java new file mode 100644 index 0000000000..f189d152ad --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/Phone.java @@ -0,0 +1,62 @@ +/* + * 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 . + */ +package org.hibernate.test.procedure; + +import java.util.ArrayList; +import java.util.Date; +import java.util.List; +import javax.persistence.Column; +import javax.persistence.ElementCollection; +import javax.persistence.Entity; +import javax.persistence.FetchType; +import javax.persistence.Id; +import javax.persistence.ManyToOne; + +/** + * @author Vlad Mihalcea + */ +@Entity +public class Phone { + + @Id + private Long id; + + @ManyToOne(fetch = FetchType.LAZY) + private Person person; + + @Column(name = "phone_number") + private String number; + + @ElementCollection + private List repairTimestamps = new ArrayList<>( ); + + public Phone() {} + + public Phone(String number) { + this.number = number; + } + + public Long getId() { + return id; + } + + public void setId(Long id) { + this.id = id; + } + + public String getNumber() { + return number; + } + + public Person getPerson() { + return person; + } + + public void setPerson(Person person) { + this.person = person; + } +} diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/PostgreSQLStoredProcedureTest.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/PostgreSQLStoredProcedureTest.java new file mode 100644 index 0000000000..662cad9623 --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/PostgreSQLStoredProcedureTest.java @@ -0,0 +1,282 @@ +package org.hibernate.test.procedure; + +import java.sql.CallableStatement; +import java.sql.Connection; +import java.sql.SQLException; +import java.sql.SQLFeatureNotSupportedException; +import java.sql.Statement; +import java.sql.Timestamp; +import java.sql.Types; +import java.time.LocalDateTime; +import java.time.ZoneOffset; +import java.util.List; +import javax.persistence.EntityManager; +import javax.persistence.ParameterMode; +import javax.persistence.StoredProcedureQuery; + +import org.hibernate.Session; +import org.hibernate.dialect.PostgreSQL81Dialect; +import org.hibernate.jdbc.ReturningWork; +import org.hibernate.jdbc.Work; +import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase; + +import org.hibernate.testing.RequiresDialect; +import org.junit.Before; +import org.junit.Test; + +import static org.junit.Assert.assertEquals; + +/** + * @author Vlad Mihalcea + */ +@RequiresDialect(PostgreSQL81Dialect.class) +public class PostgreSQLStoredProcedureTest extends BaseEntityManagerFunctionalTestCase { + + @Override + protected Class[] getAnnotatedClasses() { + return new Class[] { + Person.class, + Phone.class, + }; + } + + @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 FUNCTION sp_count_phones(bigint)" ); + } + catch (SQLException ignore) { + } + finally { + if ( statement != null ) { + statement.close(); + } + } + } + } ); + + 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_phones(bigint)" ); + } + catch (SQLException ignore) { + } + finally { + if ( statement != null ) { + statement.close(); + } + } + } + } ); + + 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( + "CREATE OR REPLACE FUNCTION sp_count_phones( " + + " IN personId bigint, " + + " OUT phoneCount bigint) " + + " RETURNS bigint AS " + + "$BODY$ " + + " BEGIN " + + " SELECT COUNT(*) INTO phoneCount " + + " FROM phone " + + " WHERE person_id = personId; " + + " END; " + + "$BODY$ " + + "LANGUAGE plpgsql;" + ); + + statement.executeUpdate( + "CREATE OR REPLACE FUNCTION fn_phones(personId BIGINT) " + + " RETURNS REFCURSOR AS " + + "$BODY$ " + + " DECLARE " + + " phones REFCURSOR; " + + " BEGIN " + + " OPEN phones FOR " + + " SELECT * " + + " FROM phone " + + " WHERE person_id = personId; " + + " RETURN phones; " + + " END; " + + "$BODY$ " + + "LANGUAGE plpgsql" + ); + } + finally { + if ( statement != null ) { + statement.close(); + } + } + } + } ); + + entityManager.getTransaction().commit(); + entityManager.close(); + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + 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.persist( person1 ); + + Phone phone1 = new Phone( "123-456-7890" ); + phone1.setId( 1L ); + + person1.addPhone( phone1 ); + + Phone phone2 = new Phone( "098_765-4321" ); + phone2.setId( 2L ); + + person1.addPhone( phone2 ); + + entityManager.getTransaction().commit(); + entityManager.close(); + } + + @Test + public void testStoredProcedureOutParameter() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "sp_count_phones" ); + query.registerStoredProcedureParameter( "personId", Long.class, ParameterMode.IN ); + query.registerStoredProcedureParameter( "phoneCount", Long.class, ParameterMode.OUT ); + + query.setParameter( "personId", 1L ); + + 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(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "fn_phones" ); + query.registerStoredProcedureParameter( 1, void.class, ParameterMode.REF_CURSOR ); + query.registerStoredProcedureParameter( 2, Long.class, ParameterMode.IN ); + + query.setParameter( 2, 1L ); + + List phones = query.getResultList(); + assertEquals( 2, phones.size() ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testFunctionWithJDBC() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + Long phoneCount = session.doReturningWork( new ReturningWork() { + @Override + public Long execute(Connection connection) throws SQLException { + CallableStatement function = null; + try { + function = connection.prepareCall( "{ ? = call sp_count_phones(?) }" ); + function.registerOutParameter( 1, Types.BIGINT ); + function.setLong( 2, 1L ); + function.execute(); + return function.getLong( 1 ); + } + finally { + if ( function != null ) { + function.close(); + } + } + } + } ); + assertEquals( Long.valueOf( 2 ), phoneCount ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } + + @Test + public void testFunctionWithJDBCByName() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + Session session = entityManager.unwrap( Session.class ); + Long phoneCount = session.doReturningWork( new ReturningWork() { + @Override + public Long execute(Connection connection) throws SQLException { + CallableStatement function = null; + try { + function = connection.prepareCall( "{ ? = call sp_count_phones(?) }" ); + function.registerOutParameter( "phoneCount", Types.BIGINT ); + function.setLong( "personId", 1L ); + function.execute(); + return function.getLong( 1 ); + } + finally { + if ( function != null ) { + function.close(); + } + } + } + } ); + assertEquals( Long.valueOf( 2 ), phoneCount ); + } catch (Exception e) { + assertEquals( SQLFeatureNotSupportedException.class, e.getCause().getClass() ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } +} diff --git a/hibernate-core/src/test/java/org/hibernate/test/procedure/SQLServerStoredProcedureTest.java b/hibernate-core/src/test/java/org/hibernate/test/procedure/SQLServerStoredProcedureTest.java new file mode 100644 index 0000000000..0804d918bf --- /dev/null +++ b/hibernate-core/src/test/java/org/hibernate/test/procedure/SQLServerStoredProcedureTest.java @@ -0,0 +1,283 @@ +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.List; +import java.util.regex.Pattern; +import javax.persistence.EntityManager; +import javax.persistence.ParameterMode; +import javax.persistence.StoredProcedureQuery; + +import org.hibernate.Session; +import org.hibernate.dialect.SQLServer2012Dialect; +import org.hibernate.jdbc.Work; +import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase; + +import org.hibernate.testing.RequiresDialect; +import org.junit.Before; +import org.junit.Test; + +import static org.junit.Assert.assertEquals; +import static org.junit.Assert.assertNotNull; +import static org.junit.Assert.assertTrue; + +/** + * @author Vlad Mihalcea + */ +@RequiresDialect(SQLServer2012Dialect.class) +public class SQLServerStoredProcedureTest extends BaseEntityManagerFunctionalTestCase { + + @Override + protected Class[] getAnnotatedClasses() { + return new Class[] { + Person.class, + Phone.class, + }; + } + + @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(); + } + } + } + } ); + + 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(); + } + } + } + } ); + + 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(); + } + } + } + } ); + + 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( + "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(); + } + } + } + } ); + + entityManager.getTransaction().commit(); + entityManager.close(); + + entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + 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.persist( person1 ); + + Phone phone1 = new Phone( "123-456-7890" ); + phone1.setId( 1L ); + + person1.addPhone( phone1 ); + + Phone phone2 = new Phone( "098_765-4321" ); + phone2.setId( 2L ); + + person1.addPhone( phone2 ); + + entityManager.getTransaction().commit(); + entityManager.close(); + } + + @Test + public void testStoredProcedureOutParameter() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + StoredProcedureQuery query = entityManager.createStoredProcedureQuery("sp_count_phones"); + query.registerStoredProcedureParameter("personId", Long.class, ParameterMode.IN); + query.registerStoredProcedureParameter("phoneCount", Long.class, ParameterMode.OUT); + + query.setParameter("personId", 1L); + + 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(); + + 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 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(); + } + } + + @Test + public void testStoredProcedureReturnValue() { + EntityManager entityManager = createEntityManager(); + entityManager.getTransaction().begin(); + + try { + 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(); + } + } + } + } ); + } + finally { + entityManager.getTransaction().rollback(); + entityManager.close(); + } + } +}