HHH-12957 - Calling custom functions in JPQL with the function() is missing in the documentation

This commit is contained in:
Vlad Mihalcea 2018-09-05 17:35:42 +03:00
parent 9d8cb3dbb7
commit 4bafeeecae
3 changed files with 426 additions and 4 deletions

View File

@ -1341,8 +1341,8 @@ include::{sourcedir}/HQLTest.java[tags=hql-str-function-example]
----
====
[[hql-non-standard-functions]]
=== Non-standardized functions
[[hql-user-defined-functions]]
=== User-defined functions
Hibernate Dialects can register additional functions known to be available for that particular database product.
These functions are also available in HQL (and JPQL, though only when using Hibernate as the JPA provider obviously).
@ -1350,8 +1350,84 @@ However, they would only be available when using that database Dialect.
Applications that aim for database portability should avoid using functions in this category.
Application developers can also supply their own set of functions.
This would usually represent either custom SQL functions or aliases for snippets of SQL.
Such function declarations are made by using the `addSqlFunction()` method of `org.hibernate.cfg.Configuration`.
This would usually represent either user-defined SQL functions or aliases for snippets of SQL.
Such function declarations are made by using the `addSqlFunction()` method of
the `org.hibernate.boot.MetadataBuilder` or the legacy `org.hibernate.cfg.Configuration`.
Now, let's assume we have the following `apply_vat` PostgreSQL user-defined function:
[[hql-user-defined-function-postgresql-example]]
.PostgreSQL user-defined function
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionWhereClauseTest.java[tags=hql-user-defined-function-postgresql-example]
----
====
Let's consider we have persisted the following entity in our database:
[[hql-user-defined-function-postgresql-entity-example]]
.Book entity
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionWhereClauseTest.java[tags=hql-user-defined-function-postgresql-entity-example]
----
====
[[hql-user-defined-functions-where-clause]]
==== User-defined functions referenced in the WHERE clause
By default, Hibernate can pass through any user-defined function that's being used in the WHERE clause
of a JPQL/HQL entity query.
[[hql-user-defined-function-postgresql-where-clause-example]]
.User-defined function passing through the WHERE clause
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionWhereClauseTest.java[tags=hql-user-defined-function-postgresql-where-clause-example]
----
====
While this works just fine with Hibernate, it might be a problem with other JPA providers.
For this purpose, JPA offers the `function` JPQL keyword which works as follows.
[[hql-user-defined-function-postgresql-jpql-example]]
.Using the JPQL `function` keyword
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionWhereClauseTest.java[tags=hql-user-defined-function-postgresql-jpql-example]
----
====
[[hql-user-defined-functions-select-clause]]
==== User-defined functions referenced in the SELECT clause
When the user-defined function is referenced in the SELECT clause of a JPQL/HQL entity query,
Hibernate can no longer pass it through unless the function is registered.
[[hql-user-defined-functions-register-metadata-builder-example]]
.Registering a user-defined function using the `MetadataBuilderContributor`
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionSelectClauseTest.java[tags=hql-user-defined-functions-register-metadata-builder-example]
----
====
Now that that `apply_vat` is registered, we can reference it in the JPQL SELECT clause.
[[hql-user-defined-function-postgresql-select-clause-example]]
.User-defined function in the SELECT clause
====
[source, JAVA, indent=0]
----
include::{sourcedir}/PostgreSQLFunctionSelectClauseTest.java[tags=hql-user-defined-function-postgresql-select-clause-example]
----
====
[[hql-collection-expressions]]
=== Collection-related expressions

View File

@ -0,0 +1,172 @@
/*
* 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.userguide.hql;
import java.sql.Statement;
import java.util.List;
import java.util.Map;
import javax.persistence.Entity;
import javax.persistence.Id;
import javax.persistence.Tuple;
import org.hibernate.Session;
import org.hibernate.boot.MetadataBuilder;
import org.hibernate.boot.spi.MetadataBuilderContributor;
import org.hibernate.dialect.PostgreSQL82Dialect;
import org.hibernate.dialect.function.StandardSQLFunction;
import org.hibernate.jpa.boot.internal.EntityManagerFactoryBuilderImpl;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.type.StandardBasicTypes;
import org.hibernate.testing.RequiresDialect;
import org.junit.After;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
import static org.junit.Assert.assertTrue;
/**
* @author Vlad Mihalcea
*/
@RequiresDialect(PostgreSQL82Dialect.class)
public class PostgreSQLFunctionSelectClauseTest extends BaseEntityManagerFunctionalTestCase {
@Override
protected Class<?>[] getAnnotatedClasses() {
return new Class<?>[] {
Book.class
};
}
@Override
protected void addMappings(Map settings) {
//tag::hql-user-defined-functions-register-metadata-builder-example[]
settings.put( "hibernate.metadata_builder_contributor",
(MetadataBuilderContributor) metadataBuilder ->
metadataBuilder.applySqlFunction(
"apply_vat",
new StandardSQLFunction(
"apply_vat",
StandardBasicTypes.INTEGER
)
)
);
//end::hql-user-defined-functions-register-metadata-builder-example[]
}
@Override
protected void afterEntityManagerFactoryBuilt() {
doInJPA( this::entityManagerFactory, entityManager -> {
entityManager.unwrap( Session.class ).doWork(
connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate(
"CREATE OR REPLACE FUNCTION apply_vat(integer) RETURNS integer " +
" AS 'select cast(($1 * 1.2) as integer);' " +
" LANGUAGE SQL " +
" IMMUTABLE " +
" RETURNS NULL ON NULL INPUT;"
);
}
}
);
});
doInJPA( this::entityManagerFactory, entityManager -> {
Book book = new Book();
book.setIsbn( "978-9730228236" );
book.setTitle( "High-Performance Java Persistence" );
book.setAuthor( "Vlad Mihalcea" );
book.setPriceCents( 4500 );
entityManager.persist( book );
});
}
@After
public void destroy() {
doInJPA( this::entityManagerFactory, entityManager -> {
entityManager.unwrap( Session.class ).doWork(
connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate(
"DROP FUNCTION apply_vat(integer)"
);
}
}
);
});
}
@Test
public void testHibernateSelectClauseFunction() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::hql-user-defined-function-postgresql-select-clause-example[]
List<Tuple> books = entityManager.createQuery(
"select b.title as title, apply_vat(b.priceCents) as price " +
"from Book b " +
"where b.author = :author ", Tuple.class )
.setParameter( "author", "Vlad Mihalcea" )
.getResultList();
assertEquals( 1, books.size() );
Tuple book = books.get( 0 );
assertEquals( "High-Performance Java Persistence", book.get( "title" ) );
assertEquals( 5400, ((Number) book.get( "price" )).intValue() );
//end::hql-user-defined-function-postgresql-select-clause-example[]
});
}
@Entity(name = "Book")
public static class Book {
@Id
private String isbn;
private String title;
private String author;
private Integer priceCents;
public String getIsbn() {
return isbn;
}
public void setIsbn(String isbn) {
this.isbn = isbn;
}
public String getTitle() {
return title;
}
public void setTitle(String title) {
this.title = title;
}
public String getAuthor() {
return author;
}
public void setAuthor(String author) {
this.author = author;
}
public Integer getPriceCents() {
return priceCents;
}
public void setPriceCents(Integer priceCents) {
this.priceCents = priceCents;
}
}
}

