Revise host.inet_addresses query to use gin index (#1550)

* Revise host.inet_addresses query to use gin index
This commit is contained in:
Weimin Yu 2022-03-09 23:32:17 -05:00 committed by GitHub
parent 9a022ff088
commit b6acbc77f1
2 changed files with 19 additions and 2 deletions

View file

@ -36,6 +36,17 @@ import javax.persistence.AccessType;
@javax.persistence.Entity(name = "Host")
@javax.persistence.Table(
name = "Host",
/**
* A gin index defined on the inet_addresses field ({@link HostBase#inetAddresses} cannot be
* declared here because JPA/Hibernate does not support index type specification. As a result,
* the hibernate-generated schema (which is for reference only) does not have this index.
*
* <p>There are Hibernate-specific solutions for adding this index to Hibernate's domain model.
* We could either declare the index in hibernate.cfg.xml or add it to the {@link
* org.hibernate.cfg.Configuration} instance for {@link SessionFactory} instantiation (which
* would prevent us from using JPA standard bootstrapping). For now, there is no obvious benefit
* doing either.
*/
indexes = {@javax.persistence.Index(columnList = "hostName")})
@ExternalMessagingName("host")
@WithStringVKey

View file

@ -64,11 +64,17 @@ final class NameserverLookupByIpCommand implements WhoisCommand {
jpaTm()
.transact(
() ->
// We cannot query @Convert-ed fields in HQL so we must use native Postgres
// We cannot query @Convert-ed fields in HQL so we must use native Postgres.
jpaTm()
.getEntityManager()
/**
* Using array_operator <@ (contained-by) with gin index on inet_address.
* Without gin index, this is slightly slower than the alternative form of
* ':address = ANY(inet_address)'.
*/
.createNativeQuery(
"SELECT * From \"Host\" WHERE :address = ANY(inet_addresses) AND "
"SELECT * From \"Host\" WHERE "
+ "ARRAY[ CAST(:address AS TEXT) ] <@ inet_addresses AND "
+ "deletion_time > CAST(:now AS timestamptz)",
HostResource.class)
.setParameter("address", InetAddresses.toAddrString(ipAddress))