Improve the performance of the queries used to find granted resources

- simplifies the queries to avoid unnecessary join
- creates two new indexes to speed up search time

Closes #28861

Signed-off-by: Stefan Guilhen <sguilhen@redhat.com>
This commit is contained in:
Stefan Guilhen 2024-04-19 16:04:12 -03:00 committed by Pedro Igor
parent 957859d846
commit 8ca4bc77a1
3 changed files with 22 additions and 3 deletions

View file

@ -257,3 +257,15 @@ Instead, implement `isSupported(Config.Scope config)`.
= Removal of the deprecated LinkedIn provider = Removal of the deprecated LinkedIn provider
In version 22.0.2 the OAuh 2.0 social provider for LinkedIn was replaced by a new OpenId Connect implementation. The legacy provider was deprecated but not removed, just in case it was still functional in some existing realms. {project_name} 25.0.0 is definitely removing the old provider and its associated `linkedin-oauth` feature. From now on, the default `LinkedIn` social provider is the only option available. In version 22.0.2 the OAuh 2.0 social provider for LinkedIn was replaced by a new OpenId Connect implementation. The legacy provider was deprecated but not removed, just in case it was still functional in some existing realms. {project_name} 25.0.0 is definitely removing the old provider and its associated `linkedin-oauth` feature. From now on, the default `LinkedIn` social provider is the only option available.
= Improved performance of `findGrantedResources` and `findGrantedOwnerResources` queries
These queries performed poorly when the `RESOURCE_SERVER_RESOURCE` and `RESOURCE_SERVER_PERM_TICKET` tables had over 100k entries
and users were granted access to over 1k resources. The queries were simplified and new indexes for the `requester` and `owner`
columns were introduced.
The new indexes are both applied to the `RESOURCE_SERVER_PERM_TICKET` table. If the table currently contains more than 300.000 entries,
{project_name} will skip the creation of the indexes by default during the automatic schema migration, and will instead log the SQL statements
on the console during migration. In this case, the statements must be run manually in the DB after {project_name}'s startup.
See the link:{upgradingguide_link}[{upgradingguide_name}] for details on how to configure a different limit.

View file

@ -42,9 +42,9 @@ import jakarta.persistence.UniqueConstraint;
@NamedQuery(name="findPermissionIdByResource", query="select p.id from PermissionTicketEntity p inner join p.resource r where p.resourceServer.id = :serverId and (r.resourceServer = :serverId and r.id = :resourceId)"), @NamedQuery(name="findPermissionIdByResource", query="select p.id from PermissionTicketEntity p inner join p.resource r where p.resourceServer.id = :serverId and (r.resourceServer = :serverId and r.id = :resourceId)"),
@NamedQuery(name="findPermissionIdByScope", query="select p.id from PermissionTicketEntity p inner join p.scope s where p.resourceServer.id = :serverId and (s.resourceServer.id = :serverId and s.id = :scopeId)"), @NamedQuery(name="findPermissionIdByScope", query="select p.id from PermissionTicketEntity p inner join p.scope s where p.resourceServer.id = :serverId and (s.resourceServer.id = :serverId and s.id = :scopeId)"),
@NamedQuery(name="findPermissionTicketIdByServerId", query="select p.id from PermissionTicketEntity p where p.resourceServer.id = :serverId "), @NamedQuery(name="findPermissionTicketIdByServerId", query="select p.id from PermissionTicketEntity p where p.resourceServer.id = :serverId "),
@NamedQuery(name="findGrantedResources", query="select distinct(r.id) from ResourceEntity r inner join PermissionTicketEntity p on r.id = p.resource.id where p.grantedTimestamp is not null and p.requester = :requester order by r.id"), @NamedQuery(name="findGrantedResources", query="select distinct(p.resource.id) from PermissionTicketEntity p where p.requester = :requester and p.grantedTimestamp is not null order by p.resource.id"),
@NamedQuery(name="findGrantedResourcesByName", query="select distinct(r.id) from ResourceEntity r inner join PermissionTicketEntity p on r.id = p.resource.id where p.grantedTimestamp is not null and p.requester = :requester and lower(r.name) like :resourceName order by r.id"), @NamedQuery(name="findGrantedResourcesByName", query="select distinct(r.id) from ResourceEntity r inner join PermissionTicketEntity p on r.id = p.resource.id where p.grantedTimestamp is not null and p.requester = :requester and lower(r.name) like :resourceName order by r.id"),
@NamedQuery(name="findGrantedOwnerResources", query="select distinct(r.id) from ResourceEntity r inner join PermissionTicketEntity p on r.id = p.resource.id where p.grantedTimestamp is not null and p.owner = :owner order by r.id") @NamedQuery(name="findGrantedOwnerResources", query="select distinct(p.resource.id) from PermissionTicketEntity p where p.owner = :owner and p.grantedTimestamp is not null order by p.resource.id")
} }
) )
public class PermissionTicketEntity { public class PermissionTicketEntity {

View file

@ -133,5 +133,12 @@
<addUniqueConstraint columnNames="CLIENT_STORAGE_PROVIDER, EXTERNAL_CLIENT_ID, USER_ID" constraintName="UK_EXTERNAL_CONSENT" tableName="USER_CONSENT"/> <addUniqueConstraint columnNames="CLIENT_STORAGE_PROVIDER, EXTERNAL_CLIENT_ID, USER_ID" constraintName="UK_EXTERNAL_CONSENT" tableName="USER_CONSENT"/>
</changeSet> </changeSet>
<changeSet author="keycloak" id="25.0.0-28861-index-creation">
<createIndex tableName="RESOURCE_SERVER_PERM_TICKET" indexName="IDX_PERM_TICKET_REQUESTER">
<column name="REQUESTER"/>
</createIndex>
<createIndex tableName="RESOURCE_SERVER_PERM_TICKET" indexName="IDX_PERM_TICKET_OWNER">
<column name="OWNER"/>
</createIndex>
</changeSet>
</databaseChangeLog> </databaseChangeLog>