Update stored procedures User Guide chapter

This commit is contained in:
Vlad Mihalcea 2016-02-16 17:58:33 +02:00
parent 0fccf6b7bd
commit af083e92ce
3 changed files with 556 additions and 58 deletions

View File

@ -641,82 +641,146 @@ include::{sourcedir}/SQLTest.java[tags=sql-hibernate-composite-key-entity-associ
----
====
[[sp_query]]
[[sql-sp]]
=== Using stored procedures for querying
Hibernate provides support for queries via stored procedures and functions.
Most of the following documentation is equivalent for both.
The stored procedure/function must return a resultset as the first out-parameter to be able to work with Hibernate.
An example of such a stored function in Oracle 9 and higher is as follows:
A stored procedure arguments are declared using the `IN` parameter type, and the result can be either marked with an `OUT`
parameter type, a `REF_CURSOR` or it could just return the result like a function.
[source,xml]
[[sql-sp-out-mysql-example]]
.MySQL stored procedure with `OUT` parameter type
====
[source, JAVA, indent=0]
----
CREATE OR REPLACE FUNCTION selectAllEmployments
RETURN SYS_REFCURSOR
AS
st_cursor SYS_REFCURSOR;
BEGIN
OPEN st_cursor FOR
SELECT EMPLOYEE, EMPLOYER,
STARTDATE, ENDDATE,
REGIONCODE, EID, VALUE, CURRENCY
FROM EMPLOYMENT;
RETURN st_cursor;
END;
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-sp-out-mysql-example]
----
====
To use this query in Hibernate you need to map it via a named query.
To use this stored procedure, you can execute the following JPA 2.1 query:
[source,xml]
[[sql-jpa-call-sp-out-mysql-example]]
.Calling a MySQL stored procedure with `OUT` parameter type using JPA
====
[source, JAVA, indent=0]
----
<sql-query name = "selectAllEmployees_SP" callable = "true">
<return alias="emp" class="Employment">
<return-property name = "employee" column = "EMPLOYEE"/>
<return-property name = "employer" column = "EMPLOYER"/>
<return-property name = "startDate" column = "STARTDATE"/>
<return-property name = "endDate" column = "ENDDATE"/>
<return-property name = "regionCode" column = "REGIONCODE"/>
<return-property name = "id" column = "EID"/>
<return-property name = "salary">
<return-column name = "VALUE"/>
<return-column name = "CURRENCY"/>
</return-property>
</return>
{ ? = call selectAllEmployments() }
</sql-query>
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-jpa-call-sp-out-mysql-example]
----
====
Stored procedures currently only return scalars and entities.
`<return-join>` and `<load-collection>` are not supported.
[[sql-hibernate-call-sp-out-mysql-example]]
.Calling a MySQL stored procedure with `OUT` parameter type using Hibernate
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-hibernate-call-sp-out-mysql-example]
----
====
[[sql-limits-storedprocedures]]
=== Rules/limitations for using stored procedures
If the stored procedure outputs the result directly without an `OUT` parameter type:
You cannot use stored procedures with Hibernate unless you follow some procedure/function rules.
If they do not follow those rules they are not usable with Hibernate.
If you still want to use these procedures you have to execute them via `session.doWork()`.
[[sql-sp-mysql-return-no-out-example]]
.MySQL stored procedure without an `OUT` parameter type
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-sp-no-out-mysql-example]
----
====
The rules are different for each database, since database vendors have different stored procedure semantics/syntax.
You can retrieve the results of the aforementioned MySQL stored procedure as follows:
[[sql-jpa-call-sp-no-out-mysql-example]]
.Calling a MySQL stored procedure and fetching the result set without an `OUT` parameter type using JPA
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-jpa-call-sp-no-out-mysql-example]
----
====
[[sql-hibernate-call-sp-no-out-mysql-example]]
.Calling a MySQL stored procedure and fetching the result set without an `OUT` parameter type using Hibernate
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-hibernate-call-sp-no-out-mysql-example]
----
====
For a `REF_CURSOR` result sets, we'll consider the following Oracle stored procedure:
[[sql-sp-ref-cursor-oracle-example]]
.Oracle `REF_CURSOR` stored procedure
====
[source, JAVA, indent=0]
----
include::{sourcedir}/OracleStoredProcedureTest.java[tags=sql-sp-ref-cursor-oracle-example]
----
====
[IMPORTANT]
====
`REF_CURSOR` result sets are only supported by Oracle and PostgreSQL because other database systems JDBC drivers don't support this feature.
====
This function can be called using the standard Java Persistence API:
[[sql-jpa-call-sp-ref-cursor-oracle-example]]
.Calling an Oracle `REF_CURSOR` stored procedure using JPA
====
[source, JAVA, indent=0]
----
include::{sourcedir}/OracleStoredProcedureTest.java[tags=sql-jpa-call-sp-ref-cursor-oracle-example]
----
====
[[sql-hibernate-call-sp-ref-cursor-oracle-example]]
.Calling an Oracle `REF_CURSOR` stored procedure using Hibernate
====
[source, JAVA, indent=0]
----
include::{sourcedir}/OracleStoredProcedureTest.java[tags=sql-hibernate-call-sp-ref-cursor-oracle-example]
----
====
If the database defines an SQL function:
[[sql-function-mysql-example]]
.MySQL function
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-function-mysql-example]
----
====
Because the current `StoredProcedureQuery` implementation doesn't yet support SQL functions,
we need to use the JDBC syntax.
[NOTE]
====
This limitation is acknowledged and it will be addressed by the https://hibernate.atlassian.net/browse/HHH-10530[HHH-10530] issue.
====
[[sql-call-function-mysql-example]]
.Calling a MySQL function
====
[source, JAVA, indent=0]
----
include::{sourcedir}/MySQLStoredProcedureTest.java[tags=sql-call-function-mysql-example]
----
====
[NOTE]
====
Stored procedure queries cannot be paged with `setFirstResult()/setMaxResults()`.
The recommended call form is standard SQL92: `{ ? = call functionName(<parameters>) }` or `{ ? = call procedureName(<parameters>}`.
Native call syntax is not supported.
Since these servers can return multiple result sets and update counts,
Hibernate will iterate the results and take the first result that is a result set as its return value, so everything else will be discarded.
For Oracle the following rules apply:
* A function must return a result set.
The first parameter of a procedure must be an `OUT` that returns a result set.
This is done by using a `SYS_REFCURSOR` type in Oracle 9 or 10.
In Oracle you need to define a `REF CURSOR` type.
See Oracle literature for further information.
For Sybase or MS SQL server the following rules apply:
* The procedure must return a result set.
Note that since these servers can return multiple result sets and update counts, Hibernate will iterate the results and take the first result that is a result set as its return value.
Everything else will be discarded.
* If you can enable `SET NOCOUNT ON` in your procedure it will probably be more efficient, but this is not a requirement.
For SQL Server, if you can enable `SET NOCOUNT ON` in your procedure it will probably be more efficient, but this is not a requirement.
====
[[sql-cud]]
=== Custom SQL for create, update and delete

