summaryrefslogtreecommitdiffstats
path: root/src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in
diff options
context:
space:
mode:
Diffstat (limited to 'src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in')
-rw-r--r--src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in293
1 files changed, 293 insertions, 0 deletions
diff --git a/src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in b/src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in
new file mode 100644
index 0000000..bf79353
--- /dev/null
+++ b/src/share/database/scripts/pgsql/upgrade_002.0_to_003.0.sh.in
@@ -0,0 +1,293 @@
+#!/bin/sh
+
+# Copyright (C) 2016-2022 Internet Systems Consortium, Inc. ("ISC")
+#
+# This Source Code Form is subject to the terms of the Mozilla Public
+# License, v. 2.0. If a copy of the MPL was not distributed with this
+# file, You can obtain one at http://mozilla.org/MPL/2.0/.
+
+# shellcheck disable=SC1091
+# SC1091: Not following: ... was not specified as input (see shellcheck -x).
+
+# Exit with error if commands exit with non-zero and if undefined variables are
+# used.
+set -eu
+
+# shellcheck disable=SC2034
+# SC2034: ... appears unused. Verify use (or export if used externally).
+prefix="@prefix@"
+
+# Include utilities. Use installed version if available and
+# use build version if it isn't.
+if [ -e @datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh ]; then
+ . "@datarootdir@/@PACKAGE_NAME@/scripts/admin-utils.sh"
+else
+ . "@abs_top_builddir@/src/bin/admin/admin-utils.sh"
+fi
+
+VERSION=$(pgsql_version "$@")
+
+if [ "$VERSION" != "2.0" ]; then
+ printf 'This script upgrades 2.0 to 3.0. '
+ printf 'Reported version is %s. Skipping upgrade.\n' "${VERSION}"
+ exit 0
+fi
+
+psql "$@" >/dev/null <<EOF
+
+START TRANSACTION;
+
+-- Upgrade to schema 3.0 begins here:
+
+--
+-- Table structure for table host_identifier_type
+--
+
+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 constraints automatically create indexes
+-- foreign key constraints do not
+CREATE TABLE hosts (
+ host_id SERIAL PRIMARY KEY NOT NULL,
+ dhcp_identifier BYTEA NOT NULL,
+ dhcp_identifier_type SMALLINT NOT NULL,
+ dhcp4_subnet_id INT DEFAULT NULL,
+ dhcp6_subnet_id INT DEFAULT NULL,
+ ipv4_address BIGINT DEFAULT NULL,
+ hostname VARCHAR(255) DEFAULT NULL,
+ dhcp4_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 fk_host_identifier_type ON hosts (dhcp_identifier_type);
+
+--
+-- Table structure for table dhcp4_options
+--
+
+CREATE TABLE dhcp4_options (
+ option_id SERIAL PRIMARY KEY NOT NULL,
+ code SMALLINT NOT NULL,
+ value BYTEA,
+ formatted_value TEXT,
+ space VARCHAR(128) DEFAULT NULL,
+ persistent BOOLEAN NOT NULL DEFAULT 'f',
+ dhcp_client_class VARCHAR(128) DEFAULT NULL,
+ dhcp4_subnet_id INT DEFAULT NULL,
+ host_id INT DEFAULT NULL,
+ 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
+--
+
+CREATE TABLE dhcp6_options (
+ option_id SERIAL PRIMARY KEY NOT NULL,
+ code INT NOT NULL,
+ value BYTEA,
+ formatted_value TEXT,
+ space VARCHAR(128) DEFAULT NULL,
+ persistent BOOLEAN NOT NULL DEFAULT 'f',
+ dhcp_client_class VARCHAR(128) DEFAULT NULL,
+ dhcp6_subnet_id INT DEFAULT NULL,
+ host_id INT DEFAULT NULL,
+ 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
+--
+
+CREATE TABLE ipv6_reservations (
+ reservation_id SERIAL PRIMARY KEY NOT NULL,
+ address VARCHAR(39) NOT NULL,
+ prefix_len SMALLINT NOT NULL DEFAULT '128',
+ 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
+);
+
+CREATE INDEX fk_ipv6_reservations_host_idx ON ipv6_reservations (host_id);
+
+--
+-- Table structure for table lease_hwaddr_source
+--
+
+CREATE TABLE lease_hwaddr_source (
+ hwaddr_source INT PRIMARY KEY NOT NULL,
+ name VARCHAR(40) DEFAULT NULL
+);
+
+-- 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');
+
+-- Hardware address obtained from raw sockets
+INSERT INTO lease_hwaddr_source VALUES (1, 'HWADDR_SOURCE_RAW');
+
+-- Hardware address converted from IPv6 link-local address with EUI-64
+INSERT INTO lease_hwaddr_source VALUES (2, 'HWADDR_SOURCE_IPV6_LINK_LOCAL');
+
+-- Hardware address extracted from client-id (duid)
+INSERT INTO lease_hwaddr_source VALUES (4, 'HWADDR_SOURCE_DUID');
+
+-- Hardware address extracted from client address relay option (RFC6939)
+INSERT INTO lease_hwaddr_source VALUES (8, 'HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION');
+
+-- Hardware address extracted from remote-id option (RFC4649)
+INSERT INTO lease_hwaddr_source VALUES (16, 'HWADDR_SOURCE_REMOTE_ID');
+
+-- Hardware address extracted from subscriber-id option (RFC4580)
+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_CMTS');
+
+INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
+
+-- Adding ORDER BY clause to sort by lease address
+--
+-- FUNCTION that returns a result set containing the data for lease4 dumps
+DROP FUNCTION IF EXISTS lease4DumpData();
+CREATE FUNCTION lease4DumpData() RETURNS
+ table (address inet,
+ hwaddr text,
+ client_id text,
+ valid_lifetime bigint,
+ expire timestamp with time zone,
+ subnet_id bigint,
+ fqdn_fwd int,
+ fqdn_rev int,
+ hostname text,
+ state text
+ ) as \$\$
+ SELECT ('0.0.0.0'::inet + l.address),
+ encode(l.hwaddr,'hex'),
+ encode(l.client_id,'hex'),
+ l.valid_lifetime,
+ l.expire,
+ l.subnet_id,
+ l.fqdn_fwd::int,
+ l.fqdn_rev::int,
+ l.hostname,
+ s.name
+ FROM lease4 l
+ left outer join lease_state s on (l.state = s.state)
+ ORDER BY l.address;
+\$\$ LANGUAGE SQL;
+--
+
+-- Add new columns to lease6
+ALTER TABLE lease6
+ ADD COLUMN hwaddr BYTEA DEFAULT NULL,
+ ADD COLUMN hwtype SMALLINT DEFAULT NULL,
+ ADD COLUMN hwaddr_source SMALLINT DEFAULT NULL;
+
+--
+-- FUNCTION that returns a result set containing the column names for lease6 dumps
+DROP FUNCTION IF EXISTS lease6DumpHeader();
+CREATE FUNCTION lease6DumpHeader() RETURNS text AS \$\$
+ select cast('address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state,hwaddr,hwtype,hwaddr_source' as text) as result;
+\$\$ LANGUAGE SQL;
+--
+
+--
+-- FUNCTION that returns a result set containing the data for lease6 dumps
+DROP FUNCTION IF EXISTS lease6DumpData();
+CREATE FUNCTION lease6DumpData() RETURNS
+ TABLE (
+ address text,
+ duid text,
+ valid_lifetime bigint,
+ expire timestamp with time zone,
+ subnet_id bigint,
+ pref_lifetime bigint,
+ name text,
+ iaid integer,
+ prefix_len smallint,
+ fqdn_fwd int,
+ fqdn_rev int,
+ hostname text,
+ state text,
+ hwaddr text,
+ hwtype smallint,
+ hwaddr_source text
+ ) AS \$\$
+ SELECT (l.address,
+ encode(l.duid,'hex'),
+ l.valid_lifetime,
+ l.expire,
+ l.subnet_id,
+ l.pref_lifetime,
+ t.name,
+ l.iaid,
+ l.prefix_len,
+ l.fqdn_fwd::int,
+ l.fqdn_rev::int,
+ l.hostname,
+ s.name,
+ encode(l.hwaddr,'hex'),
+ l.hwtype,
+ h.name
+ )
+ FROM lease6 l
+ left outer join lease6_types t on (l.lease_type = t.lease_type)
+ left outer join lease_state s on (l.state = s.state)
+ left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source)
+ ORDER BY l.address;
+\$\$ LANGUAGE SQL;
+
+-- Add columns holding reservations for siaddr, sname and file fields
+-- carried within DHCPv4 message.
+ALTER TABLE hosts ADD COLUMN dhcp4_next_server BIGINT DEFAULT NULL;
+ALTER TABLE hosts ADD COLUMN dhcp4_server_hostname VARCHAR(64) DEFAULT NULL;
+ALTER TABLE hosts ADD COLUMN dhcp4_boot_file_name VARCHAR(128) DEFAULT NULL;
+
+-- Set 3.0 schema version.
+UPDATE schema_version
+ SET version = '3', minor = '0';
+
+-- Schema 3.0 specification ends here.
+
+-- Commit the script transaction
+COMMIT;
+
+EOF