View File

@ -0,0 +1,174 @@
/*
* 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.userguide.hql;
import java.sql.Statement;
import java.util.List;
import javax.persistence.Entity;
import javax.persistence.Id;
import org.hibernate.Session;
import org.hibernate.dialect.PostgreSQL82Dialect;
import org.hibernate.jpa.test.BaseEntityManagerFunctionalTestCase;
import org.hibernate.testing.RequiresDialect;
import org.junit.After;
import org.junit.Test;
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
import static org.junit.Assert.assertEquals;
import static org.junit.Assert.assertTrue;
/**
* @author Vlad Mihalcea
*/
@RequiresDialect(PostgreSQL82Dialect.class)
public class PostgreSQLFunctionWhereClauseTest extends BaseEntityManagerFunctionalTestCase {
@Override
protected Class<?>[] getAnnotatedClasses() {
return new Class<?>[] {
Book.class
};
}
@Override
protected void afterEntityManagerFactoryBuilt() {
doInJPA( this::entityManagerFactory, entityManager -> {
entityManager.unwrap( Session.class ).doWork(
connection -> {
try(Statement statement = connection.createStatement()) {
//tag::hql-user-defined-function-postgresql-example[]
statement.executeUpdate(
"CREATE OR REPLACE FUNCTION apply_vat(integer) RETURNS integer " +
" AS 'select cast(($1 * 1.2) as integer);' " +
" LANGUAGE SQL " +
" IMMUTABLE " +
" RETURNS NULL ON NULL INPUT;"
);
//end::hql-user-defined-function-postgresql-example[]
}
}
);
});
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::hql-user-defined-function-postgresql-entity-example[]
Book book = new Book();
book.setIsbn( "978-9730228236" );
book.setTitle( "High-Performance Java Persistence" );
book.setAuthor( "Vlad Mihalcea" );
book.setPriceCents( 4500 );
entityManager.persist( book );
//end::hql-user-defined-function-postgresql-entity-example[]
});
}
@After
public void destroy() {
doInJPA( this::entityManagerFactory, entityManager -> {
entityManager.unwrap( Session.class ).doWork(
connection -> {
try(Statement statement = connection.createStatement()) {
statement.executeUpdate(
"DROP FUNCTION apply_vat(integer)"
);
}
}
);
});
}
@Test
public void testHibernatePassThroughFunction() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::hql-user-defined-function-postgresql-where-clause-example[]
List<Book> books = entityManager.createQuery(
"select b " +
"from Book b " +
"where apply_vat(b.priceCents) = :price ", Book.class )
.setParameter( "price", 5400 )
.getResultList();
assertTrue( books
.stream()
.filter( book -> "High-Performance Java Persistence".equals( book.getTitle() ) )
.findAny()
.isPresent()
);
//end::hql-user-defined-function-postgresql-where-clause-example[]
});
}
@Test
public void testCustomFunction() {
doInJPA( this::entityManagerFactory, entityManager -> {
//tag::hql-user-defined-function-postgresql-jpql-example[]
List<Book> books = entityManager.createQuery(
"select b " +
"from Book b " +
"where function('apply_vat', b.priceCents) = :price ", Book.class )
.setParameter( "price", 5400 )
.getResultList();
assertTrue( books
.stream()
.filter( book -> "High-Performance Java Persistence".equals( book.getTitle() ) )
.findAny()
.isPresent()
);
//end::hql-user-defined-function-postgresql-jpql-example[]
});
}
@Entity(name = "Book")
public static class Book {
@Id
private String isbn;
private String title;
private String author;
private Integer priceCents;
public String getIsbn() {
return isbn;
}
public void setIsbn(String isbn) {
this.isbn = isbn;
}
public String getTitle() {
return title;
}
public void setTitle(String title) {
this.title = title;
}
public String getAuthor() {
return author;
}
public void setAuthor(String author) {
this.author = author;
}
public Integer getPriceCents() {
return priceCents;
}
public void setPriceCents(Integer priceCents) {
this.priceCents = priceCents;
}
}
}