# and protocol
get_dump_query() {
local version=$1
- local dump_sql_file="$scripts_dir/${backend}/lease_dump_$version.sh"
- dump_qry=""
case ${backend} in
mysql)
- if [ ! -e $dump_sql_file ]
- then
- log_error "lease-dump: cannot access dump_sql_file: $dump_sql_file"
- exit 1;
- fi
-
- # source in the dump file which defines the sql text we'll need
- . $dump_sql_file
- if [ $? -ne 0 ]
- then
- log_error "lease-dump: error sourcing dump_sql_file: $dump_sql_file"
- exit 1
- fi
- # Construct the SQL text to dump the leases based on protocol type
- case ${dump_type} in
- 4)
- dump_qry="$lease4_dump_sql";
- ;;
- 6)
- dump_qry="$lease6_dump_sql";
- ;;
- *)
- log_error "you must specify -4 or -6 for lease-dump"
- usage
- exit 1
- ;;
- esac
+ invoke="call"
;;
-
pgsql)
- # Construct the SQL text to dump the leases based on protocol type
- case ${dump_type} in
- 4)
- dump_qry="select * from lease4DumpHeader();select * from lease4DumpData()";
- ;;
- 6)
- dump_qry="select * from lease6DumpHeader();select * from lease6DumpData()";
- ;;
- *)
- log_error "you must specify -4 or -6 for lease-dump"
- usage
- exit 1
- ;;
- esac
+ invoke="select * from"
;;
*)
log_error "unsupported backend ${backend}"
;;
esac
- if [ "$dump_qry" = "" ]
- then
- log_error "lease-dump: dump query appears to be undefined"
- exit 1
- fi
+ dump_qry="${invoke} lease${dump_type}DumpHeader();${invoke} lease${dump_type}DumpData();";
}
memfile_dump() {
SUBDIRS = .
sqlscriptsdir = ${datarootdir}/${PACKAGE_NAME}/scripts/mysql
-sqlscripts_DATA = dhcpdb_create.mysql upgrade_1.0_to_2.0.sh upgrade_2.0_to_3.0.sh lease_dump_1.0.sh lease_dump_2.0.sh lease_dump_3.0.sh
+sqlscripts_DATA = dhcpdb_create.mysql upgrade_1.0_to_2.0.sh upgrade_2.0_to_3.0.sh
-EXTRA_DIST = dhcpdb_create.mysql upgrade_1.0_to_2.0.sh upgrade_2.0_to_3.0.sh lease_dump_1.0.sh lease_dump_2.0.sh lease_dump_3.0.sh
+EXTRA_DIST = dhcpdb_create.mysql upgrade_1.0_to_2.0.sh upgrade_2.0_to_3.0.sh
) ENGINE = INNODB;
-# Create search indexes for lease4 table
+# Create search indexes for lease4 table
# index by hwaddr and subnet_id
CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
INSERT INTO lease_state VALUES (1, "declined");
INSERT INTO lease_state VALUES (2, "expired-reclaimed");
+# FUNCTION that returns a result set containing the column names for lease4 dumps
+DROP PROCEDURE IF EXISTS lease4DumpHeader;
+DELIMITER $$
+CREATE PROCEDURE lease4DumpHeader()
+BEGIN
+SELECT 'address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state';
+END $$
+DELIMITER ;
+
+# FUNCTION that returns a result set containing the data for lease4 dumps
+DROP PROCEDURE IF EXISTS lease4DumpData;
+DELIMITER $$
+CREATE PROCEDURE lease4DumpData()
+BEGIN
+SELECT
+ INET_NTOA(l.address),
+ IFNULL(HEX(l.hwaddr), ''),
+ IFNULL(HEX(l.client_id), ''),
+ l.valid_lifetime,
+ l.expire,
+ l.subnet_id,
+ l.fqdn_fwd,
+ l.fqdn_rev,
+ l.hostname,
+ s.name
+from
+ lease4 l
+ LEFT OUTER JOIN lease_state s on (l.state = s.state);
+END $$
+DELIMITER ;
+
+# FUNCTION that returns a result set containing the column names for lease6 dumps
+DROP PROCEDURE IF EXISTS lease6DumpHeader;
+DELIMITER $$
+CREATE PROCEDURE lease6DumpHeader()
+BEGIN
+SELECT 'address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,hwaddr,hwtype,hwaddr_source,state';
+END $$
+DELIMITER ;
+
+# FUNCTION that returns a result set containing the data for lease6 dumps
+DROP PROCEDURE IF EXISTS lease6DumpData;
+DELIMITER $$
+CREATE PROCEDURE lease6DumpData()
+BEGIN
+SELECT
+ l.address,
+ IFNULL(HEX(l.duid), ''),
+ l.valid_lifetime,
+ l.expire,
+ l.subnet_id,
+ l.pref_lifetime,
+ IFNULL(t.name, ''),
+ l.iaid,
+ l.prefix_len,
+ l.fqdn_fwd,
+ l.fqdn_rev,
+ l.hostname,
+ IFNULL(HEX(l.hwaddr), ''),
+ IFNULL(l.hwtype, ''),
+ IFNULL(l.hwaddr_source, ''),
+ IFNULL(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);
+END $$
+DELIMITER ;
+
+# Update the schema version number
UPDATE schema_version
SET version = '4', minor = '0';
# This line concludes database upgrade to version 4.0.
+++ /dev/null
-#!/bin/sh
-# Copyright (C) 2015 Internet Systems Consortium.
-#
-# Permission to use, copy, modify, and distribute this software for any
-# purpose with or without fee is hereby granted, provided that the above
-# copyright notice and this permission notice appear in all copies.
-#
-# THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
-# DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
-# IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
-# INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
-# INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
-# FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
-# NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
-# WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
-#
-# Specifies the MySQL sql for schema-version 1.0 required to produce
-# lease output that includes a header row containing column names,
-# followed by the lease data. The text is used in a single call
-# to the mysql command line tool.
-
-# SQL for DHCPv4 leases
-lease4_dump_sql="\
-SELECT 'address', 'hwaddr', 'client_id', 'valid_lifetime', 'expire',\
-'subnet_id', 'fqdn_fwd', 'fqdn_rev', 'hostname';\
-SELECT INET_NTOA(address), IFNULL(HEX(hwaddr), ''), IFNULL(HEX(client_id), ''),\
-valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname from lease4"
-
-# SQL for DHCPv6 leases
-lease6_dump_sql="\
-SELECT 'address', 'duid', 'valid_lifetime', 'expire',\
-'subnet_id', 'pref_lifetime', 'lease_type', 'iaid', 'prefix_len', 'fqdn_fwd',\
-'fqdn_rev', 'hostname';\
-SELECT a.address, IFNULL(HEX(a.duid), ''), a.valid_lifetime,\
-a.expire, a.subnet_id, a.pref_lifetime, IFNULL(b.name, ''), a.iaid, a.prefix_len,\
-a.fqdn_fwd, a.fqdn_rev, hostname \
-FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type)"
+++ /dev/null
-#!/bin/sh
-# Copyright (C) 2015 Internet Systems Consortium.
-#
-# Permission to use, copy, modify, and distribute this software for any
-# purpose with or without fee is hereby granted, provided that the above
-# copyright notice and this permission notice appear in all copies.
-#
-# THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
-# DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
-# IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
-# INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
-# INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
-# FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
-# NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
-# WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
-#
-# Specifies the MySQL sql for schema-version 2.0 required to produce
-# lease output that includes a header row containing column names,
-# followed by the lease data. The text is used in a single call
-# to the mysql command line tool.
-
-# SQL for DHCPv4 leases
-lease4_dump_sql="\
-SELECT 'address', 'hwaddr', 'client_id', 'valid_lifetime', 'expire',\
-'subnet_id', 'fqdn_fwd', 'fqdn_rev', 'hostname';\
-SELECT INET_NTOA(address), IFNULL(HEX(hwaddr), ''), IFNULL(HEX(client_id), ''),\
-valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname from lease4"
-
-# SQL for DHCPv6 leases
-lease6_dump_sql="\
-SELECT 'address', 'duid', 'valid_lifetime', 'expire',\
-'subnet_id', 'pref_lifetime', 'lease_type', 'iaid', 'prefix_len', 'fqdn_fwd',\
-'fqdn_rev', 'hostname', 'hwaddr', 'hwtype', 'hwaddr_source';\
-SELECT a.address, IFNULL(HEX(a.duid), ''), a.valid_lifetime,\
-a.expire, a.subnet_id, a.pref_lifetime, IFNULL(b.name, ''), a.iaid, a.prefix_len,\
-a.fqdn_fwd, a.fqdn_rev, hostname, IFNULL(HEX(hwaddr), ''), IFNULL(hwtype, ''),\
-IFNULL(hwaddr_source, '') \
-FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type)"
+++ /dev/null
-#!/bin/sh
-# Copyright (C) 2015 Internet Systems Consortium.
-#
-# Permission to use, copy, modify, and distribute this software for any
-# purpose with or without fee is hereby granted, provided that the above
-# copyright notice and this permission notice appear in all copies.
-#
-# THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
-# DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
-# IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
-# INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
-# INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
-# FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
-# NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
-# WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
-#
-# Specifies the MySQL sql for schema-version 3.0 required to produce
-# lease output that includes a header row containing column names,
-# followed by the lease data. The text is used in a single call
-# to the mysql command line tool.
-
-# SQL for DHCPv4 leases
-lease4_dump_sql="\
-SELECT 'address', 'hwaddr', 'client_id', 'valid_lifetime', 'expire',\
-'subnet_id', 'fqdn_fwd', 'fqdn_rev', 'hostname';\
-SELECT INET_NTOA(address), IFNULL(HEX(hwaddr), ''), IFNULL(HEX(client_id), ''),\
-valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname from lease4"
-
-# SQL for DHCPv6 leases
-lease6_dump_sql="\
-SELECT 'address', 'duid', 'valid_lifetime', 'expire',\
-'subnet_id', 'pref_lifetime', 'lease_type', 'iaid', 'prefix_len', 'fqdn_fwd',\
-'fqdn_rev', 'hostname', 'hwaddr', 'hwtype', 'hwaddr_source';\
-SELECT a.address, IFNULL(HEX(a.duid), ''), a.valid_lifetime,\
-a.expire, a.subnet_id, a.pref_lifetime, IFNULL(b.name, ''), a.iaid, a.prefix_len,\
-a.fqdn_fwd, a.fqdn_rev, hostname, IFNULL(HEX(hwaddr), ''), IFNULL(hwtype, ''),\
-IFNULL(hwaddr_source, '') \
-FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type)"
+++ /dev/null
-#!/bin/sh
-# Copyright (C) 2015 Internet Systems Consortium.
-#
-# Permission to use, copy, modify, and distribute this software for any
-# purpose with or without fee is hereby granted, provided that the above
-# copyright notice and this permission notice appear in all copies.
-#
-# THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
-# DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
-# IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
-# INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
-# INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
-# FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
-# NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
-# WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
-#
-# Specifies the MySQL sql for schema-version 4.0 required to produce
-# lease output that includes a header row containing column names,
-# followed by the lease data. The text is used in a single call
-# to the mysql command line tool.
-
-# SQL for DHCPv4 leases
-lease4_dump_sql="\
-SELECT 'address', 'hwaddr', 'client_id', 'valid_lifetime', 'expire',\
-'subnet_id', 'fqdn_fwd', 'fqdn_rev', 'hostname', 'state';\
-SELECT INET_NTOA(address), IFNULL(HEX(hwaddr), ''), IFNULL(HEX(client_id), ''),\
-valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname, state from lease4"
-
-# SQL for DHCPv6 leases
-lease6_dump_sql="\
-SELECT 'address', 'duid', 'valid_lifetime', 'expire',\
-'subnet_id', 'pref_lifetime', 'lease_type', 'iaid', 'prefix_len', 'fqdn_fwd',\
-'fqdn_rev', 'hostname', 'hwaddr', 'hwtype', 'hwaddr_source', 'state';\
-SELECT a.address, IFNULL(HEX(a.duid), ''), a.valid_lifetime,\
-a.expire, a.subnet_id, a.pref_lifetime, IFNULL(b.name, ''), a.iaid, a.prefix_len,\
-a.fqdn_fwd, a.fqdn_rev, hostname, IFNULL(HEX(hwaddr), ''), IFNULL(hwtype, ''),\
-IFNULL(hwaddr_source, ''), state \
-FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type)"
fqdn_rev int,
hostname text
) AS $$
- SELECT (a.address,
- encode(a.duid,'hex'),
- a.valid_lifetime,
- a.expire,
- a.subnet_id,
- a.pref_lifetime,
- b.name,
- a.iaid,
- a.prefix_len,
- a.fqdn_fwd::int,
- a.fqdn_rev::int,
- a.hostname)
- FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type);
+ 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)
+ FROM lease6 l left outer join lease6_types t on (l.lease_type = t.lease_type);
$$ LANGUAGE SQL;
--
address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state
-0.0.0.10,3230,3330,40,2015-01-01 01:15:30,50,1,1,one.example.com,0
-0.0.0.11,,313233,40,2015-02-02 02:30:45,50,1,1,,0
-0.0.0.12,3232,,40,2015-03-03 11:01:07,50,1,1,three.example.com,0
+0.0.0.10,3230,3330,40,2015-01-01 01:15:30,50,1,1,one.example.com,default
+0.0.0.11,,313233,40,2015-02-02 02:30:45,50,1,1,,declined
+0.0.0.12,3232,,40,2015-03-03 11:01:07,50,1,1,three.example.com,expired-reclaimed
address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,hwaddr,hwtype,hwaddr_source,state
-10,3230,30,2015-04-04 01:15:30,40,50,IA_TA,60,70,1,1,one.example.com,3830,90,100,0
-11,,30,2015-05-05 02:30:45,40,50,IA_TA,60,70,1,1,,3830,90,100,0
-12,3231,30,2015-06-06 11:01:07,40,50,IA_TA,60,70,1,1,three.example.com,3830,90,100,0
+10,3230,30,2015-04-04 01:15:30,40,50,IA_TA,60,70,1,1,one.example.com,3830,90,100,default
+11,,30,2015-05-05 02:30:45,40,50,IA_TA,60,70,1,1,,3830,90,100,declined
+12,3231,30,2015-06-06 11:01:07,40,50,IA_TA,60,70,1,1,three.example.com,3830,90,100,expired-reclaimed
# Insert the reference record
insert_sql="\
insert into lease4 values(10,20,30,40,\"2015-01-01 01:15:30\",50,1,1,\"one.example.com\", 0);\
-insert into lease4 values(11,NULL,123,40,\"2015-02-02 02:30:45\",50,1,1,\"\", 0);\
-insert into lease4 values(12,22,NULL,40,\"2015-03-03 11:01:07\",50,1,1,\"three.example.com\", 0);"
+insert into lease4 values(11,NULL,123,40,\"2015-02-02 02:30:45\",50,1,1,\"\", 1);\
+insert into lease4 values(12,22,NULL,40,\"2015-03-03 11:01:07\",50,1,1,\"three.example.com\", 2);"
mysql_execute "$insert_sql"
ERRCODE=$?
# Insert the reference record
insert_sql="\
insert into lease6 values(10,20,30,\"2015-04-04 01:15:30\",40,50,1,60,70,1,1,\"one.example.com\",80,90,100, 0);\
-insert into lease6 values(11,NULL,30,\"2015-05-05 02:30:45\",40,50,1,60,70,1,1,\"\",80,90,100, 0);\
-insert into lease6 values(12,21,30,\"2015-06-06 11:01:07\",40,50,1,60,70,1,1,\"three.example.com\",80,90,100, 0);"
+insert into lease6 values(11,NULL,30,\"2015-05-05 02:30:45\",40,50,1,60,70,1,1,\"\",80,90,100, 1);\
+insert into lease6 values(12,21,30,\"2015-06-06 11:01:07\",40,50,1,60,70,1,1,\"three.example.com\",80,90,100, 2);"
mysql_execute "$insert_sql"
ERRCODE=$?