View File

@ -0,0 +1,256 @@
package org.hibernate.userguide.sql;
import java.sql.CallableStatement;
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.ParameterMode;
import javax.persistence.StoredProcedureQuery;
import org.hibernate.Session;
import org.hibernate.dialect.MySQL5Dialect;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.procedure.ProcedureCall;
import org.hibernate.result.Output;
import org.hibernate.result.ResultSetOutput;
import org.hibernate.userguide.model.AddressType;
import org.hibernate.userguide.model.Call;
import org.hibernate.userguide.model.Partner;
import org.hibernate.userguide.model.Person;
import org.hibernate.userguide.model.Phone;
import org.hibernate.userguide.model.PhoneType;
import org.hibernate.testing.RequiresDialect;
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.userguide.util.TransactionUtil.doInJPA;
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,
Partner.class,
Phone.class,
Call.class,
};
}
@Before
public void init() {
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate("DROP PROCEDURE IF EXISTS count_phones");
}
catch (SQLException ignore) {
}
} );
});
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate("DROP PROCEDURE IF EXISTS person_phones");
}
catch (SQLException ignore) {
}
} );
});
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate("DROP FUNCTION IF EXISTS fn_count_comments");
}
catch (SQLException ignore) {
}
} );
});
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try(Statement statement = connection.createStatement()) {
//tag::sql-sp-out-mysql-example[]
statement.executeUpdate(
"CREATE PROCEDURE count_phones (" +
" IN personId INT, " +
" OUT phoneCount INT " +
") " +
"BEGIN " +
" SELECT COUNT(*) INTO phoneCount " +
" FROM person_phone " +
" WHERE person_phone.person_id = personId; " +
"END"
);
//end::sql-sp-out-mysql-example[]
//tag::sql-sp-no-out-mysql-example[]
statement.executeUpdate(
"CREATE PROCEDURE person_phones(IN personId INT) " +
"BEGIN " +
" SELECT * " +
" FROM person_phone " +
" WHERE person_id = personId; " +
"END"
);
//end::sql-sp-no-out-mysql-example[]
//tag::sql-function-mysql-example[]
statement.executeUpdate(
"CREATE FUNCTION fn_count_comments(postId integer) " +
"RETURNS integer " +
"DETERMINISTIC " +
"READS SQL DATA " +
"BEGIN " +
" DECLARE commentCount integer; " +
" SELECT COUNT(*) INTO commentCount " +
" FROM post_comment " +
" WHERE post_comment.post_id = postId; " +
" RETURN commentCount; " +
"END"
);
//end::sql-function-mysql-example[]
}
} );
});
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 ) )) ;
person1.getAddresses().put( AddressType.HOME, "Home address" );
person1.getAddresses().put( AddressType.OFFICE, "Office address" );
entityManager.persist(person1);
Phone phone1 = new Phone( "123-456-7890" );
phone1.setId( 1L );
phone1.setType( PhoneType.MOBILE );
person1.addPhone( phone1 );
Phone phone2 = new Phone( "098_765-4321" );
phone2.setId( 2L );
phone2.setType( PhoneType.LAND_LINE );
person1.addPhone( phone2 );
});
}
@Test
public void testStoredProcedureOutParameter() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-jpa-call-sp-out-mysql-example[]
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "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");
//end::sql-jpa-call-sp-out-mysql-example[]
assertEquals(Long.valueOf(2), phoneCount);
});
}
@Test
public void testHibernateProcedureCallOutParameter() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-hibernate-call-sp-out-mysql-example[]
Session session = entityManager.unwrap( Session.class );
ProcedureCall call = session.createStoredProcedureCall( "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 );
//end::sql-hibernate-call-sp-out-mysql-example[]
});
}
@Test
public void testStoredProcedureRefCursor() {
try {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "person_phones");
query.registerStoredProcedureParameter( 1, void.class, ParameterMode.REF_CURSOR);
query.registerStoredProcedureParameter( 2, Long.class, ParameterMode.IN);
query.setParameter(2, 1L);
List<Object[]> 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());
}
}
@Test
public void testStoredProcedureReturnValue() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-jpa-call-sp-no-out-mysql-example[]
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "person_phones");
query.registerStoredProcedureParameter( 1, Long.class, ParameterMode.IN);
query.setParameter(1, 1L);
List<Object[]> personComments = query.getResultList();
//end::sql-jpa-call-sp-no-out-mysql-example[]
assertEquals(2, personComments.size());
});
}
@Test
public void testHibernateProcedureCallReturnValueParameter() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-hibernate-call-sp-no-out-mysql-example[]
Session session = entityManager.unwrap( Session.class );
ProcedureCall call = session.createStoredProcedureCall( "post_comments" );
call.registerParameter( 1, Long.class, ParameterMode.IN ).bindValue( 1L );
Output output = call.getOutputs().getCurrent();
List<Object[]> personComments = ( (ResultSetOutput) output ).getResultList();
//end::sql-hibernate-call-sp-no-out-mysql-example[]
assertEquals( 2, personComments.size() );
});
}
@Test
public void testFunctionWithJDBC() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-call-function-mysql-example[]
final AtomicReference<Integer> commentCount = new AtomicReference<>();
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try (CallableStatement function = connection.prepareCall(
"{ ? = call fn_count_comments(?) }" )) {
function.registerOutParameter( 1, Types.INTEGER );
function.setInt( 2, 1 );
function.execute();
commentCount.set( function.getInt( 1 ) );
}
} );
//end::sql-call-function-mysql-example[]
assertEquals(Integer.valueOf(2), commentCount.get());
});
}
}

