From: Thomas Markwalder Date: Wed, 20 Jul 2022 15:53:27 +0000 (-0400) Subject: [#2452] Improve postgresl indexes on hosts table X-Git-Tag: Kea-2.2.0~18 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=b0c3dda963425f5d7dbb97bbce4e83d453b2f859;p=thirdparty%2Fkea.git [#2452] Improve postgresl indexes on hosts table src/share/database/scripts/pgsql/dhcpdb_create.pgsql src/share/database/scripts/pgsql/upgrade_012_to_013.sh.in Added host index for dhcp identifier + type only - v4 and v6 Modified existing host index to include subnet-id = 0 - v4 and v6 --- diff --git a/src/share/database/scripts/pgsql/dhcpdb_create.pgsql b/src/share/database/scripts/pgsql/dhcpdb_create.pgsql index a3d246dfd8..7c1ce31870 100644 --- a/src/share/database/scripts/pgsql/dhcpdb_create.pgsql +++ b/src/share/database/scripts/pgsql/dhcpdb_create.pgsql @@ -5604,6 +5604,24 @@ BEGIN END; $$ LANGUAGE plpgsql; +-- Improve hosts indexes for better performance of global reservations +-- Create new index that uses only dhcp4_identifier. +CREATE INDEX key_dhcp4_identifier on hosts (dhcp_identifier, dhcp_identifier_type); +-- Create new index that uses only dhcp4_identifier. +CREATE INDEX key_dhcp6_identifier on hosts (dhcp_identifier, dhcp_identifier_type); + +-- Modify existing indexes to include subnet_id values of 0, so index is also used +-- for global reservations. +DROP INDEX key_dhcp4_identifier_subnet_id; +CREATE UNIQUE INDEX key_dhcp4_identifier_subnet_id ON hosts + (dhcp_identifier ASC, dhcp_identifier_type ASC, dhcp4_subnet_id ASC) + WHERE (dhcp4_subnet_id IS NOT NULL); + +DROP INDEX key_dhcp6_identifier_subnet_id; +CREATE UNIQUE INDEX key_dhcp6_identifier_subnet_id ON hosts + (dhcp_identifier ASC, dhcp_identifier_type ASC, dhcp6_subnet_id ASC) + WHERE (dhcp6_subnet_id IS NOT NULL); + -- Update the schema version number. UPDATE schema_version SET version = '13', minor = '0'; diff --git a/src/share/database/scripts/pgsql/upgrade_012_to_013.sh.in b/src/share/database/scripts/pgsql/upgrade_012_to_013.sh.in index 39ce42327d..020edca5fe 100644 --- a/src/share/database/scripts/pgsql/upgrade_012_to_013.sh.in +++ b/src/share/database/scripts/pgsql/upgrade_012_to_013.sh.in @@ -653,6 +653,24 @@ BEGIN END; \$\$ LANGUAGE plpgsql; +-- Improve hosts indexes for better performance of global reservations +-- Create new index that uses only dhcp4_identifier. +CREATE INDEX key_dhcp4_identifier on hosts (dhcp_identifier, dhcp_identifier_type); +-- Create new index that uses only dhcp4_identifier. +CREATE INDEX key_dhcp6_identifier on hosts (dhcp_identifier, dhcp_identifier_type); + +-- Modify existing indexes to include subnet_id values of 0, so index is also used +-- for global reservations. +DROP INDEX IF EXISTS key_dhcp4_identifier_subnet_id; +CREATE UNIQUE INDEX key_dhcp4_identifier_subnet_id ON hosts + (dhcp_identifier ASC, dhcp_identifier_type ASC, dhcp4_subnet_id ASC) + WHERE (dhcp4_subnet_id IS NOT NULL); + +DROP INDEX IF EXISTS key_dhcp6_identifier_subnet_id; +CREATE UNIQUE INDEX key_dhcp6_identifier_subnet_id ON hosts + (dhcp_identifier ASC, dhcp_identifier_type ASC, dhcp6_subnet_id ASC) + WHERE (dhcp6_subnet_id IS NOT NULL); + -- Update the schema version number. UPDATE schema_version SET version = '13', minor = '0';