Improve consent deletion when a realm is removed

Closes #30992

Signed-off-by: rmartinc <rmartinc@redhat.com>
This commit is contained in:
rmartinc 2024-07-03 18:20:17 +02:00 committed by Alexander Schwartz
parent b5468c8b63
commit ce195b81f8
9 changed files with 66 additions and 39 deletions

View file

@ -0,0 +1,5 @@
= Improving performance for deletion of user consents
When a client scope or the full realm are deleted the associated user consents should also be removed. A new index over the table `USER_CONSENT_CLIENT_SCOPE` has been added to increase the performance.
Note that, if the table contains more than 300.000 entries, by default {project_name} skips the creation of the indexes during the automatic schema migration and logs the SQL statements to the console instead. The statements must be run manually in the DB after {project_name}'s startup. Check the link:{upgradingguide_link}[{upgradingguide_name}] for details on how to configure a different limit.

View file

@ -5,6 +5,10 @@
include::changes-26_0_0.adoc[leveloffset=3]
=== Migrating to 25.0.2
include::changes-25_0_2.adoc[leveloffset=3]
=== Migrating to 25.0.0
include::changes-25_0_0.adoc[leveloffset=3]

View file

@ -182,18 +182,15 @@ public class JpaUtils {
*/
public static Properties loadSpecificNamedQueries(String databaseType) {
URL specificUrl = JpaUtils.class.getClassLoader().getResource("META-INF/queries-" + databaseType + ".properties");
URL defaultUrl = JpaUtils.class.getClassLoader().getResource("META-INF/queries-default.properties");
if (defaultUrl == null) {
throw new IllegalStateException("META-INF/queries-default.properties was not found in the classpath");
}
Properties specificQueries = loadSqlProperties(specificUrl);
Properties defaultQueries = loadSqlProperties(defaultUrl);
Properties queries = new Properties();
if (specificQueries == null) {
return queries;
}
for (String queryNameFull : defaultQueries.stringPropertyNames()) {
String querySql = defaultQueries.getProperty(queryNameFull);
for (String queryNameFull : specificQueries.stringPropertyNames()) {
String querySql = specificQueries.getProperty(queryNameFull);
String queryName = getQueryShortName(queryNameFull);
String specificQueryNameFull = getQueryFromProperties(queryName, specificQueries);

View file

@ -32,19 +32,14 @@ import java.io.Serializable;
* @author <a href="mailto:mposolda@redhat.com">Marek Posolda</a>
*/
@NamedQueries({
// sub-query with deletion performs very slow in MySQL/MariaDB databases
// It is removed from here and added manually in JpaUtils to give a native implementation if needed
// @NamedQuery(name="deleteClientSessionsByRealm", query="delete from PersistentClientSessionEntity sess where sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.realmId = :realmId)"),
@NamedQuery(name="deleteClientSessionsByRealm", query="delete from PersistentClientSessionEntity sess where sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.realmId = :realmId)"),
@NamedQuery(name="deleteClientSessionsByClient", query="delete from PersistentClientSessionEntity sess where sess.clientId = :clientId"),
@NamedQuery(name="deleteClientSessionsByExternalClient", query="delete from PersistentClientSessionEntity sess where sess.clientStorageProvider = :clientStorageProvider and sess.externalClientId = :externalClientId"),
@NamedQuery(name="deleteClientSessionsByClientStorageProvider", query="delete from PersistentClientSessionEntity sess where sess.clientStorageProvider = :clientStorageProvider"),
// sub-query with deletion performs very slow in MySQL/MariaDB databases
// It is removed from here and added manually in JpaUtils to give a native implementation if needed
// @NamedQuery(name="deleteClientSessionsByUser", query="delete from PersistentClientSessionEntity sess where sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.userId = :userId)"),
@NamedQuery(name="deleteClientSessionsByUser", query="delete from PersistentClientSessionEntity sess where sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.userId = :userId)"),
@NamedQuery(name="deleteClientSessionsByUserSession", query="delete from PersistentClientSessionEntity sess where sess.userSessionId = :userSessionId and sess.offline = :offline"),
// KEYCLOAK-18842: The deleteExpiredClientSessions performs very slow in MySQL/MariaDB databases
// It is removed from here and added manually in JpaUtils to give a native implementation if needed
//@NamedQuery(name="deleteExpiredClientSessions", query="delete from PersistentClientSessionEntity sess where sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.realmId = :realmId AND u.offline = :offline AND u.lastSessionRefresh < :lastSessionRefresh)"),
@NamedQuery(name="deleteExpiredClientSessions", query="delete from PersistentClientSessionEntity sess where sess.offline = :offline AND sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.realmId = :realmId AND u.offline = :offline AND u.lastSessionRefresh < :lastSessionRefresh)"),
@NamedQuery(name="deleteClientSessionsByRealmSessionType", query="delete from PersistentClientSessionEntity sess where sess.offline = :offline AND sess.userSessionId IN (select u.userSessionId from PersistentUserSessionEntity u where u.realmId = :realmId and u.offline = :offline)"),
@NamedQuery(name="findClientSessionsByUserSession", query="select sess from PersistentClientSessionEntity sess where sess.userSessionId=:userSessionId and sess.offline = :offline"),
@NamedQuery(name="findClientSessionsOrderedByIdInterval", query="select sess from PersistentClientSessionEntity sess where sess.offline = :offline and sess.userSessionId >= :fromSessionId and sess.userSessionId <= :toSessionId order by sess.userSessionId"),
@NamedQuery(name="findClientSessionsOrderedByIdExact", query="select sess from PersistentClientSessionEntity sess where sess.offline = :offline and sess.userSessionId IN (:userSessionIds)"),

View file

@ -0,0 +1,31 @@
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!--
~ * Copyright 2024 Red Hat, Inc. and/or its affiliates
~ * and other contributors as indicated by the @author tags.
~ *
~ * Licensed under the Apache License, Version 2.0 (the "License");
~ * you may not use this file except in compliance with the License.
~ * You may obtain a copy of the License at
~ *
~ * http://www.apache.org/licenses/LICENSE-2.0
~ *
~ * Unless required by applicable law or agreed to in writing, software
~ * distributed under the License is distributed on an "AS IS" BASIS,
~ * WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
~ * See the License for the specific language governing permissions and
~ * limitations under the License.
-->
<databaseChangeLog xmlns="http://www.liquibase.org/xml/ns/dbchangelog" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xsi:schemaLocation="http://www.liquibase.org/xml/ns/dbchangelog http://www.liquibase.org/xml/ns/dbchangelog/dbchangelog-3.1.xsd">
<changeSet author="keycloak" id="18.0.15-30992-index-consent">
<preConditions onSqlOutput="TEST" onFail="MARK_RAN">
<not>
<indexExists tableName="USER_CONSENT_CLIENT_SCOPE" indexName="IDX_USCONSENT_SCOPE_ID" />
</not>
</preConditions>
<createIndex tableName="USER_CONSENT_CLIENT_SCOPE" indexName="IDX_USCONSENT_SCOPE_ID">
<column name="SCOPE_ID" type="VARCHAR(36)"/>
</createIndex>
</changeSet>
</databaseChangeLog>

View file

@ -73,6 +73,7 @@
<include file="META-INF/jpa-changelog-15.0.0.xml"/>
<include file="META-INF/jpa-changelog-17.0.0.xml"/>
<include file="META-INF/jpa-changelog-18.0.0.xml"/>
<include file="META-INF/jpa-changelog-18.0.15.xml"/>
<include file="META-INF/jpa-changelog-19.0.0.xml"/>
<include file="META-INF/jpa-changelog-20.0.0.xml"/>
<include file="META-INF/jpa-changelog-21.0.2.xml"/>

View file

@ -1,22 +0,0 @@
# properties file to define all default queries that are loaded separately
# in a properties file. These queries can be overloaded with a
# specific file for each database type. Queries are defined in the form:
# name[type]=sql
# type can be native (for native queries) or jpql (jpql syntax)
# if no type is defined jpql is the default
deleteExpiredClientSessions=delete from PersistentClientSessionEntity sess where sess.offline = :offline AND sess.userSessionId IN (\
select u.userSessionId from PersistentUserSessionEntity u \
where u.realmId = :realmId AND u.offline = :offline AND u.lastSessionRefresh < :lastSessionRefresh)
deleteClientSessionsByRealm=delete from PersistentClientSessionEntity sess where sess.userSessionId IN (\
select u.userSessionId from PersistentUserSessionEntity u \
where u.realmId = :realmId)
deleteClientSessionsByRealmSessionType=delete from PersistentClientSessionEntity sess where sess.offline = :offline AND sess.userSessionId IN (\
select u.userSessionId from PersistentUserSessionEntity u \
where u.realmId = :realmId and u.offline = :offline)
deleteClientSessionsByUser=delete from PersistentClientSessionEntity sess where sess.userSessionId IN (\
select u.userSessionId from PersistentUserSessionEntity u \
where u.userId = :userId)

View file

@ -16,3 +16,11 @@ deleteClientSessionsByRealmSessionType[native]=delete c from OFFLINE_CLIENT_SESS
deleteClientSessionsByUser[native]=delete c from OFFLINE_CLIENT_SESSION c join OFFLINE_USER_SESSION u \
where c.USER_SESSION_ID = u.USER_SESSION_ID and u.USER_ID = :userId
deleteUserConsentClientScopesByRealm[native]=delete cc from USER_CONSENT_CLIENT_SCOPE cc join USER_CONSENT uc join USER_ENTITY u \
where cc.USER_CONSENT_ID = uc.ID and uc.USER_ID = u.ID and u.REALM_ID=:realmId
deleteUserConsentsByRealm[native]=delete uc from USER_CONSENT uc join USER_ENTITY u where uc.USER_ID = u.ID and u.REALM_ID = :realmId
deleteUserConsentClientScopesByClient[native]=delete cc from USER_CONSENT_CLIENT_SCOPE cc join USER_CONSENT uc \
where cc.USER_CONSENT_ID = uc.ID and uc.CLIENT_ID = :clientId

View file

@ -16,3 +16,11 @@ deleteClientSessionsByRealmSessionType[native]=delete c from OFFLINE_CLIENT_SESS
deleteClientSessionsByUser[native]=delete c from OFFLINE_CLIENT_SESSION c join OFFLINE_USER_SESSION u \
where c.USER_SESSION_ID = u.USER_SESSION_ID and u.USER_ID = :userId
deleteUserConsentClientScopesByRealm[native]=delete cc from USER_CONSENT_CLIENT_SCOPE cc join USER_CONSENT uc join USER_ENTITY u \
where cc.USER_CONSENT_ID = uc.ID and uc.USER_ID = u.ID and u.REALM_ID=:realmId
deleteUserConsentsByRealm[native]=delete uc from USER_CONSENT uc join USER_ENTITY u where uc.USER_ID = u.ID and u.REALM_ID = :realmId
deleteUserConsentClientScopesByClient[native]=delete cc from USER_CONSENT_CLIENT_SCOPE cc join USER_CONSENT uc \
where cc.USER_CONSENT_ID = uc.ID and uc.CLIENT_ID = :clientId