View File

@ -0,0 +1,178 @@
package org.hibernate.userguide.sql;
import java.math.BigDecimal;
import java.sql.Statement;
import java.sql.Timestamp;
import java.time.LocalDateTime;
import java.time.ZoneOffset;
import java.util.List;
import javax.persistence.ParameterMode;
import javax.persistence.StoredProcedureQuery;
import org.hibernate.Session;
import org.hibernate.dialect.Oracle8iDialect;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.procedure.ProcedureCall;
import org.hibernate.result.Output;
import org.hibernate.result.ResultSetOutput;
import org.hibernate.userguide.model.AddressType;
import org.hibernate.userguide.model.Call;
import org.hibernate.userguide.model.Partner;
import org.hibernate.userguide.model.Person;
import org.hibernate.userguide.model.Phone;
import org.hibernate.userguide.model.PhoneType;
import org.hibernate.testing.RequiresDialect;
import org.junit.Before;
import org.junit.Test;
import static org.hibernate.userguide.util.TransactionUtil.doInJPA;
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,
Partner.class,
Phone.class,
Call.class,
};
}
@Before
public void init() {
doInJPA( this::entityManagerFactory, entityManager -> {
Session session = entityManager.unwrap( Session.class );
session.doWork( connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate(
"CREATE OR REPLACE PROCEDURE count_phones ( " +
" personId IN NUMBER, " +
" phoneCount OUT NUMBER ) " +
"AS " +
"BEGIN " +
" SELECT COUNT(*) INTO phoneCount " +
" FROM person_phone " +
" WHERE person_id = personId; " +
"END;"
);
//tag::sql-sp-ref-cursor-oracle-example[]
statement.executeUpdate(
"CREATE OR REPLACE PROCEDURE person_phones ( " +
" personId IN NUMBER, " +
" personPhones OUT SYS_REFCURSOR ) " +
"AS " +
"BEGIN " +
" OPEN personPhones FOR " +
" SELECT *" +
" FROM person_phone " +
" WHERE person_id = personId; " +
"END;"
);
//end::sql-sp-ref-cursor-oracle-example[]
statement.executeUpdate(
"CREATE OR REPLACE FUNCTION fn_count_phones ( " +
" personId IN NUMBER ) " +
" RETURN NUMBER " +
"IS " +
" phoneCount NUMBER; " +
"BEGIN " +
" SELECT COUNT(*) INTO phoneCount " +
" FROM person_phone " +
" WHERE person_id = personId; " +
" RETURN( phoneCount ); " +
"END;"
);
}
} );
});
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 ) )) ;
person1.getAddresses().put( AddressType.HOME, "Home address" );
person1.getAddresses().put( AddressType.OFFICE, "Office address" );
entityManager.persist(person1);
Phone phone1 = new Phone( "123-456-7890" );
phone1.setId( 1L );
phone1.setType( PhoneType.MOBILE );
person1.addPhone( phone1 );
Phone phone2 = new Phone( "098_765-4321" );
phone2.setId( 2L );
phone2.setType( PhoneType.LAND_LINE );
person1.addPhone( phone2 );
});
}
@Test
public void testStoredProcedureOutParameter() {
doInJPA( this::entityManagerFactory, entityManager -> {
StoredProcedureQuery query = entityManager.createStoredProcedureQuery("count_phones");
query.registerStoredProcedureParameter("personId", Long.class, ParameterMode.IN);
query.registerStoredProcedureParameter("phoneCount", Long.class, ParameterMode.OUT);
query.setParameter("person_id", 1L);
query.execute();
Long phoneCount = (Long) query.getOutputParameterValue("phoneCount");
assertEquals(Long.valueOf(2), phoneCount);
});
}
@Test
public void testStoredProcedureRefCursor() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-jpa-call-sp-ref-cursor-oracle-example[]
StoredProcedureQuery query = entityManager.createStoredProcedureQuery( "personPhones" );
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();
//end::sql-jpa-call-sp-ref-cursor-oracle-example[]
assertNotNull( postComments );
});
}
@Test
public void testHibernateProcedureCallRefCursor() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::sql-hibernate-call-sp-ref-cursor-oracle-example[]
Session session = entityManager.unwrap(Session.class);
ProcedureCall call = session.createStoredProcedureCall( "personPhones");
call.registerParameter(1, Long.class, ParameterMode.IN).bindValue(1L);
call.registerParameter(2, Class.class, ParameterMode.REF_CURSOR);
Output output = call.getOutputs().getCurrent();
List<Object[]> postComments = ( (ResultSetOutput) output ).getResultList();
assertEquals(2, postComments.size());
//end::sql-hibernate-call-sp-ref-cursor-oracle-example[]
});
}
@Test
public void testStoredProcedureReturnValue() {
doInJPA( this::entityManagerFactory, entityManager -> {
BigDecimal phoneCount = (BigDecimal) entityManager
.createNativeQuery("SELECT fn_count_phones(:personId) FROM DUAL")
.setParameter("personId", 1L)
.getSingleResult();
assertEquals(BigDecimal.valueOf(2), phoneCount);
});
}
}