From: Thomas Markwalder Date: Wed, 9 May 2018 18:36:37 +0000 (-0400) Subject: [5587] PostgreSQL support for shared lease stats implementation X-Git-Tag: trac5549a_base~30^2~1^2~1 X-Git-Url: http://git.ipfire.org/cgi-bin/gitweb.cgi?a=commitdiff_plain;h=b0bea19c4867e1aaeee0629f75066f005f119a7e;p=thirdparty%2Fkea.git [5587] PostgreSQL support for shared lease stats implementation src/share/database/scripts/pgsql/dhcpdb_create.pgsql Adds lease<4/6>_stat tables and triggers src/share/database/scripts/pgsql/dhcpdb_drop.pgsql Added drops for lease<4/6>_stat tables and triggers src/share/database/scripts/pgsql/upgrade_3.3_to_4.0.sh.in Adds lease<4/6>_stat tables and triggers Populates stat tables from existing lease table content src/bin/admin/tests/mysql_tests.sh.in mysql_lease6_stat_per_type() - fixed typo in test src/bin/admin/tests/pgsql_tests.sh.in run_statement() - new convenience fucntion for running statement with option expected outcome pgsql_upgrade_schema_to_version() - new function which converts the existing schema to a target version pgsql_lease4_stat_test() - tests v4 stat table and triggers in an new database pgsql_lease6_stat_test() - tests v6 stat table and triggers in an new database. pgsql_lease6_stat_per_type() - helper function which tests v6 stat table and triggers using a given address and lease type pgsql_lease_stat_upgrade_test() - tests data migration, stat table and trigger operations on an upgraded database src/lib/dhcpsrv/pgsql_lease_mgr.* Added new SQL statements for lease stats queries PgSqlLeaseStatsQuery Constructors - added variants to support where clause params start() - modified to support query variants based on where clause params PgSqlLeaseMgr Added start variants: - startSubnetLeaseStatsQuery4(const SubnetID& subnet_id) - startSubnetRangeLeaseStatsQuery4(const SubnetID& first_subnet_id, const SubnetID& last_subnet_id) src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc New unit tests: - TEST_F(PgSqlLeaseMgrTest, leaseStatsQuery4) - TEST_F(PgSqlLeaseMgrTest, leaseStatsQuery6) --- diff --git a/src/bin/admin/tests/mysql_tests.sh.in b/src/bin/admin/tests/mysql_tests.sh.in index 53ce61f738..85c1a9558f 100644 --- a/src/bin/admin/tests/mysql_tests.sh.in +++ b/src/bin/admin/tests/mysql_tests.sh.in @@ -664,7 +664,7 @@ mysql_lease6_stat_per_type() { run_statement "#6" "$qry" 1 # delete the lease - qry="delete from lease6 where address = 111;" + qry="delete from lease6 where address = $addr;" run_statement "#7" "$qry" # leases count for declined state should be 0 diff --git a/src/bin/admin/tests/pgsql_tests.sh.in b/src/bin/admin/tests/pgsql_tests.sh.in index 0e95d2fe23..da1651119c 100644 --- a/src/bin/admin/tests/pgsql_tests.sh.in +++ b/src/bin/admin/tests/pgsql_tests.sh.in @@ -1,6 +1,6 @@ #!/bin/sh -# Copyright (C) 2015-2017 Internet Systems Consortium, Inc. ("ISC") +# Copyright (C) 2015-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 @@ -23,6 +23,37 @@ db_host="localhost" # 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=`pgsql_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: pgsql_wipe() { printf "Wiping whole database %s\n" $db_name @@ -437,8 +468,319 @@ sed 's//$local_timestamp3/g' " test_finish 0 } +# Upgrades an existing schema to a target newer version +# param target_version - desired schema version as "major.minor" +pgsql_upgrade_schema_to_version() { + target_version=$1 + + # Check if the scripts directory exists at all. + if [ ! -d ${db_scripts_dir}/pgsql ]; then + log_error "Invalid scripts directory: ${db_scripts_dir}/pgsql" + exit 1 + fi + + # Check if there are any files in it + num_files=$(find ${db_scripts_dir}/pgsql/upgrade*.sh -type f | wc -l) + if [ $num_files -eq 0 ]; then + log_error "No scripts in ${db_scripts_dir}/pgsql?" + 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 ${db_scripts_dir}/pgsql/upgrade*.sh + do + if [ $version = "$target_version" ] + then + break; + fi + + echo "Processing $script file..." + sh ${script} -U ${db_user} -h ${db_host} -d ${db_name} + + version=`pgsql_version` + done + + echo "Schema upgraded to $version" +} + +# Verifies lease4_stat trigger operations on +# an new, empty database. It inserts, updates, and +# deletes various leases, checking lease4_stat +# values along the way. +pgsql_lease4_stat_test() { + test_start "pgsql.lease4_stat_test" + + # Let's wipe the whole database + pgsql_wipe + + # Ok, now let's initialize the database + ${keaadmin} lease-init pgsql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir + ERRCODE=$? + assert_eq 0 $ERRCODE "kea-admin lease-init pgsql 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 + pgsql_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 +pgsql_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 = '$addr';" + 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, pgsql_lease6_stat_per_type() +pgsql_lease6_stat_test() { + + test_start "pgsql.lease6_stat_test" + + # Let's wipe the whole database + pgsql_wipe + + # Ok, now let's initialize the database + ${keaadmin} lease-init pgsql -u $db_user -p $db_password -n $db_name -d $db_scripts_dir + ERRCODE=$? + + assert_eq 0 $ERRCODE "kea-admin lease-init pgsql 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 + pgsql_lease6_stat_per_type "111" "0" + + # Test for address 222, PD lease type + pgsql_lease6_stat_per_type "222" "1" + + # Let's wipe the whole database + pgsql_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. +pgsql_lease_stat_upgrade_test() { + test_start "pgsql.lease_stat_upgrade_test" + + # Let's wipe the whole database + pgsql_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 1.0. + pgsql_execute_script @abs_top_srcdir@/src/bin/admin/tests/dhcpdb_create_1.0.pgsql + assert_eq 0 $? "cannot initialize 1.0 database, expected exit code: %d, actual: %d" + + # Now upgrade to schema 2.0, this has lease_state in it + pgsql_upgrade_schema_to_version 2.0 + + # 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 4.0 database with leases. Let's upgrade it to 6.0 + ${keaadmin} lease-upgrade pgsql -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 + pgsql_wipe +} + pgsql_lease_init_test pgsql_lease_version_test pgsql_upgrade_test pgsql_lease4_dump_test pgsql_lease6_dump_test +pgsql_lease4_stat_test +pgsql_lease6_stat_test +pgsql_lease_stat_upgrade_test diff --git a/src/lib/dhcpsrv/pgsql_lease_mgr.cc b/src/lib/dhcpsrv/pgsql_lease_mgr.cc index dba13520cf..1929bae8ed 100644 --- a/src/lib/dhcpsrv/pgsql_lease_mgr.cc +++ b/src/lib/dhcpsrv/pgsql_lease_mgr.cc @@ -251,20 +251,49 @@ PgSqlTaggedStatement tagged_statements[] = { "hwaddr = $13, hwtype = $14, hwaddr_source = $15, " "state = $16 " "WHERE address = $17"}, - - // RECOUNT_LEASE4_STATS, + // ALL_LEASE4_STATS { 0, { OID_NONE }, - "recount_lease4_stats", - "SELECT subnet_id, state, count(state) as state_count " - "FROM lease4 GROUP BY subnet_id, state ORDER BY subnet_id"}, + "all_lease4_stats", + "SELECT subnet_id, state, leases as state_count" + " FROM lease4_stat ORDER BY subnet_id, state"}, - // RECOUNT_LEASE6_STATS, + // SUBNET_LEASE4_STATS + { 1, { OID_INT8 }, + "subnet_lease4_stats", + "SELECT subnet_id, state, leases as state_count" + " FROM lease4_stat " + " WHERE subnet_id = $1 " + " ORDER BY state"}, + + // SUBNET_RANGE_LEASE4_STATS + { 2, { OID_INT8, OID_INT8 }, + "subnet_range_lease4_stats", + "SELECT subnet_id, state, leases as state_count" + " FROM lease4_stat " + " WHERE subnet_id >= $1 and subnet_id <= $2 " + " ORDER BY subnet_id, state"}, + + // ALL_LEASE6_STATS, { 0, { OID_NONE }, - "recount_lease6_stats", - "SELECT subnet_id, lease_type, state, count(state) as state_count " - "FROM lease6 GROUP BY subnet_id, lease_type, state " - "ORDER BY subnet_id"}, + "all_lease6_stats", + "SELECT subnet_id, lease_type, state, leases as state_count" + " FROM lease6_stat ORDER BY subnet_id, lease_type, state" }, + // SUBNET_LEASE6_STATS + { 1, { OID_INT8 }, + "subnet_lease6_stats", + "SELECT subnet_id, lease_type, state, leases as state_count" + " FROM lease6_stat " + " WHERE subnet_id = $1 " + " ORDER BY lease_type, state" }, + + // SUBNET_RANGE_LEASE6_STATS + { 2, { OID_INT8, OID_INT8 }, + "subnet_range_lease6_stats", + "SELECT subnet_id, lease_type, state, leases as state_count" + " FROM lease6_stat " + " WHERE subnet_id >= $1 and subnet_id <= $2 " + " ORDER BY subnet_id, lease_type, state" }, // End of list sentinel { 0, { 0 }, NULL, NULL} }; @@ -814,7 +843,9 @@ private: /// class PgSqlLeaseStatsQuery : public LeaseStatsQuery { public: - /// @brief Constructor + /// @brief Constructor to query for all subnets' stats + /// + /// The query created will return statistics for all subnets /// /// @param conn A open connection to the database housing the lease data /// @param statement The lease data SQL prepared statement to execute @@ -826,18 +857,75 @@ public: fetch_type_(fetch_type) { } + /// @brief Constructor to query for a single subnet's stats + /// + /// The query created will return statistics for a single subnet + /// + /// @param conn A open connection to the database housing the lease data + /// @param statement The lease data SQL prepared statement to execute + /// @param fetch_type Indicates if query supplies lease type + /// @param subnet_id id of the subnet for which stats are desired + PgSqlLeaseStatsQuery(PgSqlConnection& conn, PgSqlTaggedStatement& statement, + const bool fetch_type, const SubnetID& subnet_id) + : LeaseStatsQuery(subnet_id), conn_(conn), statement_(statement), result_set_(), + next_row_(0), fetch_type_(fetch_type) { + } + + /// @brief Constructor to query for the stats for a range of subnets + /// + /// The query created will return statistics for the inclusive range of + /// subnets described by first and last sunbet IDs. + /// + /// @param conn A open connection to the database housing the lease data + /// @param statement The lease data SQL prepared statement to execute + /// @param fetch_type Indicates if query supplies lease type + /// @param first_subnet_id first subnet in the range of subnets + /// @param last_subnet_id last subnet in the range of subnets + PgSqlLeaseStatsQuery(PgSqlConnection& conn, PgSqlTaggedStatement& statement, + const bool fetch_type, const SubnetID& first_subnet_id, + const SubnetID& last_subnet_id) + : LeaseStatsQuery(first_subnet_id, last_subnet_id), conn_(conn), statement_(statement), + result_set_(), next_row_(0), fetch_type_(fetch_type) { + } + /// @brief Destructor virtual ~PgSqlLeaseStatsQuery() {}; /// @brief Creates the lease statistical data result set /// /// The result set is populated by executing a prepared SQL query - /// against the database which sums the leases per lease state per - /// subnet id. + /// against the database fetches the lease count per lease state per + /// (per least type - v6 only) per subnet id. + /// + /// Depending upon the selection mode, the query will have either no + /// parameters (for all subnets), a subnet id for a single subnet, or + /// a first and last subnet id for a subnet range. void start() { - // The query has no parameters, so we only need it's name. - result_set_.reset(new PgSqlResult(PQexecPrepared(conn_, statement_.name, - 0, NULL, NULL, NULL, 0))); + + if (getSelectMode() == ALL_SUBNETS) { + // Run the query with no where clause parameters. + result_set_.reset(new PgSqlResult(PQexecPrepared(conn_, statement_.name, + 0, 0, 0, 0, 0))); + } else { + // Set up the WHERE clause values + PsqlBindArray parms; + + // Add first_subnet_id used by both single and range. + std::string subnet_id_str = boost::lexical_cast(getFirstSubnetID()); + parms.add(subnet_id_str); + + // Add last_subnet_id for range. + if (getSelectMode() == SUBNET_RANGE) { + // Add last_subnet_id used by range. + string subnet_id_str = boost::lexical_cast(getLastSubnetID()); + parms.add(subnet_id_str); + } + + // Run the query with where clause parameters. + result_set_.reset(new PgSqlResult(PQexecPrepared(conn_, statement_.name, + parms.size(), &parms.values_[0], + &parms.lengths_[0], &parms.formats_[0], 0))); + } conn_.checkStatementError(*result_set_, statement_); } @@ -1511,9 +1599,26 @@ PgSqlLeaseMgr::deleteExpiredReclaimedLeasesCommon(const uint32_t secs, LeaseStatsQueryPtr PgSqlLeaseMgr::startLeaseStatsQuery4() { LeaseStatsQueryPtr query( - new PgSqlLeaseStatsQuery(conn_, - tagged_statements[RECOUNT_LEASE4_STATS], - false)); + new PgSqlLeaseStatsQuery(conn_, tagged_statements[ALL_LEASE4_STATS], false)); + query->start(); + return(query); +} + +LeaseStatsQueryPtr +PgSqlLeaseMgr::startSubnetLeaseStatsQuery4(const SubnetID& subnet_id) { + LeaseStatsQueryPtr query( + new PgSqlLeaseStatsQuery(conn_, tagged_statements[SUBNET_LEASE4_STATS], + false, subnet_id)); + query->start(); + return(query); +} + +LeaseStatsQueryPtr +PgSqlLeaseMgr::startSubnetRangeLeaseStatsQuery4(const SubnetID& first_subnet_id, + const SubnetID& last_subnet_id) { + LeaseStatsQueryPtr query( + new PgSqlLeaseStatsQuery(conn_, tagged_statements[SUBNET_RANGE_LEASE4_STATS], + false, first_subnet_id, last_subnet_id)); query->start(); return(query); } @@ -1521,9 +1626,26 @@ PgSqlLeaseMgr::startLeaseStatsQuery4() { LeaseStatsQueryPtr PgSqlLeaseMgr::startLeaseStatsQuery6() { LeaseStatsQueryPtr query( - new PgSqlLeaseStatsQuery(conn_, - tagged_statements[RECOUNT_LEASE6_STATS], - true)); + new PgSqlLeaseStatsQuery(conn_, tagged_statements[ALL_LEASE6_STATS], true)); + query->start(); + return(query); +} + +LeaseStatsQueryPtr +PgSqlLeaseMgr::startSubnetLeaseStatsQuery6(const SubnetID& subnet_id) { + LeaseStatsQueryPtr query( + new PgSqlLeaseStatsQuery(conn_, tagged_statements[SUBNET_LEASE6_STATS], + true, subnet_id)); + query->start(); + return(query); +} + +LeaseStatsQueryPtr +PgSqlLeaseMgr::startSubnetRangeLeaseStatsQuery6(const SubnetID& first_subnet_id, + const SubnetID& last_subnet_id) { + LeaseStatsQueryPtr query( + new PgSqlLeaseStatsQuery(conn_, tagged_statements[SUBNET_RANGE_LEASE6_STATS], + true, first_subnet_id, last_subnet_id)); query->start(); return(query); } diff --git a/src/lib/dhcpsrv/pgsql_lease_mgr.h b/src/lib/dhcpsrv/pgsql_lease_mgr.h index badc4efb39..e36abf02c3 100644 --- a/src/lib/dhcpsrv/pgsql_lease_mgr.h +++ b/src/lib/dhcpsrv/pgsql_lease_mgr.h @@ -338,22 +338,65 @@ public: /// /// It creates an instance of a PgSqlLeaseStatsQuery4 and then /// invokes its start method, which fetches its statistical data - /// result set by executing the RECOUNT_LEASE_STATS4 query. + /// result set by executing the ALL_LEASE_STATS4 query. /// The query object is then returned. /// /// @return The populated query as a pointer to an LeaseStatsQuery virtual LeaseStatsQueryPtr startLeaseStatsQuery4(); + /// @brief Creates and runs the IPv4 lease stats query for a single subnet + /// + /// It creates an instance of a PgSqlLeaseStatsQuery4 for a single subnet + /// query and then invokes its start method in which the query constructs its + /// statistical data result set. The query object is then returned. + /// + /// @param subnet_id id of the subnet for which stats are desired + /// @return A populated LeaseStatsQuery + virtual LeaseStatsQueryPtr startSubnetLeaseStatsQuery4(const SubnetID& subnet_id); + + + /// @brief Creates and runs the IPv4 lease stats query for a single subnet + /// + /// It creates an instance of a PgSqlLeaseStatsQuery4 for a subnet range + /// query and then invokes its start method in which the query constructs its + /// statistical data result set. The query object is then returned. + /// + /// @param first_subnet_id first subnet in the range of subnets + /// @param last_subnet_id last subnet in the range of subnets + /// @return A populated LeaseStatsQuery + virtual LeaseStatsQueryPtr startSubnetRangeLeaseStatsQuery4(const SubnetID& first_subnet_id, + const SubnetID& last_subnet_id); /// @brief Creates and runs the IPv6 lease stats query /// /// It creates an instance of a PgSqlLeaseStatsQuery and then /// invokes its start method, which fetches its statistical data - /// result set by executing the RECOUNT_LEASE_STATS6 query. + /// result set by executing the ALL_LEASE_STATS6 query. /// The query object is then returned. /// /// @return The populated query as a pointer to an LeaseStatsQuery virtual LeaseStatsQueryPtr startLeaseStatsQuery6(); + /// @brief Creates and runs the IPv6 lease stats query for a single subnet + /// + /// It creates an instance of a PgSqlLeaseStatsQuery6 for a single subnet + /// query and then invokes its start method in which the query constructs its + /// statistical data result set. The query object is then returned. + /// + /// @param subnet_id id of the subnet for which stats are desired + /// @return A populated LeaseStatsQuery + virtual LeaseStatsQueryPtr startSubnetLeaseStatsQuery6(const SubnetID& subnet_id); + + /// @brief Creates and runs the IPv6 lease stats query for a single subnet + /// + /// It creates an instance of a PgSqlLeaseStatsQuery6 for a subnet range + /// query and then invokes its start method in which the query constructs its + /// statistical data result set. The query object is then returned. + /// + /// @param first_subnet_id first subnet in the range of subnets + /// @param last_subnet_id last subnet in the range of subnets + /// @return A populated LeaseStatsQuery + virtual LeaseStatsQueryPtr startSubnetRangeLeaseStatsQuery6(const SubnetID& first_subnet_id, + const SubnetID& last_subnet_id); /// @brief Removes specified IPv4 leases. /// /// This rather dangerous method is able to remove all leases from specified @@ -448,8 +491,12 @@ public: INSERT_LEASE6, // Add entry to lease6 table UPDATE_LEASE4, // Update a Lease4 entry UPDATE_LEASE6, // Update a Lease6 entry - RECOUNT_LEASE4_STATS, // Fetch IPv4 lease statistical data - RECOUNT_LEASE6_STATS, // Fetch IPv4 lease statistical data + ALL_LEASE4_STATS, // Fetches IPv4 lease statistics + SUBNET_LEASE4_STATS, // Fetched IPv4 lease stats for a single subnet. + SUBNET_RANGE_LEASE4_STATS, // Fetched IPv4 lease stats for a subnet range. + ALL_LEASE6_STATS, // Fetches IPv6 lease statistics + SUBNET_LEASE6_STATS, // Fetched IPv6 lease stats for a single subnet. + SUBNET_RANGE_LEASE6_STATS, // Fetched IPv6 lease stats for a subnet range. NUM_STATEMENTS // Number of statements }; diff --git a/src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc b/src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc index d4b1e0df50..f0b3ec7b47 100644 --- a/src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc +++ b/src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc @@ -530,4 +530,14 @@ TEST_F(PgSqlLeaseMgrTest, DISABLED_wipeLeases6) { testWipeLeases6(); } +// Tests v4 lease stats query variants. +TEST_F(PgSqlLeaseMgrTest, leaseStatsQuery4) { + testLeaseStatsQuery4(); +} + +// Tests v6 lease stats query variants. +TEST_F(PgSqlLeaseMgrTest, leaseStatsQuery6) { + testLeaseStatsQuery6(); +} + } // namespace diff --git a/src/share/database/scripts/pgsql/dhcpdb_create.pgsql b/src/share/database/scripts/pgsql/dhcpdb_create.pgsql index 58809c36b7..a525b80915 100644 --- a/src/share/database/scripts/pgsql/dhcpdb_create.pgsql +++ b/src/share/database/scripts/pgsql/dhcpdb_create.pgsql @@ -570,6 +570,184 @@ CREATE INDEX lease6_by_subnet_id_lease_type ON lease6 (subnet_id, lease_type); DROP INDEX lease6_by_iaid_subnet_id_duid; CREATE INDEX lease6_by_duid_iaid_subnet_id ON lease6 (duid, iaid, subnet_id); +-- Create v4 lease statistics table +CREATE TABLE lease4_stat ( + subnet_id BIGINT NOT NULL, + state INT8 NOT NULL, + leases BIGINT, + PRIMARY KEY (subnet_id, state) +); + +-- +-- Create v4 insert trigger procedure +CREATE FUNCTION proc_stat_lease4_insert () RETURNS trigger AS $stat_lease4_insert$ +BEGIN + IF NEW.state < 2 THEN + UPDATE lease4_stat + SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND state = NEW.state; + + IF NOT FOUND THEN + INSERT INTO lease4_stat VALUES (new.subnet_id, new.state, 1); + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease4_insert$ LANGUAGE plpgsql; + +-- Create v4 insert trigger procedure +CREATE TRIGGER stat_lease4_insert +AFTER INSERT ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_insert(); + +-- +-- Create v4 update trigger procedure +CREATE FUNCTION proc_stat_lease4_update () RETURNS trigger AS $stat_lease4_update$ +BEGIN + IF OLD.state != NEW.state THEN + IF OLD.state < 2 THEN + -- Decrement the old state count if record exists + UPDATE lease4_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND state = OLD.state; + END IF; + + IF NEW.state < 2 THEN + -- Increment the new state count if record exists + UPDATE lease4_stat SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND state = NEW.state; + + -- Insert new state record if it does not exist + IF NOT FOUND THEN + INSERT INTO lease4_stat VALUES (NEW.subnet_id, NEW.state, 1); + END IF; + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease4_update$ LANGUAGE plpgsql; + +-- Create v4 update trigger +CREATE TRIGGER stat_lease4_update +AFTER UPDATE ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_update(); + + +-- +-- Create the v4 delete trigger procedure +CREATE FUNCTION proc_stat_lease4_delete () RETURNS trigger AS $stat_lease4_delete$ +BEGIN + IF OLD.state < 2 THEN + -- Decrement the state count if record exists + UPDATE lease4_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND OLD.state = state; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease4_delete$ LANGUAGE plpgsql; + +-- Create the v4 delete trigger +CREATE TRIGGER stat_lease4_delete +AFTER DELETE ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_delete(); + +-- Create v6 lease statistics table +CREATE TABLE lease6_stat ( + subnet_id BIGINT NOT NULL, + lease_type SMALLINT NOT NULL, + state INT8 NOT NULL, + leases BIGINT, + PRIMARY KEY (subnet_id, lease_type, state) +); + +-- +-- Create v6 insert trigger procedure +CREATE FUNCTION proc_stat_lease6_insert () RETURNS trigger AS $stat_lease6_insert$ +BEGIN + IF NEW.state < 2 THEN + UPDATE lease6_stat + SET leases = leases + 1 + WHERE + subnet_id = NEW.subnet_id AND lease_type = NEW.lease_type + AND state = NEW.state; + + IF NOT FOUND THEN + INSERT INTO lease6_stat + VALUES (NEW.subnet_id, NEW.lease_type, NEW.state, 1); + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease6_insert$ LANGUAGE plpgsql; + +-- Create v6 insert trigger procedure +CREATE TRIGGER stat_lease6_insert +AFTER INSERT ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_insert(); + +-- +-- Create v6 update trigger procedure +CREATE FUNCTION proc_stat_lease6_update () RETURNS trigger AS $stat_lease6_update$ +BEGIN + IF OLD.state != NEW.state THEN + IF OLD.state < 2 THEN + -- Decrement the old state count if record exists + UPDATE lease6_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND lease_type = OLD.lease_type + AND state = OLD.state; + END IF; + + IF NEW.state < 2 THEN + -- Increment the new state count if record exists + UPDATE lease6_stat SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND lease_type = NEW.lease_type + AND state = NEW.state; + + -- Insert new state record if it does not exist + IF NOT FOUND THEN + INSERT INTO lease6_stat VALUES (NEW.subnet_id, NEW.lease_type, NEW.state, 1); + END IF; + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease6_update$ LANGUAGE plpgsql; + +-- Create v6 update trigger +CREATE TRIGGER stat_lease6_update +AFTER UPDATE ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_update(); + +-- +-- Create the v6 delete trigger procedure +CREATE FUNCTION proc_stat_lease6_delete() RETURNS trigger AS $stat_lease6_delete$ +BEGIN + IF OLD.state < 2 THEN + -- Decrement the state count if record exists + UPDATE lease6_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND lease_type = OLD.lease_type + AND OLD.state = state; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +$stat_lease6_delete$ LANGUAGE plpgsql; + +-- Create the v6 delete trigger +CREATE TRIGGER stat_lease6_delete +AFTER DELETE ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_delete(); + -- Set 4.0 schema version. UPDATE schema_version SET version = '4', minor = '0'; diff --git a/src/share/database/scripts/pgsql/dhcpdb_drop.pgsql b/src/share/database/scripts/pgsql/dhcpdb_drop.pgsql index e399b786d9..3d302f0c4d 100644 --- a/src/share/database/scripts/pgsql/dhcpdb_drop.pgsql +++ b/src/share/database/scripts/pgsql/dhcpdb_drop.pgsql @@ -1,4 +1,4 @@ --- Copyright (C) 2016 Internet Systems Consortium. +-- Copyright (C) 2016-2018 Internet Systems Consortium. -- 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 @@ -20,3 +20,11 @@ DROP FUNCTION IF EXISTS lease4DumpHeader(); DROP FUNCTION IF EXISTS lease4DumpData(); DROP FUNCTION IF EXISTS lease6DumpHeader(); DROP FUNCTION IF EXISTS lease6DumpData(); +DROP TABLE IF EXISTS lease4_stat CASCADE; +DROP FUNCTION IF EXISTS proc_stat_lease4_insert (); +DROP FUNCTION IF EXISTS proc_stat_lease4_update (); +DROP FUNCTION IF EXISTS proc_stat_lease4_delete (); +DROP TABLE IF EXISTS lease6_stat CASCADE; +DROP FUNCTION IF EXISTS proc_stat_lease6_insert (); +DROP FUNCTION IF EXISTS proc_stat_lease6_update (); +DROP FUNCTION IF EXISTS proc_stat_lease6_delete (); diff --git a/src/share/database/scripts/pgsql/upgrade_3.3_to_4.0.sh.in b/src/share/database/scripts/pgsql/upgrade_3.3_to_4.0.sh.in index 85abf2fae2..b9513629c0 100644 --- a/src/share/database/scripts/pgsql/upgrade_3.3_to_4.0.sh.in +++ b/src/share/database/scripts/pgsql/upgrade_3.3_to_4.0.sh.in @@ -39,6 +39,198 @@ CREATE INDEX lease6_by_subnet_id_lease_type ON lease6 (subnet_id, lease_type); DROP INDEX lease6_by_iaid_subnet_id_duid; CREATE INDEX lease6_by_duid_iaid_subnet_id ON lease6 (duid, iaid, subnet_id); +-- Create v4 lease statistics table +CREATE TABLE lease4_stat ( + subnet_id BIGINT NOT NULL, + state INT8 NOT NULL, + leases BIGINT, + PRIMARY KEY (subnet_id, state) +); + +-- +-- Create v4 insert trigger procedure +CREATE FUNCTION proc_stat_lease4_insert () RETURNS trigger AS \$stat_lease4_insert\$ +BEGIN + IF NEW.state < 2 THEN + UPDATE lease4_stat + SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND state = NEW.state; + + IF NOT FOUND THEN + INSERT INTO lease4_stat VALUES (new.subnet_id, new.state, 1); + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease4_insert\$ LANGUAGE plpgsql; + +-- Create v4 insert trigger procedure +CREATE TRIGGER stat_lease4_insert +AFTER INSERT ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_insert(); + +-- +-- Create v4 update trigger procedure +CREATE FUNCTION proc_stat_lease4_update () RETURNS trigger AS \$stat_lease4_update\$ +BEGIN + IF OLD.state != NEW.state THEN + IF OLD.state < 2 THEN + -- Decrement the old state count if record exists + UPDATE lease4_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND state = OLD.state; + END IF; + + IF NEW.state < 2 THEN + -- Increment the new state count if record exists + UPDATE lease4_stat SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND state = NEW.state; + + -- Insert new state record if it does not exist + IF NOT FOUND THEN + INSERT INTO lease4_stat VALUES (NEW.subnet_id, NEW.state, 1); + END IF; + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease4_update\$ LANGUAGE plpgsql; + +-- Create v4 update trigger +CREATE TRIGGER stat_lease4_update +AFTER UPDATE ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_update(); + +-- +-- Create the v4 delete trigger procedure +CREATE FUNCTION proc_stat_lease4_delete () RETURNS trigger AS \$stat_lease4_delete\$ +BEGIN + IF OLD.state < 2 THEN + -- Decrement the state count if record exists + UPDATE lease4_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND OLD.state = state; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease4_delete\$ LANGUAGE plpgsql; + +-- Create the v4 delete trigger +CREATE TRIGGER stat_lease4_delete +AFTER DELETE ON lease4 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease4_delete(); + +-- Create v6 lease statistics table +CREATE TABLE lease6_stat ( + subnet_id BIGINT NOT NULL, + lease_type SMALLINT NOT NULL, + state INT8 NOT NULL, + leases BIGINT, + PRIMARY KEY (subnet_id, lease_type, state) +); + +-- +-- Create v6 insert trigger procedure +CREATE FUNCTION proc_stat_lease6_insert () RETURNS trigger AS \$stat_lease6_insert\$ +BEGIN + IF NEW.state < 2 THEN + UPDATE lease6_stat + SET leases = leases + 1 + WHERE + subnet_id = NEW.subnet_id AND lease_type = NEW.lease_type + AND state = NEW.state; + + IF NOT FOUND THEN + INSERT INTO lease6_stat + VALUES (NEW.subnet_id, NEW.lease_type, NEW.state, 1); + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease6_insert\$ LANGUAGE plpgsql; + +-- Create v6 insert trigger procedure +CREATE TRIGGER stat_lease6_insert +AFTER INSERT ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_insert(); + +-- +-- Create v6 update trigger procedure +CREATE FUNCTION proc_stat_lease6_update () RETURNS trigger AS \$stat_lease6_update\$ +BEGIN + IF OLD.state != NEW.state THEN + IF OLD.state < 2 THEN + -- Decrement the old state count if record exists + UPDATE lease6_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND lease_type = OLD.lease_type + AND state = OLD.state; + END IF; + + IF NEW.state < 2 THEN + -- Increment the new state count if record exists + UPDATE lease6_stat SET leases = leases + 1 + WHERE subnet_id = NEW.subnet_id AND lease_type = NEW.lease_type + AND state = NEW.state; + + -- Insert new state record if it does not exist + IF NOT FOUND THEN + INSERT INTO lease6_stat VALUES (NEW.subnet_id, NEW.lease_type, NEW.state, 1); + END IF; + END IF; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease6_update\$ LANGUAGE plpgsql; + +-- Create v6 update trigger +CREATE TRIGGER stat_lease6_update +AFTER UPDATE ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_update(); + +-- +-- Create the v6 delete trigger procedure +CREATE FUNCTION proc_stat_lease6_delete() RETURNS trigger AS \$stat_lease6_delete\$ +BEGIN + IF OLD.state < 2 THEN + -- Decrement the state count if record exists + UPDATE lease6_stat SET leases = leases - 1 + WHERE subnet_id = OLD.subnet_id AND lease_type = OLD.lease_type + AND OLD.state = state; + END IF; + + -- Return is ignored since this is an after insert + RETURN NULL; +END; +\$stat_lease6_delete\$ LANGUAGE plpgsql; + +-- Create the v6 delete trigger +CREATE TRIGGER stat_lease6_delete +AFTER DELETE ON lease6 + FOR EACH ROW EXECUTE PROCEDURE proc_stat_lease6_delete(); + +-- 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; + -- Set 4.0 schema version. UPDATE schema_version SET version = '4', minor = '0';