2
0
mirror of https://gitlab.isc.org/isc-projects/kea synced 2025-09-05 08:25:16 +00:00
Files
kea/src/share/database/scripts/pgsql/dhcpdb_create.pgsql
Thomas Markwalder 67e12a028b [4275] Brought Postgresql schema up to MySQL 4.1 content
Postresql schema now supports host reservations with options,
and lease6 table now includes hardware address and source

src/share/database/scripts/pgsql/dhcpdb_create.pgsql
    Added Schema 3.0 upgrade section:
    - new tables: hosts, dhcp4_options, dhcp6_options,
      ipv6_reservations, lease_hwaddr_source

    - lease4Dumpdata() - results now sorted by lease address

    - lease6 table - added columns hwaddr, hwtype, hwaddr_source

    - lease6DumpHeader() - added labels for new columns
    - lease6DumpData() - added new columns, results now sorted by
      lease address

    - schema_vesion - bumped version to 3

src/share/database/scripts/pgsql/dhcpdb_drop.pgsql
    Added drops of new tables

src/lib/dhcpsrv/pgsql_lease_mgr.cc
    - PgSqlLeaseMgr::PgSqlLeaseMgr() - added logic to detect schema
    mismatch between the code and configured database

src/lib/dhcpsrv/pgsql_lease_mgr.h
    - Bumped PG_CURRENT_VERSION from 2 to 3

src/bin/admin/tests/data/pgsql.lease6_dump_test.reference.csv
    - Reordered entries to account for dump function sort order
    - Added values for new columns on lease6 table

src/bin/admin/tests/pgsql_tests.sh.in
    - pgsql_lease_version_test() - changed expected version to 3.0
    - pgsql_lease6_dump_test() - added new column values to inserted rows
2016-06-14 15:51:08 -04:00

478 lines
16 KiB
PL/PgSQL

-- Copyright (C) 2012-2016 Internet Systems Consortium.
-- 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/.
-- This is the Kea DHCP schema specification for PostgreSQL.
-- The schema is reasonably portable (with the exception of some field types
-- specification, which are PostgreSQL-specific). Minor changes might be needed
-- for other databases.
-- To create the schema, either type the command:
-- psql -U <user> -W <password> <database> < dhcpdb_create.pgsql
-- ... at the command prompt, or log in to the PostgreSQL database and at the "postgres=#"
-- prompt, issue the command:
-- @dhcpdb_create.pgsql
-- Holds the IPv4 leases.
CREATE TABLE lease4 (
address BIGINT PRIMARY KEY NOT NULL, -- IPv4 address
hwaddr BYTEA, -- Hardware address
client_id BYTEA, -- Client ID
valid_lifetime BIGINT, -- Length of the lease (seconds)
expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
subnet_id BIGINT, -- Subnet identification
fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
hostname VARCHAR(255) -- The FQDN of the client
);
-- Create search indexes for lease4 table
-- index by hwaddr and subnet_id
CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
-- index by client_id and subnet_id
CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
-- Holds the IPv6 leases.
-- N.B. The use of a VARCHAR for the address is temporary for development:
-- it will eventually be replaced by BINARY(16).
CREATE TABLE lease6 (
address VARCHAR(39) PRIMARY KEY NOT NULL, -- IPv6 address
duid BYTEA, -- DUID
valid_lifetime BIGINT, -- Length of the lease (seconds)
expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
subnet_id BIGINT, -- Subnet identification
pref_lifetime BIGINT, -- Preferred lifetime
lease_type SMALLINT, -- Lease type (see lease6_types
-- table for possible values)
iaid INT, -- See Section 10 of RFC 3315
prefix_len SMALLINT, -- For IA_PD only
fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
hostname VARCHAR(255) -- The FQDN of the client
);
-- Create search indexes for lease4 table
-- index by iaid, subnet_id, and duid
CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
-- ... and a definition of lease6 types. This table is a convenience for
-- users of the database - if they want to view the lease table and use the
-- type names, they can join this table with the lease6 table
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
-- (related to the names of the columns in the BIND 10 DNS database file), the
-- first column is called "version" and not "major".
-- NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
-- which defines the schema for the unit tests. If you are updating
-- the version number, the schema has changed: please ensure that
-- schema_copy.h has been updated as well.
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.
--
-- Add state column to the lease4 table.
ALTER TABLE lease4
ADD COLUMN state INT8 DEFAULT 0;
-- Add state column to the lease6 table.
ALTER TABLE lease6
ADD COLUMN state INT8 DEFAULT 0;
-- Create indexes for querying leases in a given state and segregated
-- by the expiration time. One of the applications is to retrieve all
-- expired leases. However, these indexes can be also used to retrieve
-- leases in a given state regardless of the expiration time.
CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
-- Create table holding mapping of the lease states to their names.
-- This is not used in queries from the DHCP server but rather in
-- direct queries from the lease database management tools.
CREATE TABLE lease_state (
state INT8 PRIMARY KEY NOT NULL,
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.
ALTER TABLE lease4
ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
REFERENCES lease_state (state);
-- Add a constraint that any state value added to the lease6 must
-- map to a value in the lease_state table.
ALTER TABLE lease6
ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
REFERENCES lease_state (state);
-- Add a constraint that lease type in the lease6 table must map
-- to a lease type defined in the lease6_types table.
ALTER TABLE lease6
ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
REFERENCES lease6_types (lease_type);
--
-- FUNCTION that returns a result set containing the column names for lease4 dumps
DROP FUNCTION IF EXISTS lease4DumpHeader();
CREATE FUNCTION lease4DumpHeader() RETURNS text AS $$
select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state' as text) as result;
$$ LANGUAGE SQL;
--
--
-- 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);
$$ LANGUAGE SQL;
--
--
-- 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' 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
) 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)
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);
$$ 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
--
DROP TABLE IF EXISTS hosts;
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
);
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);
--
-- 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,
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,
CONSTRAINT fk_options_host1 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
);
CREATE INDEX fk_dhcp4_options_host1_idx ON dhcp4_options (host_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,
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,
CONSTRAINT fk_options_host10 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
);
CREATE INDEX fk_dhcp6_options_host1_idx ON dhcp6_options (host_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,
prefix_len SMALLINT NOT NULL DEFAULT '128',
type SMALLINT NOT NULL DEFAULT '0',
dhcp6_iaid INT DEFAULT NULL,
host_id INT NOT NULL,
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
--
DROP TABLE IF EXISTS lease_hwaddr_source;
CREATE TABLE lease_hwaddr_source (
hwaddr_source INT PRIMARY KEY NOT NULL,
name VARCHAR(40) DEFAULT NULL
);
-- 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');
-- 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;
--
-- Set 3.0 schema version.
START TRANSACTION;
UPDATE schema_version
SET version = '3', minor = '0';
COMMIT;
-- Notes:
-- Indexes
-- =======
-- It is likely that additional indexes will be needed. However, the
-- increase in lookup performance from these will come at the expense
-- of a decrease in performance during insert operations due to the need
-- to update the indexes. For this reason, the need for additional indexes
-- will be determined by experiment during performance tests.
-- The most likely additional indexes will cover the following columns:
-- hwaddr and client_id
-- For lease stability: if a client requests a new lease, try to find an
-- existing or recently expired lease for it so that it can keep using the
-- same IP address.
-- Field Sizes
-- ===========
-- If any of the VARxxx field sizes are altered, the lengths in the PgSQL
-- backend source file (pgsql_lease_mgr.cc) must be correspondingly changed.
-- Portability
-- ===========
-- Some columns contain binary data so are stored as BYTEA instead of
-- VARCHAR. This may be non-portable between databases: in this case, the
-- definition should be changed to VARCHAR.