Browse Source

[master] Merge branch 'trac3599' (kea-admin)

Tomek Mrugalski 10 years ago
parent
commit
cf22f8d212

+ 10 - 0
configure.ac

@@ -1393,6 +1393,15 @@ AC_CONFIG_FILES([compatcheck/Makefile
                  src/bin/perfdhcp/Makefile
                  src/bin/perfdhcp/tests/Makefile
                  src/bin/perfdhcp/tests/testdata/Makefile
+                 src/bin/admin/Makefile
+                 src/bin/admin/kea-admin
+                 src/bin/admin/scripts/Makefile
+                 src/bin/admin/tests/Makefile
+                 src/bin/admin/tests/memfile_tests.sh
+                 src/bin/admin/tests/mysql_tests.sh
+                 src/bin/admin/scripts/mysql/Makefile
+                 src/bin/admin/scripts/mysql/upgrade_1.0_to_2.0.sh
+                 src/bin/admin/scripts/pgsql/Makefile
                  src/hooks/Makefile
                  src/hooks/dhcp/Makefile
                  src/hooks/dhcp/user_chk/Makefile
@@ -1465,6 +1474,7 @@ AC_CONFIG_FILES([compatcheck/Makefile
            chmod +x src/bin/dhcp6/tests/dhcp6_process_tests.sh
            chmod +x src/bin/keactrl/keactrl
            chmod +x src/bin/keactrl/tests/keactrl_tests.sh
+           chmod +x src/bin/admin/kea-admin
            chmod +x src/lib/dns/gen-rdatacode.py
            chmod +x src/lib/log/tests/console_test.sh
            chmod +x src/lib/log/tests/destination_test.sh

+ 1 - 1
src/bin/Makefile.am

@@ -1,5 +1,5 @@
 # The following build order must be maintained.
-SUBDIRS = dhcp4 dhcp6 d2 perfdhcp
+SUBDIRS = dhcp4 dhcp6 d2 perfdhcp admin
 
 if CONFIG_BACKEND_JSON
 SUBDIRS += keactrl

+ 2 - 0
src/bin/admin/.gitignore

@@ -0,0 +1,2 @@
+/kea-admin
+/kea-admin.8

+ 24 - 0
src/bin/admin/Makefile.am

@@ -0,0 +1,24 @@
+SUBDIRS = . scripts tests
+
+# Install kea-admin in sbin.
+sbin_SCRIPTS  = kea-admin
+
+man_MANS = kea-admin.8
+DISTCLEANFILES = $(man_MANS)
+EXTRA_DIST = $(man_MANS) kea-admin.xml admin-utils.sh
+
+if GENERATE_DOCS
+
+kea-admin.8: kea-admin.xml
+	@XSLTPROC@ --novalid --xinclude --nonet -o $@ http://docbook.sourceforge.net/release/xsl/current/manpages/docbook.xsl $(builddir)/kea-admin.xml
+
+else
+
+$(man_MANS):
+	@echo Man generation disabled.  Creating dummy $@.  Configure with --enable-generate-docs to enable it.
+	@echo Man generation disabled.  Remove this file, configure with --enable-generate-docs, and rebuild Kea > $@
+
+endif
+
+adminscriptsdir = ${datarootdir}/${PACKAGE_NAME}/scripts
+adminscripts_DATA = admin-utils.sh

+ 44 - 0
src/bin/admin/admin-utils.sh

@@ -0,0 +1,44 @@
+# Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+#
+# Permission to use, copy, modify, and/or 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 ISC DISCLAIMS ALL WARRANTIES WITH
+# REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+# AND FITNESS.  IN NO EVENT SHALL ISC 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.
+
+# This is an utility script that is being included by other scripts.
+
+# There are two ways of calling this method.
+# mysql_execute SQL_QUERY - This call is simpler, but requires db_user,
+#     db_password and db_name variables to be bet.
+# mysql_execute SQL_QUERY PARAM1 PARAM2 .. PARAMN - Additional parameters
+#     may be specified. They are passed directly to mysql. This one is
+#     more convenient to use if the script didn't parse db_user db_password
+#     and db_name.
+#
+# @todo: Catch mysql return code. I tried to use PIPESTATUS[X], but it doesn't
+# seem to work (or at least I don't know how to use it).
+mysql_execute() {
+    if [ $# -gt 1 ]; then
+        QUERY=$1
+        shift
+        _RESULT=`echo $QUERY | mysql -N -B $@`
+    else
+        _RESULT=$(mysql -N -B --user=$db_user --password=$db_password -e "${1}" $db_name)
+    fi
+}
+
+mysql_version() {
+    mysql_execute "SELECT CONCAT(version,\".\",minor) FROM schema_version" "$@"
+}
+
+mysql_version_print() {
+    mysql_version "$@"
+    printf "%s" $_RESULT
+}

+ 351 - 0
src/bin/admin/kea-admin.in

@@ -0,0 +1,351 @@
+#!/bin/sh
+
+# Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+#
+# Permission to use, copy, modify, and/or 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 ISC DISCLAIMS ALL WARRANTIES WITH
+# REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+# AND FITNESS.  IN NO EVENT SHALL ISC 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.
+
+# This is kea-admin script that conducts administrative tasks on the Kea
+# installation. Currently supported operations are:
+#
+# - lease database init
+# - lease database version check
+# - lease database version upgrade
+
+
+# Get the location of the kea-admin scripts
+prefix=@prefix@
+SCRIPTS_DIR_DEFAULT=@datarootdir@/@PACKAGE@/scripts
+scripts_dir=${SCRIPTS_DIR_DEFAULT}
+
+# These are the default parameters. They will likely not work in any
+# specific deployment.
+db_user="keatest"
+db_password="keatest"
+db_name="keatest"
+
+# 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
+
+# Prints out usage version.
+usage() {
+    printf "kea-admin @PACKAGE_VERSION@\n"
+    printf "\n"
+    printf "This is a kea-admin script that conducts administrative tasks on\n"
+    printf "the Kea installation.\n"
+    printf "\n"
+    printf "Usage: $0 COMMAND BACKEND [parameters]\n"
+    printf "\n"
+    printf "COMMAND: Currently supported operations are:\n"
+    printf "\n"
+    printf " - lease-init: Initalizes new lease database. Useful for first time installation.\n"
+    printf " - lease-version: Checks version of the existing lease database scheme. Useful\n"
+    printf " -                for checking lease DB version when preparing for an upgrade.\n"
+    printf " - lease-upgrade: Upgrades your lease database scheme\n"
+    printf "\n"
+    printf "BACKEND - one of the supported backends: memfile|mysql|pgsql\n"
+    printf "\n"
+    printf "PARAMETERS: Parameters are optional in general, but may be required\n"
+    printf "            for specific operation.\n"
+    printf " -u or --user name - specifies username when connecting to a database\n"
+    printf " -p or --password pass - specifies a password when connecting to a database\n"
+    printf " -n or --name database - specifies a database name to connect to\n"
+    printf " -d or --directory - path to upgrade scripts (default: ${SCRIPTS_DIR_DEFAULT})\n"
+}
+
+
+### Logging functions ###
+
+# Logs message at the error level.
+# Takes one parameter that is printed as is.
+log_error() {
+    printf "ERROR/kea-admin: ${1}\n"
+}
+
+# Logs message at the warning level.
+# Takes one parameter that is printed as is.
+log_warning() {
+    printf "WARNING/kea-admin: ${1}\n"
+}
+
+# Logs message at the info level.
+# Takes one parameter that is printed as is.
+log_info() {
+    printf "INFO/kea-admin: ${1}\n"
+}
+
+### Convenience functions ###
+
+# Checks if the value is in the list. An example usage of this function
+# is to determine whether the kea-admin command belongs to the list of
+# supported commands.
+is_in_list() {
+    local member=${1}  # Value to be checked
+    local list="${2}"  # Comma separated list of items
+    _inlist=0          # Return value: 0 if not in list, 1 otherwise.
+    if [ -z ${member} ]; then
+        log_error "missing ${class}"
+    fi
+    # Iterate over all items on the list and compare with the member.
+    # If they match, return, otherwise log error and exit.
+    for item in ${list}
+    do
+        if [ ${item} = ${member} ]; then
+            _inlist=1
+            return
+        fi
+    done
+}
+
+
+### Functions that implement database initialization commands
+
+memfile_init() {
+    # @todo Implement this as part of #3601
+    log_error "NOT IMPLEMENTED"
+    exit 1
+}
+
+# Initializes a new, empty MySQL database.
+# It essentially calls scripts/mysql/dhcpdb_create.mysql script, with
+# some extra sanity checks. It will refuse to use it if there are any
+# existing tables. It's better safe than sorry.
+mysql_init() {
+    printf "Checking if there is a database initialized already. Please ignore errors.\n"
+
+    # Let's try to count the number of tables. Anything above 0 means that there
+    # is some database in place. If there is anything, we abort. Note that
+    # mysql may spit out connection or access errors to stderr, we ignore those.
+    # We should not hide them as they may give hints to user what is wrong with
+    # his setup.
+    #
+    mysql_execute "SHOW TABLES;"
+    COUNT=`echo $_RESULT | wc -w`
+    if [ $COUNT -gt 0 ]; then
+        # Let't start with a new line. mysql could have printed something out.
+        printf "\n"
+        log_error "Expected empty database $db_name, but there are $COUNT tables: \n$_RESULT. Aborting."
+        exit 1
+    fi
+
+    printf "Initializing database using script %s\n" $scripts_dir/mysql/dhcpdb_create.mysql
+    mysql -B --user=$db_user --password=$db_password $db_name < $scripts_dir/mysql/dhcpdb_create.mysql
+    ERRCODE=$?
+
+    printf "mysql returned status code $ERRCODE\n"
+
+    if [ "$ERRCODE" -eq 0 ]; then
+        printf "Lease DB version reported after initialization: "
+        mysql_version_print
+        printf "\n"
+    fi
+
+    exit $ERRCODE
+}
+
+pgsql_init() {
+    log_error "NOT IMPLEMENTED"
+    exit 1
+}
+
+### Functions that implement database version checking commands
+memfile_version() {
+    # @todo Implement this as part of #3601
+    log_error "NOT IMPLEMENTED"
+    exit 1
+}
+
+pgsql_version() {
+    log_error "NOT IMPLEMENTED"
+    exit 1
+}
+
+### Functions used for upgrade
+memfile_upgrade() {
+    # @todo Implement this as part of #3601
+    log_error "NOT IMPLEMENTED"
+    exit 1
+}
+
+# Upgrades existing MySQL database installation. The idea is that
+# it will go over all upgrade scripts from (prefix)/share/kea/scripts/mysql
+# and run them one by one. They will be named properly, so they will
+# be run in order.
+#
+# This function prints version before and after upgrade.
+mysql_upgrade() {
+
+    printf "Lease DB version reported before upgrade: "
+    mysql_version_print
+    printf "\n"
+
+    # Check if the scripts directory exists at all.
+    if [ ! -d ${scripts_dir}/mysql ]; then
+        log_error "Invalid scripts directory: ${scripts_dir}/mysql"
+        exit 1
+    fi
+
+    # Check if there are any files in it
+    num_files=$(find ${scripts_dir}/mysql/upgrade*.sh -type f | wc -l)
+    if [ $num_files -eq 0 ]; then
+        log_error "No scripts in ${scripts_dir}/mysql or the directory is not readable or does not have any upgrade* scripts."
+        exit 1
+    fi
+
+    for script in ${scripts_dir}/mysql/upgrade*.sh
+    do
+        echo "Processing $script file..."
+        sh ${script} --user=${db_user} --password=${db_password} ${db_name}
+    done
+
+    printf "Lease DB version reported after upgrade: "
+    mysql_version_print
+    printf "\n"
+}
+
+pgsql_upgrade() {
+    log_error "NOT IMPLEMENTED"
+}
+
+
+### Script starts here ###
+
+# First, find what the command is
+command=${1}
+if [ -z ${command} ]; then
+    log_error "missing command"
+    usage
+    exit 1
+fi
+is_in_list "${command}" "lease-init lease-version lease-upgrade"
+if [ ${_inlist} -eq 0 ]; then
+    log_error "invalid command: ${command}"
+    exit 1
+fi
+shift
+
+# Second, check what's the backend
+backend=${1}
+if [ -z ${backend} ]; then
+    log_error "missing backend"
+    usage
+    exit 1
+fi
+is_in_list "${backend}" "memfile mysql pgsql"
+if [ ${_inlist} -eq 0 ]; then
+    log_error "invalid backend: ${backend}"
+    exit 1
+fi
+shift
+
+# Ok, let's process parameters (if there are any)
+while [ ! -z "${1}" ]
+do
+    option=${1}
+    case ${option} in
+        # Specify database user
+        -u|--user)
+            shift
+            db_user=${1}
+            if [ -z ${db_user} ]; then
+                log_error "-u or --user requires a parameter"
+                usage
+                exit 1
+            fi
+            ;;
+        # Specify database password
+        -p|--password)
+            shift
+            db_pass=${1}
+            if [ -z ${db_pass} ]; then
+                log_error "-p or --password requires a parameter"
+                usage
+                exit 1
+            fi
+            ;;
+        # Specify database name
+        -n|--name)
+            shift
+            db_name=${1}
+            if [ -z ${db_name} ]; then
+                log_error "-n or --name requires a parameter"
+                usage
+                exit 1
+            fi
+            ;;
+        -d|--directory)
+            shift
+            scripts_dir=${1}
+            if [ -z ${scripts_dir} ]; then
+                log_error "-d or --directory requires a parameter"
+                usage
+                exit 1
+            fi
+            ;;
+        *)
+            log_error "invalid option: ${option}"
+            usage
+            exit 1
+    esac
+    shift
+done
+
+case ${command} in
+    # Initialize the database
+    lease-init)
+        case ${backend} in
+            memfile)
+                memfile_init
+                ;;
+            mysql)
+                mysql_init
+                ;;
+            pgsql)
+                pgsql_init
+                ;;
+            esac
+        ;;
+    lease-version)
+        case ${backend} in
+            memfile)
+                memfile_version
+                ;;
+            mysql)
+                mysql_version_print
+                printf "\n"
+                ;;
+            pgsql)
+                pgsql_version
+                ;;
+            esac
+        ;;
+    lease-upgrade)
+        case ${backend} in
+            memfile)
+                memfile_upgrade
+                ;;
+            mysql)
+                mysql_upgrade
+                ;;
+            pgsql)
+                pgsql_upgrade
+                ;;
+            esac
+        ;;
+esac
+
+exit 0

+ 186 - 0
src/bin/admin/kea-admin.xml

@@ -0,0 +1,186 @@
+<!DOCTYPE book PUBLIC "-//OASIS//DTD DocBook XML V4.2//EN"
+               "http://www.oasis-open.org/docbook/xml/4.2/docbookx.dtd"
+	       [<!ENTITY mdash "&#8212;">]>
+<!--
+ - Copyright (C) 2014  Internet Systems Consortium, Inc. ("ISC")
+ -
+ - Permission to use, copy, modify, and/or 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 ISC DISCLAIMS ALL WARRANTIES WITH
+ - REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+ - AND FITNESS.  IN NO EVENT SHALL ISC 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.
+-->
+
+<refentry>
+  <refentryinfo>
+    <date>Nov 5, 2014</date>
+  </refentryinfo>
+
+  <refmeta>
+    <refentrytitle>kea-admin</refentrytitle>
+    <manvolnum>8</manvolnum>
+    <refmiscinfo>Kea</refmiscinfo>
+  </refmeta>
+
+  <refnamediv>
+    <refname>kea-admin</refname>
+    <refpurpose>Shell script for managing Kea databases</refpurpose>
+  </refnamediv>
+
+  <docinfo>
+    <copyright>
+      <year>2014</year>
+      <holder>Internet Systems Consortium, Inc. ("ISC")</holder>
+    </copyright>
+  </docinfo>
+
+  <refsynopsisdiv>
+    <cmdsynopsis>
+      <command>kea-admin</command>
+      <arg>command</arg>
+      <arg>backend</arg>
+      <arg><option>-u <replaceable class="parameter">database username</replaceable></option></arg>
+      <arg><option>-p <replaceable class="parameter">database password</replaceable></option></arg>
+      <arg><option>-n <replaceable class="parameter">database name</replaceable></option></arg>
+      <arg><option>-d <replaceable class="parameter">scripts directory</replaceable></option></arg>
+    </cmdsynopsis>
+  </refsynopsisdiv>
+
+  <refsect1>
+    <title>DESCRIPTION</title>
+    <para>
+      kea-admin is a shell script which offers database maintenance. In particular,
+      it features database initialization, database version checking and 
+      database schema upgrade.
+    </para>
+  </refsect1>
+
+  <refsect1>
+    <title>OPTIONS</title>
+    <variablelist>
+      <varlistentry>
+        <term><option><replaceable class="parameter">command</replaceable></option></term>
+        <listitem>
+          <para>
+            Command to be issued to the servers. It can be one of the following:
+          </para>
+
+          <variablelist>
+            <varlistentry>
+              <term>lease-init</term>
+              <listitem>
+                <para>Initializes a new lease database. Useful during first Kea
+                installation. The database is initialized to the latest version
+                supported by the version of the software.</para>
+              </listitem>
+            </varlistentry>
+
+            <varlistentry>
+              <term>lease-version</term>
+              <listitem>
+                <para>Reports lease database version. This is not necessarily
+                equal to Kea version as each backend has its own versioning
+                scheme.</para>
+              </listitem>
+            </varlistentry>
+
+            <varlistentry>
+              <term>lease-upgrade</term>
+              <listitem>
+                <para>Conducts lease database upgrade. This is useful when
+                migrating between old and new Kea versions.</para>
+              </listitem>
+            </varlistentry>
+          </variablelist>
+
+        </listitem>
+      </varlistentry>
+
+      <varlistentry>
+        <term><option><replaceable class="parameter">backend</replaceable></option></term>
+        <listitem>
+          <para>
+            Specifies backend type. Currently allowed backends are: memfile, mysql and
+            pgsql.
+          </para>
+        </listitem>
+      </varlistentry>
+
+      <varlistentry>
+        <term><option>-u|--user <replaceable class="parameter">username</replaceable></option></term>
+        <listitem>
+          <para>
+            Specify the username when connecting to a database. If not specified,
+            the default value of keatest is used.
+          </para>
+        </listitem>
+      </varlistentry>
+
+      <varlistentry>
+        <term><option>-p|--password <replaceable class="parameter">password</replaceable></option></term>
+        <listitem>
+          <para>
+            Specifies the password when connecting to a database. If not specified,
+            the default value of keatest is used.
+          </para>
+        </listitem>
+      </varlistentry>
+
+      <varlistentry>
+        <term><option>-n|--name <replaceable class="parameter">database-name</replaceable></option></term>
+        <listitem>
+          <para>
+            Specifies the database name to connect to. If not specified,
+            the default value of keatest is used.
+          </para>
+        </listitem>
+      </varlistentry>
+
+      <varlistentry>
+        <term><option>-d|--directory <replaceable class="parameter">script-directory</replaceable></option></term>
+        <listitem>
+          <para>
+            Used for override scripts directory. That script is used during upgrades,
+            database initialization and possibly other operations. If not specified,
+            the default value of (prefix)/share/kea/scripts/ is used.
+          </para>
+        </listitem>
+      </varlistentry>
+
+    </variablelist>
+
+  </refsect1>
+
+  <refsect1>
+    <title>SEE ALSO</title>
+    <para>
+      <citerefentry>
+        <refentrytitle>keactrl</refentrytitle>
+        <manvolnum>8</manvolnum>
+      </citerefentry>
+
+      <citerefentry>
+        <refentrytitle>kea-dhcp4</refentrytitle>
+        <manvolnum>8</manvolnum>
+      </citerefentry>
+
+      <citerefentry>
+        <refentrytitle>kea-dhcp6</refentrytitle>
+        <manvolnum>8</manvolnum>
+      </citerefentry>
+
+      <citerefentry>
+        <refentrytitle>kea-dhcp-ddns</refentrytitle>
+        <manvolnum>8</manvolnum>
+      </citerefentry>
+
+    </para>
+  </refsect1>
+
+</refentry>

+ 1 - 0
src/bin/admin/scripts/Makefile.am

@@ -0,0 +1 @@
+SUBDIRS = mysql pgsql

+ 1 - 0
src/bin/admin/scripts/mysql/.gitignore

@@ -0,0 +1 @@
+/upgrade_1.0_to_2.0.sh

+ 6 - 0
src/bin/admin/scripts/mysql/Makefile.am

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

+ 198 - 0
src/bin/admin/scripts/mysql/dhcpdb_create.mysql

@@ -0,0 +1,198 @@
+# Copyright (C) 2012-2013  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.
+
+# This is the Kea schema specification for MySQL.
+#
+# The schema is reasonably portable (with the exception of the engine
+# specification, which is MySQL-specific).  Minor changes might be needed for
+# other databases.
+
+# To create the schema, either type the command:
+#
+# mysql -u <user> -p <password> <database> < dhcpdb_create.mysql
+#
+# ... at the command prompt, or log in to the MySQL database and at the "mysql>"
+# prompt, issue the command:
+#
+# source dhcpdb_create.mysql
+#
+# This script is also called from kea-admin, see kea-admin init mysql
+#
+# Over time, Kea database schema will evolve. Each version is marked with
+# major.minor version. This file is organized sequentially, i.e. database
+# is initialized to 1.0, then upgraded to 2.0 etc. This may be somewhat
+# sub-optimal, but it ensues consistency with upgrade scripts. (It is much
+# easier to maintain init and upgrade scripts if they look the same).
+# Since initialization is done only once, it's perfromance is not an issue.
+
+# This line starts database initialization to 1.0.
+
+# Holds the IPv4 leases.
+CREATE TABLE lease4 (
+    address INT UNSIGNED PRIMARY KEY NOT NULL,  # IPv4 address
+    hwaddr VARBINARY(20),                       # Hardware address
+    client_id VARBINARY(128),                   # Client ID
+    valid_lifetime INT UNSIGNED,                # Length of the lease (seconds)
+    expire TIMESTAMP,                           # Expiration time of the lease
+    subnet_id INT UNSIGNED,                     # Subnet identification
+    fqdn_fwd BOOL,                              # Has forward DNS update been performed by a server
+    fqdn_rev BOOL,                              # Has reverse DNS update been performed by a server
+    hostname VARCHAR(255)                       # The FQDN of the client
+    ) ENGINE = INNODB;
+
+
+# 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 VARBINARY(128),                        # DUID
+    valid_lifetime INT UNSIGNED,                # Length of the lease (seconds)
+    expire TIMESTAMP,                           # Expiration time of the lease
+    subnet_id INT UNSIGNED,                     # Subnet identification
+    pref_lifetime INT UNSIGNED,                 # Preferred lifetime
+    lease_type TINYINT,                         # Lease type (see lease6_types
+                                                #    table for possible values)
+    iaid INT UNSIGNED,                          # See Section 10 of RFC 3315
+    prefix_len TINYINT UNSIGNED,                # For IA_PD only
+    fqdn_fwd BOOL,                              # Has forward DNS update been performed by a server
+    fqdn_rev BOOL,                              # Has reverse DNS update been performed by a server
+    hostname VARCHAR(255)                       # The FQDN of the client
+
+    ) ENGINE = INNODB;
+
+# 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.
+# Make sure those values match Lease6::LeaseType enum (see src/bin/dhcpsrv/
+# lease_mgr.h)
+CREATE TABLE lease6_types (
+    lease_type TINYINT 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 1.0 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;
+
+# This line concludes database initalization to version 1.0.
+
+# This line starts database upgrade to version 2.0.
+ALTER TABLE lease6
+    ADD COLUMN hwaddr varbinary(20), # Hardware/MAC address, typically only 6
+                                     # bytes is used, but some hardware (e.g.
+                                     # Infiniband) use up to 20.
+    ADD COLUMN hwtype smallint unsigned, # hardware type (16 bits)
+    ADD COLUMN hwaddr_source int unsigned; # Hardware source. See description
+                                     # of lease_hwaddr_source below.
+
+# Kea keeps track of the hardware/MAC address source, i.e. how the address
+# was obtained. Depending on the technique and your network topology, it may
+# be more or less trustworthy. 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. For details,
+# see constants defined in src/lib/dhcp/dhcp/pkt.h for detailed explanation.
+CREATE TABLE lease_hwaddr_source (
+    hwaddr_source INT PRIMARY KEY NOT NULL,
+    name VARCHAR(40)
+);
+
+# 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");
+
+UPDATE schema_version SET version="2", minor="0";
+
+# This line concludes database upgrade to version 2.0.
+
+# 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:
+#
+# expire
+# To speed up the deletion of expired leases from the database.
+#
+# 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 MySQL
+# backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
+#
+# Portability
+# ===========
+# The "ENGINE = INNODB" on some tables is not portable to another database
+# and will need to be removed.
+#
+# Some columns contain binary data so are stored as VARBINARY instead of
+# VARCHAR.  This may be non-portable between databases: in this case, the
+# definition should be changed to VARCHAR.

+ 44 - 0
src/bin/admin/scripts/mysql/upgrade_1.0_to_2.0.sh.in

@@ -0,0 +1,44 @@
+#!/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
+
+mysql_version "$@"
+VERSION=$_RESULT
+
+if [ "$VERSION" != "1.0" ]; then
+    printf "This script upgrades 1.0 to 2.0. Reported version is $VERSION. Skipping upgrade.\n"
+    exit 0
+fi
+
+mysql "$@" <<EOF
+ALTER TABLE lease6
+    ADD COLUMN hwaddr varbinary(20),
+    ADD COLUMN hwtype smallint unsigned,
+    ADD COLUMN hwaddr_source int unsigned;
+
+CREATE TABLE lease_hwaddr_source (
+    hwaddr_source INT PRIMARY KEY NOT NULL,
+    name VARCHAR(40)
+);
+
+-- See src/lib/dhcp/dhcp/pkt.h for detailed explanation
+INSERT INTO lease_hwaddr_source VALUES (1, "HWADDR_SOURCE_RAW");
+INSERT INTO lease_hwaddr_source VALUES (2, "HWADDR_SOURCE_IPV6_LINK_LOCAL");
+INSERT INTO lease_hwaddr_source VALUES (4, "HWADDR_SOURCE_DUID");
+INSERT INTO lease_hwaddr_source VALUES (8, "HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION");
+INSERT INTO lease_hwaddr_source VALUES (16, "HWADDR_SOURCE_REMOTE_ID");
+INSERT INTO lease_hwaddr_source VALUES (32, "HWADDR_SOURCE_SUBSCRIBER_ID");
+INSERT INTO lease_hwaddr_source VALUES (64, "HWADDR_SOURCE_DOCSIS");
+
+UPDATE schema_version SET version="2", minor="0";
+EOF
+
+RESULT=$?
+
+exit $?

+ 6 - 0
src/bin/admin/scripts/pgsql/Makefile.am

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

src/lib/dhcpsrv/dhcpdb_create.pgsql → src/bin/admin/scripts/pgsql/dhcpdb_create.pgsql


+ 2 - 0
src/bin/admin/tests/.gitignore

@@ -0,0 +1,2 @@
+/memfile_tests.sh
+/mysql_tests.sh

+ 24 - 0
src/bin/admin/tests/Makefile.am

@@ -0,0 +1,24 @@
+SUBDIRS = .
+
+SHTESTS = memfile_tests.sh
+
+if HAVE_MYSQL
+SHTESTS += mysql_tests.sh
+endif
+
+if HAVE_PGSQL
+SHTESTS += pgsql_tests.sh
+endif
+
+noinst_SCRIPTS = $(SHTESTS)
+
+CLEANFILES = *.log
+DISTCLEANFILES = memfile_tests.sh mysql_tests.sh
+
+# Execute all test scripts.
+check-local:
+	for shtest in $(SHTESTS) ; do \
+	echo Running test: $$shtest ; \
+	chmod +x $(abs_builddir)/$$shtest ; \
+	${SHELL} $(abs_builddir)/$$shtest || exit ; \
+	done

+ 3 - 1
src/lib/dhcpsrv/dhcpdb_create.mysql

@@ -13,7 +13,9 @@
 # NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
 # WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
 
-# This is the BIND 10 DHCP schema specification for MySQL.
+# This is the Kea schema 1.0 specification for MySQL.
+# Note: this is outdated version on purpose and it used to test upgrade
+# process. Do not update this file to 2.0 or any later.
 #
 # The schema is reasonably portable (with the exception of the engine
 # specification, which is MySQL-specific).  Minor changes might be needed for

+ 46 - 0
src/bin/admin/tests/memfile_tests.sh.in

@@ -0,0 +1,46 @@
+#!/bin/sh
+
+# Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+#
+# Permission to use, copy, modify, and/or 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 ISC DISCLAIMS ALL WARRANTIES WITH
+# REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+# AND FITNESS.  IN NO EVENT SHALL ISC 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.
+
+# Include common test library.
+. @abs_top_builddir@/src/lib/testutils/dhcp_test_lib.sh
+
+memfile_init_test() {
+    test_start "memfile.init"
+    
+    # @todo: Implement this (ticket #3601)
+
+    test_finish 0
+}
+
+memfile_version_test() {
+    test_start "memfile.version"
+    
+    # @todo: Implement this (ticket #3601)
+
+    test_finish 0
+}
+
+memfile_upgrade_test() {
+    test_start "memfile.upgrade"
+    
+    # @todo: Implement this (ticket #3601)
+
+    test_finish 0
+}
+
+memfile_init_test
+memfile_version_test
+memfile_upgrade_test

+ 184 - 0
src/bin/admin/tests/mysql_tests.sh.in

@@ -0,0 +1,184 @@
+#!/bin/sh
+
+# Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+#
+# Permission to use, copy, modify, and/or 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 ISC DISCLAIMS ALL WARRANTIES WITH
+# REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+# AND FITNESS.  IN NO EVENT SHALL ISC 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.
+
+# Include common test library.
+. @abs_top_builddir@/src/lib/testutils/dhcp_test_lib.sh
+
+# If the code is installed, include admin-utils.sh from the destination
+# directory. If not, include it from the sources.
+prefix=@prefix@
+
+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
+
+db_user="keatest"
+db_pass="keatest"
+db_name="keatest"
+
+# Set location of the kea-admin.
+keaadmin=@abs_top_builddir@/src/bin/admin/kea-admin
+
+# Wipe all tables from the DB:
+mysql_wipe() {
+    printf "Wiping whole database %s\n" $db_name
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+SET @tables = NULL;
+SELECT GROUP_CONCAT(table_schema, '.', table_name) INTO @tables
+  FROM information_schema.tables
+  WHERE table_schema = 'keatest';
+
+SET @tables = CONCAT('DROP TABLE ', @tables);
+PREPARE stmt FROM @tables;
+EXECUTE stmt;
+DEALLOCATE PREPARE stmt;
+EOF
+}
+
+mysql_lease_init_test() {
+    test_start "mysql.lease-init"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    # Ok, now let's initalize the database
+    ${keaadmin} lease-init mysql -u $db_user -p $db_pass -n $db_name -d @abs_top_srcdir@/src/bin/admin/scripts
+    ERRCODE=$?
+
+    assert_eq 0 $ERRCODE "kea-admin lease-init mysql returned non-zero status code %d, expected %d"
+
+    # Ok, now let's check if the tables are indeed there.
+    # First table: schema_version. Should have 2 columns: version and minor.
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT version, minor FROM schema_version;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "schema_version table is missing or broken. (returned status code %d, expected %d)"
+
+    # Second table: lease4
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT address, hwaddr, client_id, valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname FROM lease4;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease4 table is missing or broken. (returned status code %d, expected %d)"
+
+    # Third table: lease6
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT address, duid, valid_lifetime, expire, subnet_id, pref_lifetime, lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, hwaddr, hwtype, hwaddr_source FROM lease6;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease6 table is missing or broken. (returned status code %d, expected %d)"
+
+    # Fourth table: lease6_types
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT lease_type, name FROM lease6_types;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease6_types table is missing or broken. (returned status code %d, expected %d)"
+
+    # Fifth table: lease_hwaddr_source
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT hwaddr_source, name FROM lease_hwaddr_source;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease_hwaddr_source table is missing or broken. (returned status code %d, expected %d)"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    test_finish 0
+}
+
+mysql_lease_version_test() {
+    test_start "mysql.lease-version"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    # Ok, now let's create a version 1.7
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+CREATE TABLE schema_version (
+    version INT PRIMARY KEY NOT NULL,
+    minor INT
+    );
+INSERT INTO schema_version VALUES (1, 7);
+EOF
+
+    version=$(${keaadmin} lease-version mysql -u $db_user -p $db_pass -n $db_name)
+
+    assert_str_eq "1.7" ${version} "Expected kea-admin to return %s, returned value was %s"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    test_finish 0
+}
+
+mysql_lease_upgrade_test() {
+
+    # @todo: need to test whether non-empty database is updated correctly and the data survives the upgrade
+
+    test_start "mysql.lease-upgrade"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    # Initialize database to scheme 1.0.
+    mysql -u$db_user -p$db_pass $db_name < @abs_top_srcdir@/src/bin/admin/tests/dhcpdb_create_1.0.mysql
+
+    # Sanity check - verify that it reports version 1.0.
+    version=$(${keaadmin} lease-version mysql -u $db_user -p $db_pass -n $db_name -d @abs_top_srcdir@/src/bin/admin/scripts)
+
+    assert_str_eq "1.0" ${version} "Expected kea-admin to return %s, returned value was %s"
+
+    # Ok, we have a 1.0 database. Let's upgrade it to 2.0
+    ${keaadmin} lease-upgrade mysql -u $db_user -p $db_pass -n $db_name -d @abs_top_srcdir@/src/bin/admin/scripts
+    ERRCODE=$?
+
+    assert_eq 0 $ERRCODE "kea-admin lease-upgrade mysql returned non-zero status code %d, expected %d"
+
+    # Let's check that the new tables are indeed there.
+
+    # Third table: lease6
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT hwaddr, hwtype, hwaddr_source FROM lease6;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease6 table not upgraded to 2.0 (returned status code %d, expected %d)"
+
+    # Fifth table: lease_hwaddr_source
+    mysql -u$db_user -p$db_pass $db_name >/dev/null 2>&1 <<EOF
+    SELECT hwaddr_source, name FROM lease_hwaddr_source;
+EOF
+    ERRCODE=$?
+    assert_eq 0 $ERRCODE "lease_hwaddr_source table is missing or broken. (returned status code %d, expected %d)"
+
+    # Verify that it reports version 2.0.
+    version=$(${keaadmin} lease-version mysql -u $db_user -p $db_pass -n $db_name)
+
+    assert_str_eq "2.0" ${version} "Expected kea-admin to return %s, returned value was %s"
+
+    # Let's wipe the whole database
+    mysql_wipe
+
+    test_finish 0
+}
+
+mysql_lease_init_test
+mysql_lease_version_test
+mysql_lease_upgrade_test

+ 3 - 3
src/lib/dhcpsrv/Makefile.am

@@ -121,9 +121,9 @@ endif
 # The message file should be in the distribution
 EXTRA_DIST = dhcpsrv_messages.mes
 
-# Distribute MySQL schema creation script and backend documentation
-EXTRA_DIST += dhcpdb_create.mysql dhcpdb_create.pgsql database_backends.dox libdhcpsrv.dox
-dist_pkgdata_DATA = dhcpdb_create.mysql dhcpdb_create.pgsql
+# Distribute backend documentation
+# Database schema creation script moved to src/bin/admin
+EXTRA_DIST += database_backends.dox libdhcpsrv.dox
 
 install-data-local:
 	$(mkinstalldirs) $(DESTDIR)$(dhcp_data_dir)

+ 27 - 2
src/lib/testutils/dhcp_test_lib.sh.in

@@ -59,6 +59,23 @@ assert_eq() {
     fi
 }
 
+# Assertion that checks if two strings are equal.
+# If numbers are not equal, the mismatched values are presented and the
+# detailed error is printed. The detailed error must use the printf
+# formatting like this:
+#    "Expected that some value 1 %d is equal to some other value %d".
+assert_str_eq() {
+    val1=${1}         # Reference value
+    val2=${2}         # Tested value
+    detailed_err=${3} # Detailed error format string
+    # If nothing found, present an error an exit.
+    if [ "${val1}" != "${val2}" ]; then
+        printf "Assertion failure: ${val1} != ${val2}, for val1=${val1}, val2=${val2}\n"
+        printf "${detailed_err}\n" ${val1} ${val2}
+        clean_exit 1
+    fi
+}
+
 # Assertion that checks if one string contains another string.
 # If assertion fails, both strings are displayed and the detailed
 # error is printed. The detailed error must use the printf formatting
@@ -96,8 +113,9 @@ test_finish() {
         cleanup
         printf "PASSED ${TEST_NAME}\n\n"
     else
-        # Dump log file if exists for debugging purposes.
-        if [ -s ${LOG_FILE} ]; then
+        # Dump log file for debugging purposes if specified and exists.
+        # Otherwise the code below would simply call cat.
+        if [ -n "${LOG_FILE}" -a -s "${LOG_FILE}" ]; then
             printf "Log file dump:\n"
             cat ${LOG_FILE}
         fi
@@ -209,6 +227,12 @@ get_reconfigs() {
 # in the ${LOG_FILE}, ${CFG_FILE} and ${KEACTRL_CFG_FILE} variables
 # recpectively, prior to calling this function.
 cleanup() {
+
+    # If there is no KEA_PROCS set, just return
+    if [ -z "${KEA_PROCS}" ]; then
+        return
+    fi
+
     # KEA_PROCS holds the name of all Kea processes. Shut down each
     # of them if running.
     for proc_name in ${KEA_PROCS}
@@ -221,6 +245,7 @@ cleanup() {
             kill -9 ${pid}
         done
     done
+
     # Remove temporary files.
     rm -rf ${LOG_FILE}
     rm -rf ${CFG_FILE}