2
0
mirror of https://gitlab.isc.org/isc-projects/kea synced 2025-09-10 10:55:19 +00:00

[4275] Postgresql schema 3.0 now matches MySql schema 4.2

Added 4.1 to 4.2 updates from MySQL and created upgrade
script for 2.0 to 3.0

src/share/database/scripts/pgsql/dhcpdb_create.pgsql
    - Enclosed the entire script in a single transaction
    - Removed DROP TABLE statements
    - Added host_identifier_type table and data
    - Added dhcp_option_scope table and data
    - Updated unqiue constraints for hosts table
    - Added scope_id and foreign key constraint to dhcp4_options table
    - Added scope_id and foreign key constraint to dhcp6_options table
    - Added unique contraint to ipv6_reservations table
    - Changed 'HWADDR_SOURCE_DOCSIS' to 'HWADDR_SOURCE_DOCSIS_CMTS'
    - Inserted row for 'HWADDR_SOURCE_UKNOWN'

src/share/database/scripts/pgsql/dhcpdb_drop.pgsql
    Added drops for host_identifier_type and  dhcp_option_scope

src/share/database/scripts/pgsql/upgrade_2.0_to_3.0.sh.in
    New file for upgrading Postgresql from 2.0 to 3.0

configure.ac
    Added src/share/database/scripts/pgsql/upgrade_2.0_to_3.0.sh

src/bin/admin/tests/pgsql_tests.sh.in
    - pgsql_upgrade_1_0_to_2_0 - new function which contains all the checks used
    to verify 1.0 to 2.0 upgrade (extracted from pgsql_upgrade_test)
    - pgsql_upgrade_2_0_to_3_0 - new function which contains all the checks used
    to verify 2.0 to 3.0 upgrade
    - pgsql_upgrade_test() - modified use new upgrade check fucntions

src/share/database/scripts/pgsql/Makefile.am
    Added entry for upgrade_2.0_to_3.0.sh
This commit is contained in:
Thomas Markwalder
2016-06-15 10:52:14 -04:00
parent 67e12a028b
commit a7db35543a
6 changed files with 441 additions and 45 deletions

View File

