Browse Source

[3916] Use stored functions for Postgres lease dumps

lease_dump_1.0.sh - deleted, now obsolete

src/bin/admin/scripts/pgsql/Makefile.am
    removed entries for lease_dump_1.0.sh

src/bin/admin/kea-admin.in
    get_dump_query() - modified SQL text returned for Postgres backend
    which calls stored functions to produce lease dumps  rather than
    SQL texti from lease_dump_<version>.sh

src/bin/admin/scripts/pgsql/dhcpdb_create.pgsql
    added statments to create lease dump functions:
        lease4DumpHeader
        lease4DumpData
        lease6DumpHeader
        lease6DumpData

src/bin/admin/tests/data/pgsql.lease6_dump_test.reference.csv
    Booleans were expected be 't' or 'f', changed to int 1 or 0
Thomas Markwalder 9 years ago
parent
commit
9fbe63fc67

+ 42 - 17
src/bin/admin/kea-admin.in

@@ -311,36 +311,61 @@ check_file_overwrite () {
 # and protocol
 # and protocol
 get_dump_query() {
 get_dump_query() {
     local version=$1
     local version=$1
+    local dump_sql_file="$scripts_dir/${backend}/lease_dump_$version.sh"
 
 
     dump_qry=""
     dump_qry=""
-    dump_sql_file="$scripts_dir/${backend}/lease_dump_$version.sh"
-    if [ ! -e $dump_sql_file ]
-    then
-        log_error "lease-dump: cannot access dump_sql_file: $dump_sql_file"
-        exit 1;
-    fi
+    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
+        # 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
+        ;;
 
 
-    # Construct the SQL text to dump the leases based on protocol type
-    case ${dump_type} in
+    pgsql)
+        # Construct the SQL text to dump the leases based on protocol type
+        case ${dump_type} in
         4)
         4)
-            dump_qry="$lease4_dump_sql";
+            dump_qry="select * from lease4DumpHeader();select * from lease4DumpData()";
             ;;
             ;;
         6)
         6)
-            dump_qry="$lease6_dump_sql";
+            dump_qry="select * from lease6DumpHeader();select * from lease6DumpData()";
             ;;
             ;;
         *)
         *)
             log_error "you must specify -4 or -6 for lease-dump"
             log_error "you must specify -4 or -6 for lease-dump"
             usage
             usage
             exit 1
             exit 1
             ;;
             ;;
+        esac
+        ;;
+    *)
+        log_error "unsupported backend ${backend}"
+        usage
+        exit 1
+        ;;
     esac
     esac
 
 
     if [ "$dump_qry" = "" ]
     if [ "$dump_qry" = "" ]

+ 2 - 2
src/bin/admin/scripts/pgsql/Makefile.am

@@ -1,6 +1,6 @@
 SUBDIRS = .
 SUBDIRS = .
 
 
 sqlscriptsdir = ${datarootdir}/${PACKAGE_NAME}/scripts/pgsql
 sqlscriptsdir = ${datarootdir}/${PACKAGE_NAME}/scripts/pgsql
-sqlscripts_DATA = dhcpdb_create.pgsql lease_dump_1.0.sh
+sqlscripts_DATA = dhcpdb_create.pgsql
 
 
-EXTRA_DIST = dhcpdb_create.pgsql lease_dump_1.0.sh
+EXTRA_DIST = dhcpdb_create.pgsql

+ 77 - 0
src/bin/admin/scripts/pgsql/dhcpdb_create.pgsql

@@ -50,6 +50,41 @@ CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
 -- index by client_id and subnet_id
 -- index by client_id and subnet_id
 CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
 CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
 
 
+--
+--  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' 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
+    ) as $$
+    SELECT ('0.0.0.0'::inet + address), 
+            encode(hwaddr,'hex'), 
+            encode(client_id,'hex'),
+            valid_lifetime,
+            expire,
+            subnet_id,
+            fqdn_fwd::int,
+            fqdn_rev::int,
+            hostname
+    from lease4;
+$$ LANGUAGE SQL;
+--
+
 -- Holds the IPv6 leases.
 -- Holds the IPv6 leases.
 -- N.B. The use of a VARCHAR for the address is temporary for development:
 -- N.B. The use of a VARCHAR for the address is temporary for development:
 -- it will eventually be replaced by BINARY(16).
 -- it will eventually be replaced by BINARY(16).
@@ -103,6 +138,48 @@ START TRANSACTION;
 INSERT INTO schema_version VALUES (1, 0);
 INSERT INTO schema_version VALUES (1, 0);
 COMMIT;
 COMMIT;
 
 
+--
+--  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' 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
+    ) 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);
+$$ LANGUAGE SQL;
+--
+
 -- Notes:
 -- Notes:
 
 
 -- Indexes
 -- Indexes

+ 0 - 39
src/bin/admin/scripts/pgsql/lease_dump_1.0.sh

@@ -1,39 +0,0 @@
-#!/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 PostgreSQL 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 ('0.0.0.0'::inet + address) AS address,\
-encode(hwaddr,'hex'), encode(client_id,'hex'), valid_lifetime,\
-expire, subnet_id, fqdn_fwd::int AS fqdn_fwd, fqdn_rev::int AS 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, 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, a.fqdn_rev, hostname \
-FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type)"

+ 3 - 3
src/bin/admin/tests/data/pgsql.lease6_dump_test.reference.csv

@@ -1,4 +1,4 @@
 address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname
 address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname
-12,21,30,<timestamp3>,40,50,IA_TA,60,70,t,t,three.example.com
-11,,30,<timestamp2>,40,50,IA_TA,60,70,t,t,
-10,20,30,<timestamp1>,40,50,IA_TA,60,70,t,t,one.example.com
+12,21,30,<timestamp3>,40,50,IA_TA,60,70,1,1,three.example.com
+11,,30,<timestamp2>,40,50,IA_TA,60,70,1,1,
+10,20,30,<timestamp1>,40,50,IA_TA,60,70,1,1,one.example.com