HHH-17506 Add documentation for ON CONFLICT clause

This commit is contained in:
Christian Beikov 2023-12-21 10:56:52 +01:00
parent bb4ed4b000
commit 81892127b3
4 changed files with 49 additions and 4 deletions

View File

@ -276,6 +276,11 @@ It's usually better to just use `persist()`.
On the other hand, you might consider using it to set up test data.
====
[NOTE]
====
`insert` statements are not available in JPQL.
====
The BNF for an `insert` statement is:
[[hql-insert-bnf-example]]
@ -331,9 +336,37 @@ It's not available for entities whose id generator is implemented in Java, nor f
The same two options are available for a `@Version` attribute.
When no version is explicitly specified, the version for a new entity instance is used.
To implement "upsert" semantics i.e. insert-or-update, the `on conflict` clause can be used.
Reacting on conflicts can be either based on the name or the list of attribute paths of a unique constraint.
Using the unique constraint name as conflict target requires either native database support,
which at the time of writing is only available in PostgreSQL, or that the statement is a single row insert.
A single row insert can be ensured by specifying only a single values tuple in case of an insert-values statement,
or using `fetch first 1 rows only` in case of an insert-select statement.
Possible conflict actions are to ignore the conflict or update conflicting objects/rows.
[[hql-insert-conflict-example]]
====
[source, SQL, indent=0]
----
include::{example-dir-hql}/../query/hql/InsertConflictTests.java[tags=hql-insert-conflict-example]
----
====
The special alias `excluded` is available in the `update set` clause of the `conflict clause`
and refers to the values that failed insertion due to a unique constraint conflict.
[NOTE]
====
`insert ... select` statements are not available in JPQL.
The MySQL/MariaDB implementation leverages the native `on duplicate key` clause
which does not support specifying an explicit column list or constraint name.
Beware that this implementation might produce different results than on other databases
if a table has more than a single unique constraint.
Another quirk of this implementation is that the MySQL/MariaDB JDBC driver returns surprising update counts.
For every row that is inserted, the update count is incremented by 1, but for rows that are updated,
the update count is incremented by 2.
To learn more about this, refer to the https://dev.mysql.com/doc/refman/8.0/en/insert-on-duplicate.html[MySQL documentation].
====
[[hql-literals]]

View File

@ -1,5 +1,5 @@
insertStatement
: "INSERT" "INTO"? targetEntity targetFields (queryExpression | valuesList)
: "INSERT" "INTO"? targetEntity targetFields (queryExpression | valuesList) conflictClause?
targetEntity
: entityName variable?
@ -12,3 +12,14 @@ valuesList
values
: "(" expression ("," expression)* ")"
conflictClause
: "on conflict" conflictTarget? conflictAction
conflictTarget
: "on constraint" identifier
| "(" simplePath ("," simplePath)* ")";
conflictAction
: "do nothing"
| "do update" setClause whereClause?

View File

@ -1966,7 +1966,7 @@ public abstract class AbstractSqlAstTranslator<T extends JdbcOperation> implemen
// To allow meaningful usage, we simply ignore the constraint column names in this emulation.
// A possible problem with this is when the constraint column names contain the primary key columns,
// but the insert fails due to a unique constraint violation. This emulation will not cause a failure to be
// propagated, but instead will run the respective conflict action. todo: document this
// propagated, but instead will run the respective conflict action.
final String constraintName = conflictClause.getConstraintName();
if ( constraintName != null ) {
throw new IllegalQueryOperationException( "Dialect does not support constraint name in conflict clause" );

View File

@ -18,7 +18,6 @@ import org.hibernate.testing.orm.domain.StandardDomainModel;
import org.hibernate.testing.orm.domain.contacts.Contact;
import org.hibernate.testing.orm.domain.contacts.Contact.Name;
import org.hibernate.testing.orm.domain.gambit.BasicEntity;
import org.hibernate.testing.orm.junit.DialectFeatureCheck;
import org.hibernate.testing.orm.junit.DialectFeatureChecks;
import org.hibernate.testing.orm.junit.DomainModel;
import org.hibernate.testing.orm.junit.JiraKey;
@ -90,12 +89,14 @@ public class InsertConflictTests {
public void testOnConflictDoUpdate(SessionFactoryScope scope) {
scope.inTransaction(
session -> {
//tag::hql-insert-conflict-example[]
int updated = session.createMutationQuery(
"insert into BasicEntity (id, data) " +
"values (1, 'John') " +
"on conflict(id) do update " +
"set data = excluded.data"
).executeUpdate();
//end::hql-insert-conflict-example[]
if ( scope.getSessionFactory().getJdbcServices().getDialect() instanceof MySQLDialect ) {
// Strange MySQL returns 2 if the conflict action updates a row
// Also see https://dev.mysql.com/doc/refman/8.0/en/insert-on-duplicate.html