Skip to content

Commit d75f960

Browse files
committed
HHH-16648
1 parent 6d0c166 commit d75f960

File tree

6 files changed

+469
-9
lines changed

6 files changed

+469
-9
lines changed

documentation/src/main/asciidoc/userguide/chapters/query/hql/QueryLanguage.adoc

+129-9
Original file line numberDiff line numberDiff line change
@@ -1117,16 +1117,9 @@ There are several ways to call native or user-defined SQL functions.
11171117
- A native or user-defined function may be called using JPQL's `function` syntax, for example, ``function('sinh', phi)``.
11181118
(This is the easiest way, but not the best way.)
11191119
- A user-written `FunctionContributor` may register user-defined functions.
1120-
- A custom `Dialect` may register additional native functions by overriding `initializeFunctionRegistry()`.
1120+
- A custom `Dialect` may register additional native functions by overriding `initializeFunctionRegistry()`. <<hql-user-defined-functions-implementation, Example of implementation.>>
11211121
1122-
[TIP]
1123-
====
1124-
Registering a function isn't hard, but is beyond the scope of this chapter.
1125-
1126-
(It's even possible to use the APIs Hibernate provides to make your own _portable_ functions!)
1127-
====
1128-
1129-
Fortunately, every built-in `Dialect` already registers many native functions for the database it supports.
1122+
Fortunately, every built-in `Dialect` already registers many native functions for the database it supports. So there is no need to define this functions explicitly.
11301123
11311124
[TIP]
11321125
====
@@ -2632,3 +2625,130 @@ Hibernate does emulate the `search` and `cycle` clauses though if necessary, so
26322625

26332626
Note that most modern database versions support recursive CTEs already.
26342627
====
2628+
2629+
[[hql-user-defined-functions-implementation]]
2630+
=== User-defined functions implementation
2631+
2632+
Hibernate Dialects can register additional functions known to be available for that particular database product.
2633+
These functions are also available in HQL (and JPQL, though only when using Hibernate as the JPA provider, obviously).
2634+
However, they would only be available when using that database Dialect.
2635+
Applications that aim for database portability should avoid using functions in this category.
2636+
2637+
Application developers can also supply their own set of functions.
2638+
This would usually represent either user-defined SQL functions or aliases for snippets of SQL.
2639+
2640+
Such function can be declared by using the `register()` method of `org.hibernate.query.sqm.function.SqmFunctionRegistry`.
2641+
2642+
For example, we have the following SQL function:
2643+
2644+
[[hql-user-defined-function-example]]
2645+
.Custom aggregate function
2646+
====
2647+
[source, SQL, indent=0]
2648+
----
2649+
include::{extrasdir}/hql-user-defined-function-example.sql[]
2650+
----
2651+
====
2652+
2653+
Also, we have the `Employee` entity.
2654+
2655+
[[hql-user-defined-function-domain-model]]
2656+
.Domain model
2657+
====
2658+
[source, JAVA, indent=0]
2659+
----
2660+
include::{example-dir-hql}/customFunctions/Employee.java[tags=hql-examples-domain-model-example]
2661+
----
2662+
====
2663+
2664+
Let’s persist the following entities in our database:
2665+
2666+
[[hql-user-defined-function-inital-data]]
2667+
.Initial data
2668+
====
2669+
[source, JAVA, indent=0]
2670+
----
2671+
include::{example-dir-hql}/customFunctions/CustomDialectFunctionTest.java[tags=hql-user-defined-dialect-function-inital-data]
2672+
----
2673+
====
2674+
2675+
The first step for implementing a custom function is to create a custom dialect `ExtendedPGDialect`, which inherits from `PostgreSQLDialect`.
2676+
2677+
[[hql-user-defined-dialect-function-cutom-dialect]]
2678+
.Custom dialect
2679+
====
2680+
[source, JAVA, indent=0]
2681+
----
2682+
include::{example-dir-hql}/customFunctions/ExtendedPGDialect.java[tags=hql-user-defined-dialect-function-custom-dialect]
2683+
----
2684+
====
2685+
2686+
Secondly, we will set the `ExtendedPGDialect` to Hibernate config.
2687+
2688+
[[hql-user-defined-dialect-function-cutom-dialect-property]]
2689+
.Custom dialect property
2690+
====
2691+
[source, xml, indent=0]
2692+
----
2693+
<session-factory>
2694+
<!-- Other properties -->
2695+
<property name="hibernate.dialect">path.to.the.ExtendedPGDialect</property>
2696+
</session-factory>
2697+
----
2698+
====
2699+
2700+
For implementing custom function we should inherit the new class `CountItemsGreaterValSqmFunction` from `AbstractSqmSelfRenderingFunctionDescriptor` class.
2701+
2702+
[NOTE]
2703+
====
2704+
Constructor of `org.hibernate.query.sqm.function.AbstractSqmSelfRenderingFunctionDescriptor` contains the following fields:
2705+
2706+
* `String name` - name of the function _in the database_
2707+
* `FunctionKind` - type of the function: `NORMAL`, `AGGREGATE`, `ORDERED_SET_AGGREGATE` or `WINDOW`
2708+
* `ArgumentsValidator` - validator of the arguments provided to an JPQL/HQL function
2709+
* `FunctionReturnTypeResolver` - resolver of the function return type
2710+
* `FunctionArgumentTypeResolver` - resolver of the function argument types
2711+
====
2712+
2713+
[[hql-user-defined-dialect-function-sqm-renderer]]
2714+
.Custom function renderer
2715+
====
2716+
[source, JAVA, indent=0]
2717+
----
2718+
include::{example-dir-hql}/customFunctions/CountItemsGreaterValSqmFunction.java[tags=hql-user-defined-dialect-function-sqm-renderer]
2719+
----
2720+
====
2721+
2722+
Next step we should define the renderer:
2723+
2724+
[[hql-user-defined-dialect-function-sqm-renderer-definition]]
2725+
.Custom function renderer definition
2726+
====
2727+
[source, JAVA, indent=0]
2728+
----
2729+
include::{example-dir-hql}/customFunctions/CountItemsGreaterValSqmFunction.java[tags=hql-user-defined-dialect-function-sqm-renderer-definition]
2730+
----
2731+
====
2732+
2733+
Then we'll extend the `initializeFunctionRegistry()` method of the `ExtendedPGDialect` with new the logic:
2734+
adding `CountItemsGreaterValSqmFunction` to the default function registry of `FunctionContributions`.
2735+
2736+
[[hql-user-defined-dialect-function-registry-extending]]
2737+
.Custom dialect
2738+
====
2739+
[source, JAVA, indent=0]
2740+
----
2741+
include::{example-dir-hql}/customFunctions/ExtendedPGDialect.java[tags=hql-user-defined-dialect-function-registry-extending]
2742+
----
2743+
====
2744+
2745+
Once the `countItemsGreaterVal` function has been registered, we are able to use it in our JPQL/HQL queries.
2746+
2747+
[[hql-user-defined-dialect-function-test]]
2748+
.Test of the custom function
2749+
====
2750+
[source, JAVA, indent=0]
2751+
----
2752+
include::{example-dir-hql}/customFunctions/CustomDialectFunctionTest.java[tags=hql-user-defined-dialect-function-test]
2753+
----
2754+
====
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,20 @@
1+
CREATE OR REPLACE FUNCTION greater_than(count BIGINT, value NUMERIC, gr_val NUMERIC)
2+
RETURNS BIGINT AS
3+
$$
4+
BEGIN
5+
RETURN CASE WHEN value > gr_val THEN (count + 1)::BIGINT ELSE count::BIGINT END;
6+
END;
7+
$$ LANGUAGE "plpgsql";
8+
9+
CREATE OR REPLACE FUNCTION agg_final(c bigint) RETURNS BIGINT AS
10+
$$
11+
BEGIN
12+
return c;
13+
END;
14+
$$ LANGUAGE "plpgsql";
15+
16+
CREATE OR REPLACE AGGREGATE count_items_greater_val(NUMERIC, NUMERIC) (
17+
SFUNC = greater_than,
18+
STYPE = BIGINT,
19+
FINALFUNC = agg_final,
20+
INITCOND = 0);
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,135 @@
1+
package org.hibernate.orm.test.hql.customFunctions;
2+
3+
import org.hibernate.dialect.Dialect;
4+
import org.hibernate.dialect.function.CastFunction;
5+
import org.hibernate.metamodel.mapping.JdbcMapping;
6+
import org.hibernate.query.sqm.function.AbstractSqmSelfRenderingFunctionDescriptor;
7+
import org.hibernate.query.sqm.function.FunctionKind;
8+
import org.hibernate.query.sqm.produce.function.*;
9+
import org.hibernate.sql.ast.Clause;
10+
import org.hibernate.sql.ast.SqlAstTranslator;
11+
import org.hibernate.sql.ast.spi.SqlAppender;
12+
import org.hibernate.sql.ast.tree.SqlAstNode;
13+
import org.hibernate.sql.ast.tree.expression.CastTarget;
14+
import org.hibernate.sql.ast.tree.expression.Expression;
15+
import org.hibernate.sql.ast.tree.predicate.Predicate;
16+
import org.hibernate.type.BasicType;
17+
import org.hibernate.type.StandardBasicTypes;
18+
import org.hibernate.type.spi.TypeConfiguration;
19+
20+
import java.math.BigDecimal;
21+
import java.util.Arrays;
22+
import java.util.List;
23+
24+
import static org.hibernate.query.sqm.produce.function.FunctionParameterType.NUMERIC;
25+
26+
//tag::hql-user-defined-dialect-function-sqm-renderer[]
27+
public class CountItemsGreaterValSqmFunction extends AbstractSqmSelfRenderingFunctionDescriptor {
28+
private final CastFunction castFunction;
29+
private final BasicType<BigDecimal> bigDecimalType;
30+
31+
public CountItemsGreaterValSqmFunction(String name, Dialect dialect, TypeConfiguration typeConfiguration) {
32+
super(
33+
name,
34+
FunctionKind.AGGREGATE,
35+
/* Function consumes 2 numeric typed args:
36+
- the aggregation argument
37+
- the bottom edge for the count predicate*/
38+
new ArgumentTypesValidator(StandardArgumentsValidators.exactly(2),
39+
FunctionParameterType.NUMERIC,
40+
FunctionParameterType.NUMERIC
41+
),
42+
// Function returns one value - the number of items
43+
StandardFunctionReturnTypeResolvers.invariant(
44+
typeConfiguration.getBasicTypeRegistry()
45+
.resolve(StandardBasicTypes.BIG_INTEGER)
46+
),
47+
StandardFunctionArgumentTypeResolvers.invariant(
48+
typeConfiguration, NUMERIC, NUMERIC
49+
)
50+
);
51+
// Extracting cast function for setting input arguments to correct the type
52+
castFunction = new CastFunction(
53+
dialect,
54+
dialect.getPreferredSqlTypeCodeForBoolean()
55+
);
56+
bigDecimalType = typeConfiguration.getBasicTypeRegistry()
57+
.resolve(StandardBasicTypes.BIG_DECIMAL);
58+
}
59+
60+
@Override
61+
public void render(
62+
SqlAppender sqlAppender,
63+
List<? extends SqlAstNode> sqlAstArguments,
64+
SqlAstTranslator<?> walker) {
65+
render(sqlAppender, sqlAstArguments, null, walker);
66+
}
67+
68+
//tag::hql-user-defined-dialect-function-sqm-renderer-definition[]
69+
@Override
70+
public void render(
71+
SqlAppender sqlAppender,
72+
List<? extends SqlAstNode> sqlAstArguments,
73+
Predicate filter,
74+
SqlAstTranslator<?> translator) {
75+
// Renderer definition
76+
//end::hql-user-defined-dialect-function-sqm-renderer[]
77+
78+
// Appending name of SQL function to result query
79+
sqlAppender.appendSql(getName());
80+
sqlAppender.appendSql('(');
81+
82+
// Extracting 2 arguments
83+
final Expression first_arg = (Expression) sqlAstArguments.get(0);
84+
final Expression second_arg = (Expression) sqlAstArguments.get(1);
85+
86+
// If JPQL contains "filter" expression, but database doesn't support it
87+
// then append: function_name(case when (filter_expr) then (argument) else null end)
88+
final boolean caseWrapper = filter != null && !translator.supportsFilterClause();
89+
if (caseWrapper) {
90+
translator.getCurrentClauseStack().push(Clause.WHERE);
91+
sqlAppender.appendSql("case when ");
92+
93+
filter.accept(translator);
94+
translator.getCurrentClauseStack().pop();
95+
96+
sqlAppender.appendSql(" then ");
97+
renderArgument(sqlAppender, translator, first_arg);
98+
sqlAppender.appendSql(" else null end)");
99+
} else {
100+
renderArgument(sqlAppender, translator, first_arg);
101+
sqlAppender.appendSql(", ");
102+
renderArgument(sqlAppender, translator, second_arg);
103+
sqlAppender.appendSql(')');
104+
if (filter != null) {
105+
translator.getCurrentClauseStack().push(Clause.WHERE);
106+
sqlAppender.appendSql(" filter (where ");
107+
108+
filter.accept(translator);
109+
sqlAppender.appendSql(')');
110+
translator.getCurrentClauseStack().pop();
111+
}
112+
}
113+
//tag::hql-user-defined-dialect-function-sqm-renderer[]
114+
}
115+
116+
//end::hql-user-defined-dialect-function-sqm-renderer[]
117+
private void renderArgument(
118+
SqlAppender sqlAppender,
119+
SqlAstTranslator<?> translator,
120+
Expression arg) {
121+
// Extracting the type of argument
122+
final JdbcMapping sourceMapping = arg.getExpressionType().getJdbcMappings().get(0);
123+
if (sourceMapping.getJdbcType().isNumber()) {
124+
castFunction.render(sqlAppender,
125+
Arrays.asList(arg, new CastTarget(bigDecimalType)),
126+
translator
127+
);
128+
} else {
129+
arg.accept(translator);
130+
}
131+
}
132+
//tag::hql-user-defined-dialect-function-sqm-renderer[]
133+
//end::hql-user-defined-dialect-function-sqm-renderer-definition[]
134+
}
135+
//end::hql-user-defined-dialect-function-sqm-renderer[]
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,73 @@
1+
package org.hibernate.orm.test.hql.customFunctions;
2+
3+
import jakarta.persistence.EntityManager;
4+
import org.hibernate.Session;
5+
import org.hibernate.cfg.AvailableSettings;
6+
import org.hibernate.cfg.Configuration;
7+
import org.hibernate.cfg.Environment;
8+
import org.hibernate.dialect.PostgreSQLDialect;
9+
import org.hibernate.testing.junit4.BaseCoreFunctionalTestCase;
10+
import org.hibernate.testing.orm.junit.RequiresDialect;
11+
import org.junit.Test;
12+
13+
14+
import java.sql.Statement;
15+
16+
import static org.hibernate.testing.transaction.TransactionUtil.doInJPA;
17+
import static org.junit.Assert.assertEquals;
18+
19+
@RequiresDialect(PostgreSQLDialect.class)
20+
public class CustomDialectFunctionTest extends BaseCoreFunctionalTestCase {
21+
22+
@Override
23+
protected void configure(Configuration configuration) {
24+
super.configure(configuration);
25+
26+
configuration.addAnnotatedClass(Employee.class);
27+
configuration.setProperty(AvailableSettings.DIALECT, "org.hibernate.orm.test.hql.customFunctions.ExtendedPGDialect");
28+
}
29+
30+
@Override
31+
protected Class<?>[] getAnnotatedClasses() {
32+
return new Class<?>[]{
33+
Employee.class
34+
};
35+
}
36+
37+
@Test
38+
public void test_custom_sqm_functions() {
39+
doInJPA(this::sessionFactory, session -> {
40+
try (EntityManager entityManager = session.getEntityManagerFactory().createEntityManager()) {
41+
var tx = entityManager.getTransaction();
42+
tx.begin();
43+
44+
entityManager.unwrap(Session.class).doWork(connection -> {
45+
try (Statement statement = connection.createStatement()) {
46+
statement.executeUpdate("""
47+
create or replace function greater_than(c bigint, val numeric, gr_val numeric) returns bigint as $$ begin return case when val > gr_val then (c + 1)::bigint else c::bigint end; end; $$ language "plpgsql";
48+
create or replace function agg_final(c bigint) returns bigint as $$ begin return c; end; $$ language "plpgsql";
49+
create or replace aggregate count_items_greater_val(numeric, numeric) (sfunc = greater_than, stype = bigint, finalfunc = agg_final, initcond = 0);
50+
"""
51+
);
52+
}
53+
});
54+
55+
//tag::hql-user-defined-dialect-function-inital-data[]
56+
entityManager.persist(new Employee(1L, 200L, "Jonn", "Robson"));
57+
entityManager.persist(new Employee(2L, 350L, "Bert", "Marshall"));
58+
entityManager.persist(new Employee(3L, 360L, "Joey", "Barton"));
59+
entityManager.persist(new Employee(4L, 400L, "Bert", "Marshall"));
60+
//end::hql-user-defined-dialect-function-inital-data[]
61+
62+
tx.commit();
63+
//tag::hql-user-defined-dialect-function-test[]
64+
var res = entityManager
65+
.createQuery("select count_items_greater_val(salary, 220) from Employee")
66+
.getSingleResult();
67+
assertEquals(3L, res);
68+
//end::hql-user-defined-dialect-function-test[]
69+
}
70+
});
71+
}
72+
73+
}

0 commit comments

Comments
 (0)