Commit ebd3358b authored by Thomas Markwalder's avatar Thomas Markwalder
Browse files

[5586] Added schema unit tests

src/share/database/scripts/mysql/upgrade_5.2_to_6.0.sh.in
    Added SQL statements to populate lease4/6_stat tables
    from existing lease table content.

src/bin/admin/tests/dhcpdb_create_5.1.mysql
    New file used for upgrade testing

src/bin/admin/tests/mysql_tests.sh.in
    run_statement() - new convenience function for running SQL
    statements with an optional expected return value

    mysql_lease4_stat_test() - verifies lease4_stat
    table and trigger operations on a new database

    mysql_lease6_stat_test()
    mysql_lease6_stat_per_type() - new functions
    which lease6_stat table and trigger operations
    on a new database

    mysql_lease_stat_upgrade_test() - new function
    which verifies data migration from an earlier
    schema and trigger operation
parent 3ade7065
This diff is collapsed.
#!/bin/sh
# Copyright (C) 2014-2017 Internet Systems Consortium, Inc. ("ISC")
# Copyright (C) 2014-2018 Internet Systems Consortium, Inc. ("ISC")
#
# This Source Code Form is subject to the terms of the Mozilla Public
# License, v. 2.0. If a copy of the MPL was not distributed with this
......@@ -22,6 +22,38 @@ db_name="keatest"
# Set location of the kea-admin.
keaadmin=@abs_top_builddir@/src/bin/admin/kea-admin
# Convenience function for running an SQL statement
# param hdr - text message to prepend to any error
# param qry - SQL statement to run
# param exp_valu - optional expected value. This can be used IF the SQL statement
# generates a single value, such as a SELECT which returns one column for one row.
# Examples:
#
# qry="insert into lease6 (address, lease_type, subnet_id, state) values ($addr,$ltype,1,0);"
# run_statement "#2" "$qry"
#
# qry="select leases from lease6_stat where subnet_id = 1 and lease_type = $ltype and state = 0";
# run_statement "#3" "$qry" 1
run_statement() {
hdr="$1";shift;
qry="$1";shift;
exp_value="$1";
# Execute the statment
value=`mysql_execute "${qry}"`
ERRCODE=$?
# Execution should succeed
assert_eq 0 $ERRCODE "$hdr: SQL=[$qry] failed: (expected status code %d, returned %d)"
# If there's an expected value, test it
if [ "x$exp_value" != "x" ]
then
assert_str_eq "$exp_value" "$value" "$hdr: SQL=[$qry] wrong: (expected value %s, returned %s)"
fi
}
# Wipe all tables from the DB:
mysql_wipe() {
printf "Wiping whole database %s\n" $db_name
......@@ -189,7 +221,7 @@ mysql_upgrade_test() {
mysql -u$db_user -p$db_password $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_password -n $db_name -d $db_scripts_dir)
version=$(${keaadmin} lease-version mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir)
assert_str_eq "1.0" ${version} "Expected kea-admin to return %s, returned value was %s"
......@@ -319,14 +351,14 @@ EOF
assert_eq 0 $ERRCODE "select from dhcp_option_scope failed. (expected status code %d, returned %d)"
assert_eq 4 "$count" "dhcp_option_scope does not contain correct number of entries. (expected %d, returned %d)"
#table: scope_id columns to dhcp4_options (upgrade 4.1 -> 5.0)
#table: scope_id columns to dhcp4_options (upgrade 4.1 -> 5.0)
# verify that dhcp4_options table includes scope_id
qry="select scope_id from dhcp4_options";
count=`mysql_execute "${qry}"`
ERRCODE=$?
assert_eq 0 $ERRCODE "select scope_id from dhcp4_options failed. (expected status code %d, returned %d)"
#table: scope_id columns to dhcp6_options (upgrade 4.1 -> 5.0)
#table: scope_id columns to dhcp6_options (upgrade 4.1 -> 5.0)
# verify that dhcp6_options table includes scope_id
qry="select scope_id from dhcp6_options";
count=`mysql_execute "${qry}"`
......@@ -362,7 +394,7 @@ EOF
ERRCODE=$?
assert_eq 0 $ERRCODE "select from host_identifier_type failed. (expected status code %d, returned %d)"
assert_eq 5 "$count" "host_identifier_type does not contain correct number of entries. (expected count %d, returned %d)"
#table: user_context columns to hosts, dhcp4_options and dhcp6_options (upgrade 5.2 -> 6.0)
# verify that hosts table includes user_context
qry="select user_context from hosts";
......@@ -382,6 +414,8 @@ EOF
ERRCODE=$?
assert_eq 0 $ERRCODE "select user_context from dhcp6_options failed. (expected status code %d, returned %d)"
# lease4/6_stats changes are tested separately
# Verify upgraded schema reports version 6.0
version=$(${keaadmin} lease-version mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir)
assert_str_eq "6.0" ${version} "Expected kea-admin to return %s, returned value was %s"
......@@ -512,6 +546,276 @@ insert into lease6 values(12,21,30,'2015-06-06 11:01:07',40,50,1,60,70,1,1,'thre
test_finish 0
}
# Verifies lease4_stat trigger operations on
# an new, empty database. It inserts, updates, and
# deletes various leases, checking lease4_stat
# values along the way.
mysql_lease4_stat_test() {
test_start "mysql.lease4_stat_test"
# Let's wipe the whole database
mysql_wipe
# Ok, now let's initialize the database
${keaadmin} lease-init mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir
ERRCODE=$?
assert_eq 0 $ERRCODE "kea-admin lease-init mysql returned non-zero status code %d, expected %d"
# Verify lease4 stat table is present
qry="select count(subnet_id) from lease4_stat";
run_statement "#1" "$qry" 0
# Insert lease4
qry="insert into lease4 (address, subnet_id, state) values (111,1,0);"
run_statement "#2" "$qry"
# Assigned state count should be 1
qry="select leases from lease4_stat where subnet_id = 1 and state = 0";
run_statement "#3" "$qry" 1
# Set lease state to declined
qry="update lease4 set state = 1 where address = 111;"
run_statement "#4" "$qry"
# Leases state count for assigned should be 0
qry="select leases from lease4_stat where subnet_id = 1 and state = 0";
run_statement "#5" "$qry" 0
# Leases state count for declined should be 1
qry="select leases from lease4_stat where subnet_id = 1 and state = 1";
run_statement "#6" "$qry" 1
# Delete the lease
qry="delete from lease4 where address = 111;"
run_statement "#7" "$qry"
# Leases state count for declined should be 0
qry="select leases from lease4_stat where subnet_id = 1 and state = 1";
run_statement "#8" "$qry" 0
# Let's wipe the whole database
mysql_wipe
test_finish 0
}
# Verifies that lease6_stat triggers operate correctly
# for using a given address and lease_type. It will
# insert a lease, update it, and delete checking the
# lease stat counts along the way. It assumes the
# database has been created but is empty.
# param addr - address to use to add to subnet 1
# param ltype - type of lease to create
mysql_lease6_stat_per_type() {
addr=$1;shift;
ltype=$1;
# insert a lease6 for addr and ltype, state assigned
qry="insert into lease6 (address, lease_type, subnet_id, state) values ($addr,$ltype,1,0);"
run_statement "#2" "$qry"
# assigned stat should be 1
qry="select leases from lease6_stat where subnet_id = 1 and lease_type = $ltype and state = 0";
run_statement "#3" "$qry" 1
# update the lease, changing state to declined
qry="update lease6 set state = 1 where address = $addr;"
run_statement "#4" "$qry"
# leases stat for assigned state should be 0
qry="select leases from lease6_stat where subnet_id = 1 and lease_type = $ltype and state = 0";
run_statement "#5" "$qry" 0
# leases count for declined state should be 1
qry="select leases from lease6_stat where subnet_id = 1 and lease_type = $ltype and state = 1";
run_statement "#6" "$qry" 1
# delete the lease
qry="delete from lease6 where address = 111;"
run_statement "#7" "$qry"
# leases count for declined state should be 0
qry="select leases from lease6_stat where subnet_id = 1 and lease_type = $ltype and state = 0";
run_statement "#6" "$qry" 0
}
# Verifies that lease6_stat triggers operation correctly
# for both NA and PD lease types, mysql_lease6_stat_per_type()
mysql_lease6_stat_test() {
test_start "mysql.lease6_stat_test"
# Let's wipe the whole database
mysql_wipe
# Ok, now let's initialize the database
${keaadmin} lease-init mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir
ERRCODE=$?
assert_eq 0 $ERRCODE "kea-admin lease-init mysql returned non-zero status code %d, expected %d"
# verify lease6 stat table is present
qry="select count(subnet_id) from lease6_stat"
run_statement "#1" "$qry"
# Test for address 111, NA lease type
mysql_lease6_stat_per_type "111" "0"
# Test for address 222, PD lease type
mysql_lease6_stat_per_type "222" "1"
# Let's wipe the whole database
mysql_wipe
test_finish 0
}
# Verifies that you can upgrade from earlier version and
# lease<4/6>_stat tables will be populated based on existing
# leases and that the stat triggers work properly.
mysql_lease_stat_upgrade_test() {
test_start "my_sql_lease_stat_upgrade_test"
# Let's wipe the whole database
mysql_wipe
# We need to create an older database with lease data so we can
# verify the upgrade mechanisms which prepopulate the lease stat
# tables.
#
# Initialize database to scheme 5.1. We need a schema that has lease state
# might as well used the one right before 6.0 which adds lease4/6_stat stuff.
mysql -u$db_user -p$db_password $db_name < @abs_top_srcdir@/src/bin/admin/tests/dhcpdb_create_5.1.mysql
# Sanity check - verify that it reports version 5.1
version=$(${keaadmin} lease-version mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir)
assert_str_eq "5.1" ${version} "Expected kea-admin to return %s, returned value was %s"
# Now we need insert some leases to "migrate" for both v4 and v6
qry=\
"insert into lease4 (address, subnet_id, state) values (111,10,0);\
insert into lease4 (address, subnet_id, state) values (222,10,0);\
insert into lease4 (address, subnet_id, state) values (333,10,1);\
insert into lease4 (address, subnet_id, state) values (444,10,2);\
insert into lease4 (address, subnet_id, state) values (555,77,0);"
run_statement "insert v4 leases" "$qry"
qry=\
"insert into lease6 (address, lease_type, subnet_id, state) values (111,0,40,0);\
insert into lease6 (address, lease_type, subnet_id, state) values (222,0,40,1);\
insert into lease6 (address, lease_type, subnet_id, state) values (333,1,40,0);\
insert into lease6 (address, lease_type, subnet_id, state) values (444,1,50,0);\
insert into lease6 (address, lease_type, subnet_id, state) values (555,1,50,0);\
insert into lease6 (address, lease_type, subnet_id, state) values (666,1,40,2);"
run_statement "insert v6 leases" "$qry"
# Ok, we have a 5.1 database with leases. Let's upgrade it to 6.0
${keaadmin} lease-upgrade mysql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir
ERRCODE=$?
#
# First we'll verify lease4_stats are correct after migration.
#
# Assigned leases for subnet 10 should be 2
qry="select leases from lease4_stat where subnet_id = 10 and state = 0"
run_statement "#4.1" "$qry" 2
# Assigned leases for subnet 77 should be 1
qry="select leases from lease4_stat where subnet_id = 77 and state = 0"
run_statement "#4.2" "$qry" 1
# Should be no records for EXPIRED
qry="select count(subnet_id) from lease4_stat where state = 2"
run_statement "#4.3" "$qry" 0
#
# Now we'll verify v4 trigger operation for insert,update, and delete
#
# Insert a new lease subnet 77
qry="insert into lease4 (address, subnet_id, state) values (777,77,0);"
run_statement "#4.4" "$qry"
# Assigned count for subnet 77 should be 2
qry="select leases from lease4_stat where subnet_id = 77 and state = 0"
run_statement "#4.5" "$qry" 2
# Update the state of the new lease to declined
qry="update lease4 set state = 1 where address = 777;"
run_statement "#4.6" "$qry"
# Assigned count for subnet 77 should be 1 again
qry="select leases from lease4_stat where subnet_id = 77 and state = 0"
run_statement "#4.7" "$qry" 1
# Declined count for subnet 77 should be 1
qry="select leases from lease4_stat where subnet_id = 77 and state = 1"
run_statement "#4.8" "$qry" 1
# Delete the lease.
qry="delete from lease4 where address = 777;"
run_statement "#4.9" "$qry"
# Declined count for subnet 77 should be 0
qry="select leases from lease4_stat where subnet_id = 77 and state = 1"
run_statement "#4.10" "$qry" 0
#
# Next we'll verify lease6_stats are correct after migration.
#
# Assigned leases for subnet 40 should be 1
qry="select leases from lease6_stat where subnet_id = 40 and lease_type = 0 and state = 0"
run_statement "#6.1" "$qry" 1
# Assigned (PD) leases for subnet 40 should be 1
qry="select leases from lease6_stat where subnet_id = 40 and lease_type = 1 and state = 0"
run_statement "#6.2" "$qry" 1
# Declined leases for subnet 40 should be 1
qry="select leases from lease6_stat where subnet_id = 40 and lease_type = 0 and state = 1"
run_statement "#6.3" "$qry" 1
# Assigned (PD) leases for subnet 50 should be 2
qry="select leases from lease6_stat where subnet_id = 50 and lease_type = 1 and state = 0"
run_statement "#6.4" "$qry" 2
# Should be no records for EXPIRED
qry="select count(subnet_id) from lease4_stat where state = 2"
run_statement "#6.5" "$qry" 0
#
# Finally we'll verify v6 trigger operation for insert,update, and delete
#
# Insert a new lease subnet 50
qry="insert into lease6 (address, subnet_id, lease_type, state) values (777,50,1,0);"
run_statement "#6.5" "$qry"
# Assigned count for subnet 50 should be 3
qry="select leases from lease6_stat where subnet_id = 50 and lease_type = 1 and state = 0"
run_statement "#6.6" "$qry" 3
# Update the state of the new lease to expired
qry="update lease6 set state = 2 where address = 777;"
run_statement "#6.7" "$qry"
# Assigned count for subnet 50 should be 2 again
qry="select leases from lease6_stat where subnet_id = 50 and lease_type = 1 and state = 0"
run_statement "#6.8" "$qry" 2
# Delete another PD lease.
qry="delete from lease6 where address = 555;"
run_statement "#6.9" "$qry"
# Assigned leases for subnet 50 should be 1
qry="select leases from lease6_stat where subnet_id = 50 and lease_type = 1 and state = 0"
run_statement "#6.10" "$qry" 1
# Let's wipe the whole database
mysql_wipe
}
mysql_lease_init_test
mysql_host_reservation_init_test
......@@ -519,3 +823,6 @@ mysql_lease_version_test
mysql_upgrade_test
mysql_lease4_dump_test
mysql_lease6_dump_test
mysql_lease4_stat_test
mysql_lease6_stat_test
mysql_lease_stat_upgrade_test
......@@ -175,6 +175,21 @@ CREATE TRIGGER stat_lease6_delete AFTER DELETE ON lease6
END $$
DELIMITER ;
# Populate lease4_stat table based on existing leases
# We only care about assigned and declined states
INSERT INTO lease4_stat (subnet_id, state, leases)
SELECT subnet_id, state, count(state)
FROM lease4 WHERE state < 2
GROUP BY subnet_id, state ORDER BY subnet_id;
# Populate lease6_stat table based on existing leases
# We only care about assigned and declined states
INSERT INTO lease6_stat (subnet_id, lease_type, state, leases)
SELECT subnet_id, lease_type, state, count(state)
FROM lease6 WHERE state < 2
GROUP BY subnet_id, lease_type, state
ORDER BY subnet_id;
# Update the schema version number
UPDATE schema_version
SET version = '6', minor = '0';
......
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