@@ -19,6 +19,8 @@
-- @dhcpdb_create.pgsql
-- Start a single transaction for the Entire script
START TRANSACTION;
-- Holds the IPv4 leases.
CREATE TABLE lease4 (
@@ -71,11 +73,10 @@ CREATE TABLE lease6_types (
lease_type SMALLINT PRIMARY KEY NOT NULL, -- Lease type code.
name VARCHAR(5) -- Name of the lease type
);
START TRANSACTION;
INSERT INTO lease6_types VALUES (0, 'IA_NA'); -- Non-temporary v6 addresses
INSERT INTO lease6_types VALUES (1, 'IA_TA'); -- Temporary v6 addresses
INSERT INTO lease6_types VALUES (2, 'IA_PD'); -- Prefix delegations
COMMIT;
-- Finally, the version of the schema. We start at 0.1 during development.
-- This table is only modified during schema upgrades. For historical reasons
@@ -90,9 +91,8 @@ CREATE TABLE schema_version (
version INT PRIMARY KEY NOT NULL, -- Major version number
minor INT -- Minor version number
);
START TRANSACTION;
INSERT INTO schema_version VALUES (1, 0);
COMMIT;
--
-- Schema 2.0 specification starts here.
@@ -121,11 +121,9 @@ CREATE TABLE lease_state (
name VARCHAR(64) NOT NULL);
-- Insert currently defined state names.
START TRANSACTION;
INSERT INTO lease_state VALUES (0, 'default');
INSERT INTO lease_state VALUES (1, 'declined');
INSERT INTO lease_state VALUES (2, 'expired-reclaimed');
COMMIT;
-- Add a constraint that any state value added to the lease4 must
-- map to a value in the lease_state table.
@@ -230,20 +228,41 @@ $$ LANGUAGE SQL;
--
-- Set 2.0 schema version.
START TRANSACTION;
UPDATE schema_version
SET version = '2', minor = '0';
COMMIT;
-- Schema 2.0 specification ends here.
-- Upgrade to schema 3.0 begins here:
--
-- Table structure for table hosts
-- Table structure for table host_identifier_type
--
DROP TABLE IF EXISTS hosts;
CREATE TABLE host_identifier_type (
type SMALLINT PRIMARY KEY NOT NULL,
name VARCHAR(32) DEFAULT NULL
);
INSERT INTO host_identifier_type VALUES (0, 'hw-address');
INSERT INTO host_identifier_type VALUES (1, 'duid');
INSERT INTO host_identifier_type VALUES (2, 'circuit-id');
CREATE TABLE dhcp_option_scope (
scope_id SMALLINT PRIMARY KEY NOT NULL,
scope_name varchar(32) DEFAULT NULL
);
INSERT INTO dhcp_option_scope VALUES (0, 'global');
INSERT INTO dhcp_option_scope VALUES (1, 'subnet');
INSERT INTO dhcp_option_scope VALUES (2, 'client-class');
INSERT INTO dhcp_option_scope VALUES (3, 'host');
--
-- Table structure for table hosts
--
-- Primary key and unique contraints automatically create indexes
-- foreign key constraints do not
CREATE TABLE hosts (
host_id SERIAL PRIMARY KEY NOT NULL,
dhcp_identifier BYTEA NOT NULL,
@@ -253,18 +272,20 @@ CREATE TABLE hosts (
ipv4_address BIGINT DEFAULT NULL,
hostname VARCHAR(255) DEFAULT NULL,
dhcp4_client_classes VARCHAR(255) DEFAULT NULL,
dhcp6_client_classes VARCHAR(255) DEFAULT NULL
dhcp6_client_classes VARCHAR(255) DEFAULT NULL,
CONSTRAINT key_dhcp4_ipv4_address_subnet_id UNIQUE (ipv4_address, dhcp4_subnet_id),
CONSTRAINT key_dhcp4_identifier_subnet_id UNIQUE (dhcp_identifier, dhcp_identifier_type, dhcp4_subnet_id),
CONSTRAINT key_dhcp6_identifier_subnet_id UNIQUE (dhcp_identifier, dhcp_identifier_type, dhcp6_subnet_id),
CONSTRAINT fk_host_identifier_type FOREIGN KEY (dhcp_identifier_type) REFERENCES host_identifier_type (type)
ON DELETE CASCADE
);
CREATE INDEX key_dhcp4_identifier_subnet_id ON hosts (dhcp_identifier, dhcp_identifier_type);
CREATE INDEX key_dhcp6_identifier_subnet_id ON hosts (dhcp_identifier, dhcp_identifier_type, dhcp6_subnet_id);
CREATE INDEX fk_host_identifier_type ON hosts (dhcp_identifier_type);
--
-- Table structure for table dhcp4_options
--
DROP TABLE IF EXISTS dhcp4_options;
CREATE TABLE dhcp4_options (
option_id SERIAL PRIMARY KEY NOT NULL,
code SMALLINT NOT NULL,
@@ -275,16 +296,18 @@ CREATE TABLE dhcp4_options (
dhcp_client_class VARCHAR(128) DEFAULT NULL,
dhcp4_subnet_id INT DEFAULT NULL,
host_id INT DEFAULT NULL,
CONSTRAINT fk_options_host1 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
scope_id SMALLINT NOT NULL,
CONSTRAINT fk_options_host1 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE,
CONSTRAINT fk_dhcp4_option_scode FOREIGN KEY (scope_id) REFERENCES dhcp_option_scope (scope_id) ON DELETE CASCADE
);
CREATE INDEX fk_dhcp4_options_host1_idx ON dhcp4_options (host_id);
CREATE INDEX fk_dhcp4_options_scope_idx ON dhcp4_options (scope_id);
--
-- Table structure for table dhcp6_options
--
DROP TABLE IF EXISTS dhcp6_options;
CREATE TABLE dhcp6_options (
option_id SERIAL PRIMARY KEY NOT NULL,
code INT NOT NULL,
@@ -295,16 +318,18 @@ CREATE TABLE dhcp6_options (
dhcp_client_class VARCHAR(128) DEFAULT NULL,
dhcp6_subnet_id INT DEFAULT NULL,
host_id INT DEFAULT NULL,
CONSTRAINT fk_options_host10 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
scope_id SMALLINT NOT NULL,
CONSTRAINT fk_options_host10 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE,
CONSTRAINT fk_dhcp6_option_scode FOREIGN KEY (scope_id) REFERENCES dhcp_option_scope (scope_id) ON DELETE CASCADE
);
CREATE INDEX fk_dhcp6_options_host1_idx ON dhcp6_options (host_id);
CREATE INDEX fk_dhcp6_options_scope_idx ON dhcp6_options (scope_id);
--
-- Table structure for table ipv6_reservations
--
DROP TABLE IF EXISTS ipv6_reservations;
CREATE TABLE ipv6_reservations (
reservation_id SERIAL PRIMARY KEY NOT NULL,
address VARCHAR(39) NOT NULL,
@@ -312,6 +337,7 @@ CREATE TABLE ipv6_reservations (
type SMALLINT NOT NULL DEFAULT '0',
dhcp6_iaid INT DEFAULT NULL,
host_id INT NOT NULL,
CONSTRAINT key_dhcp6_address_prefix_len UNIQUE (address, prefix_len),
CONSTRAINT fk_ipv6_reservations_host FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
);
@@ -321,7 +347,6 @@ CREATE INDEX fk_ipv6_reservations_host_idx ON ipv6_reservations (host_id);
-- Table structure for table lease_hwaddr_source
--
DROP TABLE IF EXISTS lease_hwaddr_source;
CREATE TABLE lease_hwaddr_source (
hwaddr_source INT PRIMARY KEY NOT NULL,
name VARCHAR(40) DEFAULT NULL
@@ -346,8 +371,13 @@ INSERT INTO lease_hwaddr_source VALUES (16, 'HWADDR_SOURCE_REMOTE_ID');
INSERT INTO lease_hwaddr_source VALUES (32, 'HWADDR_SOURCE_SUBSCRIBER_ID');
-- Hardware address extracted from docsis options
INSERT INTO lease_hwaddr_source VALUES (64, 'HWADDR_SOURCE_DOCSIS');
INSERT INTO lease_hwaddr_source VALUES (64, 'HWADDR_SOURCE_DOCSIS_CMTS');
INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
-- In the event hardware address cannot be determined, we need to satisfy
-- foreign key constraint between lease6 and lease_hardware_source
INSERT INTO lease_hwaddr_source VALUES (0, 'HWADDR_SOURCE_UNKNOWN');
-- Adding ORDER BY clause to sort by lease address
--
@@ -440,12 +470,14 @@ CREATE FUNCTION lease6DumpData() RETURNS
left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source)
ORDER BY l.address;
$$ LANGUAGE SQL;
--
-- Set 3.0 schema version.
START TRANSACTION;
UPDATE schema_version
SET version = '3', minor = '0';
-- Schema 3.0 specification ends here.
-- Commit the script transaction
COMMIT;
-- Notes: