Commit 67e12a02 authored by Thomas Markwalder's avatar Thomas Markwalder
Browse files

[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
parent 3004ceae
address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state
12,21,30,<timestamp3>,40,50,IA_TA,60,70,1,1,three.example.com,expired-reclaimed
11,,30,<timestamp2>,40,50,IA_TA,60,70,1,1,,declined
10,20,30,<timestamp1>,40,50,IA_TA,60,70,1,1,one.example.com,default
address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state,hwaddr,hwtype,hwaddr_source
10,20,30,<timestamp1>,40,50,IA_TA,60,70,1,1,one.example.com,default,80,90,HWADDR_SOURCE_REMOTE_ID
11,,30,<timestamp2>,40,50,IA_TA,60,70,1,1,,declined,80,90,HWADDR_SOURCE_RAW
12,21,30,<timestamp3>,40,50,IA_TA,60,70,1,1,three.example.com,expired-reclaimed,80,90,HWADDR_SOURCE_DUID
......@@ -88,7 +88,7 @@ pgsql_lease_version_test() {
# Verfiy that kea-admin lease-version returns the correct version
version=$(${keaadmin} lease-version pgsql -u $db_user -p $db_password -n $db_name)
assert_str_eq "2.0" ${version} "Expected kea-admin to return %s, returned value was %s"
assert_str_eq "3.0" ${version} "Expected kea-admin to return %s, returned value was %s"
# Let's wipe the whole database
pgsql_wipe
......@@ -297,9 +297,9 @@ pgsql_lease6_dump_test() {
# Insert the reference records
insert_sql="\
insert into lease6 values(10,E'\\x20',30,'$timestamp1',40,50,1,60,70,'t','t','one.example.com', 0);\
insert into lease6 values(11,'',30,'$timestamp2',40,50,1,60,70,'t','t','', 1);\
insert into lease6 values(12,E'\\x21',30,'$timestamp3',40,50,1,60,70,'t','t','three.example.com', 2);"
insert into lease6 values(10,E'\\x20',30,'$timestamp1',40,50,1,60,70,'t','t','one.example.com', 0,decode('80','hex'),90,16);\
insert into lease6 values(11,'',30,'$timestamp2',40,50,1,60,70,'t','t','', 1,decode('80','hex'),90,1);\
insert into lease6 values(12,E'\\x21',30,'$timestamp3',40,50,1,60,70,'t','t','three.example.com', 2,decode('80','hex'),90,4);"
pgsql_execute "$insert_sql"
ERRCODE=$?
......
......@@ -704,6 +704,14 @@ PgSqlLeaseMgr::PgSqlLeaseMgr(const DatabaseConnection::ParameterMap& parameters)
isc_throw(DbOpenError, "Number of statements prepared: " << i
<< " does not match expected count:" << NUM_STATEMENTS);
}
pair<uint32_t, uint32_t> code_version(PG_CURRENT_VERSION, PG_CURRENT_MINOR);
pair<uint32_t, uint32_t> db_version = getVersion();
if (code_version != db_version) {
isc_throw(DbOpenError, "Posgresql schema version mismatch: need version: "
<< code_version.first << "." << code_version.second
<< " found version: " << db_version.first << "." << db_version.second);
}
}
PgSqlLeaseMgr::~PgSqlLeaseMgr() {
......
......@@ -26,7 +26,7 @@ class PgSqlLease4Exchange;
class PgSqlLease6Exchange;
/// Defines PostgreSQL backend version: 2.0
const uint32_t PG_CURRENT_VERSION = 2;
const uint32_t PG_CURRENT_VERSION = 3;
const uint32_t PG_CURRENT_MINOR = 0;
/// @brief PostgreSQL Lease Manager
......
......@@ -237,6 +237,217 @@ 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
......
......@@ -9,6 +9,11 @@ DROP TABLE IF EXISTS lease6 CASCADE;
DROP TABLE IF EXISTS lease6_types CASCADE;
DROP TABLE IF EXISTS schema_version CASCADE;
DROP TABLE IF EXISTS lease_state CASCADE;
DROP TABLE IF EXISTS dhcp4_options CASCADE;
DROP TABLE IF EXISTS dhcp6_options CASCADE;
DROP TABLE IF EXISTS ipv6_reservations CASCADE;
DROP TABLE IF EXISTS lease_hwaddr_source CASCADE;
DROP TABLE IF EXISTS hosts CASCADE;
DROP FUNCTION IF EXISTS lease4DumpHeader();
DROP FUNCTION IF EXISTS lease4DumpData();
DROP FUNCTION IF EXISTS lease6DumpHeader();
......
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment