From: Thomas Markwalder Date: Tue, 20 Oct 2015 12:36:14 +0000 (-0400) Subject: [3969] Added upgrade support from Postgres schema 1.0 to 2.0 X-Git-Tag: fdfb_base~6^2~1^2~1 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=49b0bac2763bd50e795ee21a2b922c8046f08908;p=thirdparty%2Fkea.git [3969] Added upgrade support from Postgres schema 1.0 to 2.0 Upgrade adds state column to both lease tables, the state table, and the lease dump functions. src/bin/admin/scripts/pgsql/upgrade_1.0_to_2.0.sh - new script for upgrading postgres schema src/bin/admin/tests/dhcpdb_create_1.0.pgsql new sql script for creating 1.0 schema db configure.ac added entry for new upgrade script src/bin/admin/kea-admin.in pgsql_upgrade() - modified to set Postgres password env variable and pass in remaining args as psql expects them src/bin/admin/scripts/pgsql/Makefile.am added entry for new upgrade script src/bin/admin/tests/Makefile.am added entry for 1.0 schema script src/bin/admin/tests/pgsql_tests.sh.in pgsql_upgrade_test() - revamped now that Postgres actually has its first upgrade script. --- diff --git a/configure.ac b/configure.ac index 038d2dce12..6207f9948a 100755 --- a/configure.ac +++ b/configure.ac @@ -1414,6 +1414,7 @@ AC_CONFIG_FILES([compatcheck/Makefile src/bin/admin/scripts/mysql/upgrade_2.0_to_3.0.sh src/bin/admin/scripts/mysql/upgrade_3.0_to_4.0.sh src/bin/admin/scripts/pgsql/Makefile + src/bin/admin/scripts/pgsql/upgrade_1.0_to_2.0.sh src/hooks/Makefile src/hooks/dhcp/Makefile src/hooks/dhcp/user_chk/Makefile diff --git a/src/bin/admin/kea-admin.in b/src/bin/admin/kea-admin.in index c181d18ec5..5abc0fb600 100644 --- a/src/bin/admin/kea-admin.in +++ b/src/bin/admin/kea-admin.in @@ -275,10 +275,14 @@ pgsql_upgrade() { exit 1 fi + # Postgres psql does not accept pw on command line, but can do it + # thru an env + export PGPASSWORD=$db_password + for script in ${scripts_dir}/pgsql/upgrade*.sh do echo "Processing $script file..." - sh ${script} --user=${db_user} --password=${db_password} ${db_name} + sh ${script} -U ${db_user} -d ${db_name} done version=`pgsql_version` diff --git a/src/bin/admin/scripts/pgsql/Makefile.am b/src/bin/admin/scripts/pgsql/Makefile.am index f148dfd614..1cefa26c26 100644 --- a/src/bin/admin/scripts/pgsql/Makefile.am +++ b/src/bin/admin/scripts/pgsql/Makefile.am @@ -2,5 +2,6 @@ SUBDIRS = . sqlscriptsdir = ${datarootdir}/${PACKAGE_NAME}/scripts/pgsql sqlscripts_DATA = dhcpdb_create.pgsql +sqlscripts_DATA += upgrade_1.0_to_2.0.sh -EXTRA_DIST = dhcpdb_create.pgsql +EXTRA_DIST = ${sqlscripts_DATA} diff --git a/src/bin/admin/scripts/pgsql/upgrade_1.0_to_2.0.sh.in b/src/bin/admin/scripts/pgsql/upgrade_1.0_to_2.0.sh.in new file mode 100644 index 0000000000..22d6af4d82 --- /dev/null +++ b/src/bin/admin/scripts/pgsql/upgrade_1.0_to_2.0.sh.in @@ -0,0 +1,157 @@ +#!/bin/sh + +# 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" != "1.0" ]; then + printf "This script upgrades 1.0 to 2.0. Reported version is $VERSION. Skipping upgrade.\n" + exit 0 +fi + +psql "$@" >/dev/null < -W < 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; + +-- 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. diff --git a/src/bin/admin/tests/pgsql_tests.sh.in b/src/bin/admin/tests/pgsql_tests.sh.in index a42d37c7aa..43e04b9d37 100644 --- a/src/bin/admin/tests/pgsql_tests.sh.in +++ b/src/bin/admin/tests/pgsql_tests.sh.in @@ -122,12 +122,35 @@ pgsql_upgrade_test() { # Wipe the whole database pgsql_wipe - # Create the database - ${keaadmin} lease-init pgsql -u $db_user -p $db_password -n $db_name -d $scripts_dir + # Initialize database to scheme 1.0. + pgsql_execute_script @abs_top_srcdir@/src/bin/admin/tests/dhcpdb_create_1.0.pgsql assert_eq 0 $? "cannot initialize the database, expected exit code: %d, actual: %d" ${keaadmin} lease-upgrade pgsql -u $db_user -p $db_password -n $db_name -d $scripts_dir - assert_eq 1 $? "lease-upgrade should have failed, expected exit code: %d, actual: %d" + assert_eq 0 $? "lease-upgrade failed, expected exit code: %d, actual: %d" + + #table: state column added to lease4 (upgrade 1.0 -> 2.0) + output=`pgsql_execute "SELECT state from lease4;"` + ERRCODE=$? + assert_eq 0 $ERRCODE "lease4 is missing state column. (returned status code %d, expected %d)" + + #table: state column added to lease6 (upgrade 1.0 -> 2.0) + output=`pgsql_execute "SELECT state from lease6;"` + ERRCODE=$? + assert_eq 0 $ERRCODE "lease6 is missing state column. (returned status code %d, expected %d)" + + #table: stored procedures for lease dumps added (upgrade 1.0 -> 2.0) + output=`pgsql_execute "select lease4DumpHeader from lease4DumpHeader();"` + assert_eq 0 $ERRCODE "function lease4DumpHeader() broken or missing. (returned status code %d, expected %d)" + + output=`pgsql_execute "select address from lease4DumpData();"` + assert_eq 0 $ERRCODE "function lease4DumpData() broken or missing. (returned status code %d, expected %d)" + + output=`pgsql_execute "select lease6DumpHeader from lease6DumpHeader();"` + assert_eq 0 $ERRCODE "function lease6DumpHeader() broken or missing. (returned status code %d, expected %d)" + + output=`pgsql_execute "select address from lease6DumpData();"` + assert_eq 0 $ERRCODE "function lease6DumpData() broken or missing. (returned status code %d, expected %d)" # Let's wipe the whole database pgsql_wipe