Browse Source

[master] Merge branch 'trac3968'

Marcin Siodelski 9 years ago
parent
commit
0bc02588d8

+ 39 - 3
src/bin/admin/scripts/mysql/dhcpdb_create.mysql

@@ -265,21 +265,57 @@ ALTER TABLE lease6
 # by the expiration time. One of the applications is to retrieve all
 # expired leases. However, these indexes can be also used to retrieve
 # leases in a given state regardless of the expiration time.
-CREATE INDEX lease4_by_state_expire ON lease4 (state, expire);
-CREATE INDEX lease6_by_state_expire ON lease6 (state, expire);
+CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
+CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
 
 # Create table holding mapping of the lease states to their names.
 # This is not used in queries from the DHCP server but rather in
 # direct queries from the lease database management tools.
 CREATE TABLE IF NOT EXISTS lease_state (
   state INT UNSIGNED PRIMARY KEY NOT NULL,
-  name VARCHAR(64) NOT NULL);
+  name VARCHAR(64) NOT NULL
+) ENGINE=INNODB;
 
 # Insert currently defined state names.
 INSERT INTO lease_state VALUES (0, "default");
 INSERT INTO lease_state VALUES (1, "declined");
 INSERT INTO lease_state VALUES (2, "expired-reclaimed");
 
+# Add a constraint that any state value added to the lease4 must
+# map to a value in the lease_state table.
+ALTER TABLE lease4
+    ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+# Add a constraint that any state value added to the lease6 must
+# map to a value in the lease_state table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+# Add a constraint that lease type in the lease6 table must map
+# to a lease type defined in the lease6_types table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
+    REFERENCES lease6_types (lease_type);
+
+# Modify the name of one of the HW address sources, and add a new one.
+UPDATE lease_hwaddr_source
+    SET name = 'HWADDR_SOURCE_DOCSIS_CMTS'
+    WHERE hwaddr_source = 64;
+
+INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
+
+# Add UNSIGNED to match with the lease6.
+ALTER TABLE lease_hwaddr_source
+    MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL;
+
+# Add a constraint that non-null hwaddr_source in the lease6 table
+# must map to an entry in the lease_hwaddr_source.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source)
+    REFERENCES lease_hwaddr_source (hwaddr_source);
+
 # FUNCTION that returns a result set containing the column names for lease4 dumps
 DROP PROCEDURE IF EXISTS lease4DumpHeader;
 DELIMITER $$

+ 39 - 3
src/bin/admin/scripts/mysql/upgrade_3.0_to_4.0.sh.in

@@ -28,21 +28,57 @@ ALTER TABLE lease6
 # by the expiration time. One of the applications is to retrieve all
 # expired leases. However, these indexes can be also used to retrieve
 # leases in a given state regardless of the expiration time.
-CREATE INDEX lease4_by_state_expire ON lease4 (state, expire);
-CREATE INDEX lease6_by_state_expire ON lease6 (state, expire);
+CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
+CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
 
 # Create table holding mapping of the lease states to their names.
 # This is not used in queries from the DHCP server but rather in
 # direct queries from the lease database management tools.
 CREATE TABLE IF NOT EXISTS lease_state (
   state INT UNSIGNED PRIMARY KEY NOT NULL,
-  name VARCHAR(64) NOT NULL);
+  name VARCHAR(64) NOT NULL
+) ENGINE=INNODB;
 
 # Insert currently defined state names.
 INSERT INTO lease_state VALUES (0, "default");
 INSERT INTO lease_state VALUES (1, "declined");
 INSERT INTO lease_state VALUES (2, "expired-reclaimed");
 
+# Add a constraint that any state value added to the lease4 must
+# map to a value in the lease_state table.
+ALTER TABLE lease4
+    ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+# Add a constraint that any state value added to the lease6 must
+# map to a value in the lease_state table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+# Add a constraint that lease type in the lease6 table must map
+# to a lease type defined in the lease6_types table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
+    REFERENCES lease6_types (lease_type);
+
+# Modify the name of one of the HW address sources, and add a new one.
+UPDATE lease_hwaddr_source
+    SET name = 'HWADDR_SOURCE_DOCSIS_CMTS'
+    WHERE hwaddr_source = 64;
+
+INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
+
+# Add UNSIGNED to match with the lease6.
+ALTER TABLE lease_hwaddr_source
+    MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL DEFAULT 0;
+
+# Add a constraint that non-null hwaddr_source in the lease6 table
+# must map to an entry in the lease_hwaddr_source.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source)
+    REFERENCES lease_hwaddr_source (hwaddr_source);
+
 # FUNCTION that returns a result set containing the column names for lease4 dumps
 DROP PROCEDURE IF EXISTS lease4DumpHeader;
 DELIMITER $$

+ 109 - 38
src/bin/admin/scripts/pgsql/dhcpdb_create.pgsql

@@ -1,4 +1,4 @@
+-- Copyright (C) 2012-2015  Internet Systems Consortium.
 
 -- Permission to use, copy, modify, and distribute this software for any
 -- purpose with or without fee is hereby granted, provided that the above
@@ -13,7 +13,7 @@
 -- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
 -- WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
 
+-- This is the Kea DHCP schema specification for PostgreSQL.
 
 -- The schema is reasonably portable (with the exception of some field types
 -- specification, which are PostgreSQL-specific).  Minor changes might be needed
@@ -50,41 +50,6 @@ 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);
 
---
-DROP FUNCTION IF EXISTS lease4DumpHeader();
-CREATE FUNCTION lease4DumpHeader() RETURNS text AS  $$
-    select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname' as text) as result;
-$$ LANGUAGE SQL;
---
-
---
-DROP FUNCTION IF EXISTS lease4DumpData();
-CREATE FUNCTION lease4DumpData() RETURNS 
-    table (address inet, 
-           hwaddr text, 
-           client_id text,
-           valid_lifetime bigint,
-           expire timestamp with time zone,
-           subnet_id bigint, 
-           fqdn_fwd int,
-           fqdn_rev int,
-           hostname text
-    ) as $$
-    SELECT ('0.0.0.0'::inet + address), 
-            encode(hwaddr,'hex'), 
-            encode(client_id,'hex'),
-            valid_lifetime,
-            expire,
-            subnet_id,
-            fqdn_fwd::int,
-            fqdn_rev::int,
-            hostname
-    from lease4;
-$$ LANGUAGE SQL;
---
-
 -- Holds the IPv6 leases.
 -- N.B. The use of a VARCHAR for the address is temporary for development:
 -- it will eventually be replaced by BINARY(16).
@@ -139,10 +104,99 @@ INSERT INTO schema_version VALUES (1, 0);
 COMMIT;
 
 --
+-- Schema 2.0 specification starts here.
+--
+
+-- Add state column to the lease4 table.
+ALTER TABLE lease4
+    ADD COLUMN state INT8 DEFAULT 0;
+
+-- Add state column to the lease6 table.
+ALTER TABLE lease6
+    ADD COLUMN state INT8 DEFAULT 0;
+
+-- Create indexes for querying leases in a given state and segregated
+-- by the expiration time. One of the applications is to retrieve all
+-- expired leases. However, these indexes can be also used to retrieve
+-- leases in a given state regardless of the expiration time.
+CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
+CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
+
+-- Create table holding mapping of the lease states to their names.
+-- This is not used in queries from the DHCP server but rather in
+-- direct queries from the lease database management tools.
+CREATE TABLE lease_state (
+    state INT8 PRIMARY KEY NOT NULL,
+    name VARCHAR(64) NOT NULL);
+
+-- Insert currently defined state names.
+START TRANSACTION;
+INSERT INTO lease_state VALUES (0, 'default');
+INSERT INTO lease_state VALUES (1, 'declined');
+INSERT INTO lease_state VALUES (2, 'expired-reclaimed');
+COMMIT;
+
+-- Add a constraint that any state value added to the lease4 must
+-- map to a value in the lease_state table.
+ALTER TABLE lease4
+    ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+-- Add a constraint that any state value added to the lease6 must
+-- map to a value in the lease_state table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
+    REFERENCES lease_state (state);
+
+-- Add a constraint that lease type in the lease6 table must map
+-- to a lease type defined in the lease6_types table.
+ALTER TABLE lease6
+    ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
+    REFERENCES lease6_types (lease_type);
+
+--
+--  FUNCTION that returns a result set containing the column names for lease4 dumps
+DROP FUNCTION IF EXISTS lease4DumpHeader();
+CREATE FUNCTION lease4DumpHeader() RETURNS text AS  $$
+    select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state' as text) as result;
+$$ LANGUAGE SQL;
+--
+
+--
+--  FUNCTION that returns a result set containing the data for lease4 dumps
+DROP FUNCTION IF EXISTS lease4DumpData();
+CREATE FUNCTION lease4DumpData() RETURNS
+    table (address inet,
+           hwaddr text,
+           client_id text,
+           valid_lifetime bigint,
+           expire timestamp with time zone,
+           subnet_id bigint,
+           fqdn_fwd int,
+           fqdn_rev int,
+           hostname text,
+           state text
+    ) as $$
+    SELECT ('0.0.0.0'::inet + l.address),
+            encode(l.hwaddr,'hex'),
+            encode(l.client_id,'hex'),
+            l.valid_lifetime,
+            l.expire,
+            l.subnet_id,
+            l.fqdn_fwd::int,
+            l.fqdn_rev::int,
+            l.hostname,
+            s.name
+    FROM lease4 l
+         left outer join lease_state s on (l.state = s.state);
+$$ LANGUAGE SQL;
+--
+
+--
 --  FUNCTION that returns a result set containing the column names for lease6 dumps
 DROP FUNCTION IF EXISTS lease6DumpHeader();
 CREATE FUNCTION lease6DumpHeader() RETURNS text AS  $$
-    select cast('address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname' as text) as result;
+    select cast('address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state' as text) as result;
 $$ LANGUAGE SQL;
 --
 
@@ -162,7 +216,8 @@ CREATE FUNCTION lease6DumpData() RETURNS
            prefix_len smallint,
            fqdn_fwd int,
            fqdn_rev int,
-           hostname text
+           hostname text,
+           state text
     ) AS $$
     SELECT (l.address,
             encode(l.duid,'hex'),
@@ -175,11 +230,22 @@ CREATE FUNCTION lease6DumpData() RETURNS
             l.prefix_len,
             l.fqdn_fwd::int,
             l.fqdn_rev::int,
-            l.hostname)
-     FROM lease6 l left outer join lease6_types t on (l.lease_type = t.lease_type);
+            l.hostname,
+            s.name)
+     FROM lease6 l
+         left outer join lease6_types t on (l.lease_type = t.lease_type)
+         left outer join lease_state s on (l.state = s.state);
 $$ LANGUAGE SQL;
 --
 
+-- Set 2.0 schema version.
+START TRANSACTION;
+UPDATE schema_version
+    SET version = '2', minor = '0';
+COMMIT;
+
+-- Schema 2.0 specification ends here.
+
 -- Notes:
 
 -- Indexes
@@ -192,9 +258,6 @@ $$ LANGUAGE SQL;
 
 -- The most likely additional indexes will cover the following columns:
 
-
 -- 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
@@ -202,8 +265,8 @@ $$ LANGUAGE SQL;
 
 -- Field Sizes
 -- ===========
+-- If any of the VARxxx field sizes are altered, the lengths in the PgSQL
+-- backend source file (pgsql_lease_mgr.cc) must be correspondingly changed.
 
 -- Portability
 -- ===========

+ 1 - 1
src/bin/admin/tests/data/mysql.lease6_dump_test.reference.csv

@@ -1,4 +1,4 @@
 address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,hwaddr,hwtype,hwaddr_source,state
-10,3230,30,2015-04-04 01:15:30,40,50,IA_TA,60,70,1,1,one.example.com,3830,90,,default
 11,,30,2015-05-05 02:30:45,40,50,IA_TA,60,70,1,1,,3830,90,HWADDR_SOURCE_RAW,declined
 12,3231,30,2015-06-06 11:01:07,40,50,IA_TA,60,70,1,1,three.example.com,3830,90,HWADDR_SOURCE_DUID,expired-reclaimed
+10,3230,30,2015-04-04 01:15:30,40,50,IA_TA,60,70,1,1,one.example.com,3830,90,HWADDR_SOURCE_REMOTE_ID,default

+ 4 - 4
src/bin/admin/tests/data/pgsql.lease4_dump_test.reference.csv

@@ -1,4 +1,4 @@
-address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname
-0.0.0.10,20,30,40,<timestamp1>,50,1,1,one.example.com
-0.0.0.11,,013233,40,<timestamp2>,50,1,1,
-0.0.0.12,22,,40,<timestamp3>,50,1,1,three.example.com
+address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state
+0.0.0.10,20,30,40,<timestamp1>,50,1,1,one.example.com,default
+0.0.0.11,,013233,40,<timestamp2>,50,1,1,,declined
+0.0.0.12,22,,40,<timestamp3>,50,1,1,three.example.com,expired-reclaimed

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

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

+ 1 - 1
src/bin/admin/tests/mysql_tests.sh.in

@@ -395,7 +395,7 @@ mysql_lease6_dump_test() {
 
     # Insert the reference record
     insert_sql="\
-insert into lease6 values(10,20,30,\"2015-04-04 01:15:30\",40,50,1,60,70,1,1,\"one.example.com\",80,90,0,0);\
+insert into lease6 values(10,20,30,\"2015-04-04 01:15:30\",40,50,1,60,70,1,1,\"one.example.com\",80,90,16,0);\
 insert into lease6 values(11,NULL,30,\"2015-05-05 02:30:45\",40,50,1,60,70,1,1,\"\",80,90,1,1);\
 insert into lease6 values(12,21,30,\"2015-06-06 11:01:07\",40,50,1,60,70,1,1,\"three.example.com\",80,90,4,2);"
 

+ 13 - 9
src/bin/admin/tests/pgsql_tests.sh.in

@@ -68,17 +68,21 @@ pgsql_lease_init_test() {
     assert_eq 0 $? "schema_version table check failed, expected exit code: %d, actual: %d"
 
     # Check lease4 table
-    RESULT=`pgsql_execute "SELECT address, hwaddr, client_id, valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname FROM lease4;"`
+    RESULT=`pgsql_execute "SELECT address, hwaddr, client_id, valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname, state FROM lease4;"`
     assert_eq 0 $? "lease4 table check failed, expected exit code: %d, actual: %d"
 
     # Check lease6 table
-    RESULT=`pgsql_execute "SELECT address, duid, valid_lifetime, expire, subnet_id, pref_lifetime, lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname FROM lease6;"`
+    RESULT=`pgsql_execute "SELECT address, duid, valid_lifetime, expire, subnet_id, pref_lifetime, lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, state FROM lease6;"`
     assert_eq 0 $? "lease6 table check failed, expected exit code: %d, actual: %d"
 
     # Check lease6_types table
     RESULT=`pgsql_execute "SELECT lease_type, name FROM lease6_types;"`
     assert_eq 0 $? "lease6_types table check failed, expected exit code: %d, actual: %d"
 
+    # Check lease_state table
+    RESULT=`pgsql_execute "SELECT state, name FROM lease_state;"`
+    assert_eq 0 $? "lease_state table check failed, expected exit code: %d, actual: %d"
+
     # Trying to create it again should fail.  This verifies the db present
     # check
     echo ""
@@ -104,7 +108,7 @@ pgsql_lease_version_test() {
 
     # Verfiy that kea-admin lease-version returns the correct version
     version=$(${keaadmin} lease-version pgsql -u $db_user -p $db_password -n $db_name)
-    assert_str_eq "1.0" ${version} "Expected kea-admin to return %s, returned value was %s"
+    assert_str_eq "2.0" ${version} "Expected kea-admin to return %s, returned value was %s"
 
     # Let's wipe the whole database
     pgsql_wipe
@@ -195,9 +199,9 @@ pgsql_lease4_dump_test() {
 
     # Insert the reference records
     insert_sql="\
-insert into lease4 values(10,E'\\x20',E'\\x30',40,'$timestamp1',50,'t','t','one.example.com');\
-insert into lease4 values(11,'',E'\\x0123',40,'$timestamp2',50,'t','t','');\
-insert into lease4 values(12,E'\\x22','',40,'$timestamp3',50,'t','t','three.example.com');"
+insert into lease4 values(10,E'\\x20',E'\\x30',40,'$timestamp1',50,'t','t','one.example.com', 0);\
+insert into lease4 values(11,'',E'\\x0123',40,'$timestamp2',50,'t','t','', 1);\
+insert into lease4 values(12,E'\\x22','',40,'$timestamp3',50,'t','t','three.example.com', 2);"
 
     pgsql_execute "$insert_sql"
     ERRCODE=$?
@@ -290,9 +294,9 @@ pgsql_lease6_dump_test() {
 
     # Insert the reference records
     insert_sql="\
-insert into lease6 values(10,E'\\x20',30,'$timestamp1',40,50,1,60,70,'t','t','one.example.com');\
-insert into lease6 values(11,'',30,'$timestamp2',40,50,1,60,70,'t','t','');\
-insert into lease6 values(12,E'\\x21',30,'$timestamp3',40,50,1,60,70,'t','t','three.example.com');"
+insert into lease6 values(10,E'\\x20',30,'$timestamp1',40,50,1,60,70,'t','t','one.example.com', 0);\
+insert into lease6 values(11,'',30,'$timestamp2',40,50,1,60,70,'t','t','', 1);\
+insert into lease6 values(12,E'\\x21',30,'$timestamp3',40,50,1,60,70,'t','t','three.example.com', 2);"
 
     pgsql_execute "$insert_sql"
     ERRCODE=$?

+ 22 - 0
src/lib/dhcpsrv/dhcpsrv_messages.mes

@@ -546,6 +546,28 @@ A debug message issued when the server is attempting to obtain a set
 of IPv4 leases from the PostgreSQL database for a client with the specified
 client identification.
 
+% DHCPSRV_PGSQL_GET_EXPIRED4 obtaining maximum %1 of expired IPv4 leases
+A debug message issued when the server is attempting to obtain expired
+IPv4 leases to reclaim them. The maximum number of leases to be retrieved
+is logged in the message.
+
+% DHCPSRV_PGSQL_GET_EXPIRED6 obtaining maximum %1 of expired IPv6 leases
+A debug message issued when the server is attempting to obtain expired
+IPv6 leases to reclaim them. The maximum number of leases to be retrieved
+is logged in the message.
+
+% DHCPSRV_PGSQL_DELETE_EXPIRED_RECLAIMED4 deleting reclaimed IPv4 leases that expired more than %1 seconds ago
+A debug message issued when the server is removing reclaimed DHCPv4
+leases which have expired longer than a specified period of time.
+The argument is the amount of time Kea waits after a reclaimed
+lease expires before considering its removal.
+
+% DHCPSRV_PGSQL_DELETE_EXPIRED_RECLAIMED6 deleting reclaimed IPv6 leases that expired more than %1 seconds ago
+A debug message issued when the server is removing reclaimed DHCPv6
+leases which have expired longer than a specified period of time.
+The argument is the amount of time Kea waits after a reclaimed
+lease expires before considering its removal.
+
 % DHCPSRV_PGSQL_GET_HWADDR obtaining IPv4 leases for hardware address %1
 A debug message issued when the server is attempting to obtain a set
 of IPv4 leases from the PostgreSQL database for a client with the specified

+ 2 - 2
src/lib/dhcpsrv/mysql_lease_mgr.cc

@@ -143,7 +143,7 @@ TaggedStatement tagged_statements[] = {
                         "state "
                             "FROM lease4 "
                             "WHERE state != ? AND expire < ? "
-                            "ORDER BY expire "
+                            "ORDER BY expire ASC "
                             "LIMIT ?"},
     {MySqlLeaseMgr::GET_LEASE6_ADDR,
                     "SELECT address, duid, valid_lifetime, "
@@ -182,7 +182,7 @@ TaggedStatement tagged_statements[] = {
                         "state "
                             "FROM lease6 "
                             "WHERE state != ? AND expire < ? "
-                            "ORDER BY expire "
+                            "ORDER BY expire ASC "
                             "LIMIT ?"},
     {MySqlLeaseMgr::GET_VERSION,
                     "SELECT version, minor FROM schema_version"},

+ 169 - 57
src/lib/dhcpsrv/pgsql_lease_mgr.cc

@@ -24,6 +24,7 @@
 
 #include <iostream>
 #include <iomanip>
+#include <limits>
 #include <sstream>
 #include <string>
 #include <time.h>
@@ -49,7 +50,7 @@ using namespace std;
 namespace {
 
 // Maximum number of parameters used in any single query
-const size_t MAX_PARAMETERS_IN_QUERY = 13;
+const size_t MAX_PARAMETERS_IN_QUERY = 14;
 
 /// @brief  Defines a single query
 struct TaggedStatement {
@@ -91,17 +92,29 @@ TaggedStatement tagged_statements[] = {
       "delete_lease4",
       "DELETE FROM lease4 WHERE address = $1"},
 
+    // DELETE_LEASE4_STATE_EXPIRED
+    { 2, { OID_INT8, OID_TIMESTAMP },
+      "delete_lease4_state_expired",
+      "DELETE FROM lease4 "
+          "WHERE state = $1 AND expire < $2"},
+
     // DELETE_LEASE6
     { 1, { OID_VARCHAR },
       "delete_lease6",
       "DELETE FROM lease6 WHERE address = $1"},
 
+    // DELETE_LEASE6_STATE_EXPIRED
+    { 2, { OID_INT8, OID_TIMESTAMP },
+      "delete_lease6_state_expired",
+      "DELETE FROM lease6 "
+          "WHERE state = $1 AND expire < $2"},
+
     // GET_LEASE4_ADDR
     { 1, { OID_INT8 },
       "get_lease4_addr",
       "SELECT address, hwaddr, client_id, "
         "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
-        "fqdn_fwd, fqdn_rev, hostname "
+        "fqdn_fwd, fqdn_rev, hostname, state "
       "FROM lease4 "
       "WHERE address = $1"},
 
@@ -110,7 +123,7 @@ TaggedStatement tagged_statements[] = {
       "get_lease4_clientid",
       "SELECT address, hwaddr, client_id, "
         "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
-        "fqdn_fwd, fqdn_rev, hostname "
+        "fqdn_fwd, fqdn_rev, hostname, state "
       "FROM lease4 "
       "WHERE client_id = $1"},
 
@@ -119,7 +132,7 @@ TaggedStatement tagged_statements[] = {
       "get_lease4_clientid_subid",
       "SELECT address, hwaddr, client_id, "
         "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
-        "fqdn_fwd, fqdn_rev, hostname "
+        "fqdn_fwd, fqdn_rev, hostname, state "
       "FROM lease4 "
       "WHERE client_id = $1 AND subnet_id = $2"},
 
@@ -128,7 +141,7 @@ TaggedStatement tagged_statements[] = {
       "get_lease4_hwaddr",
       "SELECT address, hwaddr, client_id, "
         "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
-        "fqdn_fwd, fqdn_rev, hostname "
+        "fqdn_fwd, fqdn_rev, hostname, state "
       "FROM lease4 "
       "WHERE hwaddr = $1"},
 
@@ -137,16 +150,28 @@ TaggedStatement tagged_statements[] = {
       "get_lease4_hwaddr_subid",
       "SELECT address, hwaddr, client_id, "
         "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
-        "fqdn_fwd, fqdn_rev, hostname "
+        "fqdn_fwd, fqdn_rev, hostname, state "
       "FROM lease4 "
       "WHERE hwaddr = $1 AND subnet_id = $2"},
 
+    // GET_LEASE4_EXPIRE
+    { 3, { OID_INT8, OID_TIMESTAMP, OID_INT8 },
+      "get_lease4_expire",
+      "SELECT address, hwaddr, client_id, "
+          "valid_lifetime, extract(epoch from expire)::bigint, subnet_id, "
+          "fqdn_fwd, fqdn_rev, hostname, state "
+              "FROM lease4 "
+              "WHERE state != $1 AND expire < $2 "
+              "ORDER BY expire "
+              "LIMIT $3"},
+
     // GET_LEASE6_ADDR
     { 2, { OID_VARCHAR, OID_INT2 },
       "get_lease6_addr",
       "SELECT address, duid, valid_lifetime, "
         "extract(epoch from expire)::bigint, subnet_id, pref_lifetime, "
-        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname "
+        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, "
+        "state "
       "FROM lease6 "
       "WHERE address = $1 AND lease_type = $2"},
 
@@ -155,7 +180,8 @@ TaggedStatement tagged_statements[] = {
        "get_lease6_duid_iaid",
        "SELECT address, duid, valid_lifetime, "
          "extract(epoch from expire)::bigint, subnet_id, pref_lifetime, "
-         "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname "
+         "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, "
+         "state "
        "FROM lease6 "
        "WHERE duid = $1 AND iaid = $2 AND lease_type = $3"},
 
@@ -164,53 +190,70 @@ TaggedStatement tagged_statements[] = {
       "get_lease6_duid_iaid_subid",
       "SELECT address, duid, valid_lifetime, "
         "extract(epoch from expire)::bigint, subnet_id, pref_lifetime, "
-        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname "
+        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, "
+        "state "
       "FROM lease6 "
       "WHERE lease_type = $1 "
         "AND duid = $2 AND iaid = $3 AND subnet_id = $4"},
 
+    // GET_LEASE6_EXPIRE
+    { 3, { OID_INT8, OID_TIMESTAMP, OID_INT8 },
+      "get_lease6_expire",
+      "SELECT address, duid, valid_lifetime, "
+          "extract(epoch from expire)::bigint, subnet_id, pref_lifetime, "
+          "lease_type, iaid, prefix_len, "
+          "fqdn_fwd, fqdn_rev, hostname, state "
+          "state "
+              "FROM lease6 "
+              "WHERE state != $1 AND expire < $2 "
+              "ORDER BY expire "
+              "LIMIT $3"},
+
     // GET_VERSION
     { 0, { OID_NONE },
       "get_version",
       "SELECT version, minor FROM schema_version"},
 
     // INSERT_LEASE4
-    { 9, { OID_INT8, OID_BYTEA, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
-           OID_BOOL, OID_BOOL, OID_VARCHAR },
+    { 10, { OID_INT8, OID_BYTEA, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
+            OID_BOOL, OID_BOOL, OID_VARCHAR, OID_INT8, OID_INT8 },
       "insert_lease4",
       "INSERT INTO lease4(address, hwaddr, client_id, "
-        "valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname) "
-      "VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9)"},
+        "valid_lifetime, expire, subnet_id, fqdn_fwd, fqdn_rev, hostname, "
+        "state) "
+      "VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10)"},
 
     // INSERT_LEASE6
-    { 12, { OID_VARCHAR, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
+    { 13, { OID_VARCHAR, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
             OID_INT8, OID_INT2, OID_INT8, OID_INT2, OID_BOOL, OID_BOOL,
-            OID_VARCHAR },
+            OID_VARCHAR, OID_INT8 },
       "insert_lease6",
       "INSERT INTO lease6(address, duid, valid_lifetime, "
         "expire, subnet_id, pref_lifetime, "
-        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname) "
-      "VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12)"},
+        "lease_type, iaid, prefix_len, fqdn_fwd, fqdn_rev, hostname, state) "
+      "VALUES ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)"},
 
     // UPDATE_LEASE4
-    { 10, { OID_INT8, OID_BYTEA, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
-            OID_BOOL, OID_BOOL, OID_VARCHAR, OID_INT8 },
+    { 11, { OID_INT8, OID_BYTEA, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8,
+            OID_BOOL, OID_BOOL, OID_VARCHAR, OID_INT8, OID_INT8 },
       "update_lease4",
       "UPDATE lease4 SET address = $1, hwaddr = $2, "
         "client_id = $3, valid_lifetime = $4, expire = $5, "
-        "subnet_id = $6, fqdn_fwd = $7, fqdn_rev = $8, hostname = $9 "
-      "WHERE address = $10"},
+        "subnet_id = $6, fqdn_fwd = $7, fqdn_rev = $8, hostname = $9, "
+        "state = $10"
+      "WHERE address = $11"},
 
     // UPDATE_LEASE6
-    { 13, { OID_VARCHAR, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8, OID_INT8,
+    { 14, { OID_VARCHAR, OID_BYTEA, OID_INT8, OID_TIMESTAMP, OID_INT8, OID_INT8,
             OID_INT2, OID_INT8, OID_INT2, OID_BOOL, OID_BOOL, OID_VARCHAR,
-            OID_VARCHAR },
+            OID_INT8, OID_VARCHAR },
       "update_lease6",
       "UPDATE lease6 SET address = $1, duid = $2, "
         "valid_lifetime = $3, expire = $4, subnet_id = $5, "
         "pref_lifetime = $6, lease_type = $7, iaid = $8, "
-        "prefix_len = $9, fqdn_fwd = $10, fqdn_rev = $11, hostname = $12 "
-      "WHERE address = $13"},
+        "prefix_len = $9, fqdn_fwd = $10, fqdn_rev = $11, hostname = $12, "
+        "state = $13 "
+      "WHERE address = $14"},
 
     // End of list sentinel
     { 0,  { 0 }, NULL, NULL}
@@ -283,12 +326,26 @@ public:
 
     PgSqlLeaseExchange()
         : addr_str_(""), valid_lifetime_(0), valid_lft_str_(""),
-         expire_(0), expire_str_(""), subnet_id_(0), subnet_id_str_(""),
-         cltt_(0), fqdn_fwd_(false), fqdn_rev_(false), hostname_("") {
+          expire_(0), expire_str_(""), subnet_id_(0), subnet_id_str_(""),
+          cltt_(0), fqdn_fwd_(false), fqdn_rev_(false), hostname_(""),
+          state_str_("") {
     }
 
     virtual ~PgSqlLeaseExchange(){}
 
+    /// @brief Converts time_t value to a text representation in local time.
+    ///
+    /// @param input_time A time_t value representing time.
+    /// @return std::string containing stringified time.
+    static std::string
+    convertToDatabaseTime(const time_t input_time) {
+        struct tm tinfo;
+        char buffer[20];
+        localtime_r(&input_time, &tinfo);
+        strftime(buffer, sizeof(buffer), "%Y-%m-%d %H:%M:%S", &tinfo);
+        return (std::string(buffer));
+    }
+
     /// @brief Converts lease expiration time to a text representation in
     /// local time.
     ///
@@ -324,12 +381,7 @@ public:
             isc_throw(isc::BadValue, "Time value is too large: " << expire_time_64);
         }
 
-        struct tm tinfo;
-        char buffer[20];
-        const time_t time_val = static_cast<time_t>(expire_time_64);
-        localtime_r(&time_val, &tinfo);
-        strftime(buffer, sizeof(buffer), "%Y-%m-%d %H:%M:%S", &tinfo);
-        return (std::string(buffer));
+        return (convertToDatabaseTime(static_cast<time_t>(expire_time_64)));
     }
 
     /// @brief Converts time stamp from the database to a time_t
@@ -549,6 +601,7 @@ protected:
     bool fqdn_fwd_;
     bool fqdn_rev_;
     std::string hostname_;
+    std::string state_str_;
     //@}
 
 };
@@ -571,8 +624,9 @@ private:
     static const size_t FQDN_FWD_COL = 6;
     static const size_t FQDN_REV_COL = 7;
     static const size_t HOSTNAME_COL = 8;
+    static const size_t STATE_COL = 9;
     /// @brief Number of columns in the table holding DHCPv4 leases.
-    static const size_t LEASE_COLUMNS = 9;
+    static const size_t LEASE_COLUMNS = 10;
 
 public:
 
@@ -581,7 +635,7 @@ public:
         : lease_(), addr4_(0), hwaddr_length_(0), hwaddr_(hwaddr_length_),
         client_id_length_(0) {
 
-        BOOST_STATIC_ASSERT(8 < LEASE_COLUMNS);
+        BOOST_STATIC_ASSERT(9 < LEASE_COLUMNS);
 
         memset(hwaddr_buffer_, 0, sizeof(hwaddr_buffer_));
         memset(client_id_buffer_, 0, sizeof(client_id_buffer_));
@@ -596,6 +650,7 @@ public:
         column_labels_.push_back("fqdn_fwd");
         column_labels_.push_back("fqdn_rev");
         column_labels_.push_back("hostname");
+        column_labels_.push_back("state");
     }
 
     /// @brief Creates the bind array for sending Lease4 data to the database.
@@ -660,6 +715,9 @@ public:
 
             bind_array.add(lease->hostname_);
 
+            state_str_ = boost::lexical_cast<std::string>(lease->state_);
+            bind_array.add(state_str_);
+
         } catch (const std::exception& ex) {
             isc_throw(DbOperationError,
                       "Could not create bind array from Lease4: "
@@ -750,17 +808,18 @@ private:
     static const int FQDN_FWD_COL = 9;
     static const int FQDN_REV_COL = 10;
     static const int HOSTNAME_COL = 11;
+    static const int STATE_COL = 12;
     //@}
-    /// @brief Number of columns in the table holding DHCPv4 leases.
-    static const size_t LEASE_COLUMNS = 12;
+    /// @brief Number of columns in the table holding DHCPv6 leases.
+    static const size_t LEASE_COLUMNS = 13;
 
 public:
     PgSqlLease6Exchange()
         : lease_(), duid_length_(0), duid_(), iaid_(0), iaid_str_(""),
-         lease_type_(Lease6::TYPE_NA), lease_type_str_(""), prefix_len_(0),
-         prefix_len_str_(""), pref_lifetime_(0), preferred_lft_str_("") {
+          lease_type_(Lease6::TYPE_NA), lease_type_str_(""), prefix_len_(0),
+          prefix_len_str_(""), pref_lifetime_(0), preferred_lft_str_("") {
 
-        BOOST_STATIC_ASSERT(11 < LEASE_COLUMNS);
+        BOOST_STATIC_ASSERT(12 < LEASE_COLUMNS);
 
         memset(duid_buffer_, 0, sizeof(duid_buffer_));
 
@@ -777,6 +836,7 @@ public:
         column_labels_.push_back("fqdn_fwd");
         column_labels_.push_back("fqdn_rev");
         column_labels_.push_back("hostname");
+        column_labels_.push_back("state");
     }
 
     /// @brief Creates the bind array for sending Lease6 data to the database.
@@ -838,6 +898,10 @@ public:
             bind_array.add(lease->fqdn_rev_);
 
             bind_array.add(lease->hostname_);
+
+            state_str_ = boost::lexical_cast<std::string>(lease->state_);
+            bind_array.add(state_str_);
+
         } catch (const std::exception& ex) {
             isc_throw(DbOperationError,
                       "Could not create bind array from Lease6: "
@@ -1383,19 +1447,46 @@ PgSqlLeaseMgr::getLeases6(Lease::Type lease_type, const DUID& duid,
 }
 
 void
-PgSqlLeaseMgr::getExpiredLeases6(Lease6Collection&, const size_t) const {
-    isc_throw(NotImplemented, "PgSqlLeaseMgr::getExpiredLeases6 is currently"
-              " not implemented");
+PgSqlLeaseMgr::getExpiredLeases6(Lease6Collection& expired_leases,
+                                 const size_t max_leases) const {
+    LOG_DEBUG(dhcpsrv_logger, DHCPSRV_DBG_TRACE_DETAIL, DHCPSRV_PGSQL_GET_EXPIRED6)
+        .arg(max_leases);
+    getExpiredLeasesCommon(expired_leases, max_leases, GET_LEASE6_EXPIRE);
 }
 
 void
-PgSqlLeaseMgr::getExpiredLeases4(Lease4Collection&, const size_t) const {
-    isc_throw(NotImplemented, "PgSqlLeaseMgr::getExpiredLeases4 is currently"
-              " not implemented");
+PgSqlLeaseMgr::getExpiredLeases4(Lease4Collection& expired_leases,
+                                 const size_t max_leases) const {
+    LOG_DEBUG(dhcpsrv_logger, DHCPSRV_DBG_TRACE_DETAIL, DHCPSRV_PGSQL_GET_EXPIRED4)
+        .arg(max_leases);
+    getExpiredLeasesCommon(expired_leases, max_leases, GET_LEASE4_EXPIRE);
 }
 
+template<typename LeaseCollection>
+void
+PgSqlLeaseMgr::getExpiredLeasesCommon(LeaseCollection& expired_leases,
+                                       const size_t max_leases,
+                                       StatementIndex statement_index) const {
+    PsqlBindArray bind_array;
+
+    // Exclude reclaimed leases.
+    bind_array.add(boost::lexical_cast<std::string>(Lease::STATE_EXPIRED_RECLAIMED));
+
+    // Expiration timestamp.
+    bind_array.add(PgSqlLeaseExchange::convertToDatabaseTime(time(NULL)));
 
-template <typename LeasePtr>
+    // If the number of leases is 0, we will return all leases. This is
+    // achieved by setting the limit to a very high value.
+    uint32_t limit = max_leases > 0 ? static_cast<uint32_t>(max_leases) :
+        std::numeric_limits<uint32_t>::max();
+    bind_array.add(boost::lexical_cast<std::string>(limit));
+
+    // Retrieve leases from the database.
+    getLeaseCollection(statement_index, bind_array, expired_leases);
+}
+
+
+template<typename LeasePtr>
 void
 PgSqlLeaseMgr::updateLeaseCommon(StatementIndex stindex,
                                  PsqlBindArray& bind_array,
@@ -1471,7 +1562,7 @@ PgSqlLeaseMgr::updateLease6(const Lease6Ptr& lease) {
     updateLeaseCommon(stindex, bind_array, lease);
 }
 
-bool
+uint64_t
 PgSqlLeaseMgr::deleteLeaseCommon(StatementIndex stindex,
                                  PsqlBindArray& bind_array) {
     PGresult* r = PQexecPrepared(conn_, tagged_statements[stindex].name,
@@ -1484,7 +1575,7 @@ PgSqlLeaseMgr::deleteLeaseCommon(StatementIndex stindex,
     int affected_rows = boost::lexical_cast<int>(PQcmdTuples(r));
     PQclear(r);
 
-    return (affected_rows > 0);
+    return (affected_rows);
 }
 
 bool
@@ -1499,24 +1590,45 @@ PgSqlLeaseMgr::deleteLease(const isc::asiolink::IOAddress& addr) {
         std::string addr4_str = boost::lexical_cast<std::string>
                                  (static_cast<uint32_t>(addr));
         bind_array.add(addr4_str);
-        return (deleteLeaseCommon(DELETE_LEASE4, bind_array));
+        return (deleteLeaseCommon(DELETE_LEASE4, bind_array) > 0);
     }
 
     std::string addr6_str = addr.toText();
     bind_array.add(addr6_str);
-    return (deleteLeaseCommon(DELETE_LEASE6, bind_array));
+    return (deleteLeaseCommon(DELETE_LEASE6, bind_array) > 0);
+}
+
+uint64_t
+PgSqlLeaseMgr::deleteExpiredReclaimedLeases4(const uint32_t secs) {
+    LOG_DEBUG(dhcpsrv_logger, DHCPSRV_DBG_TRACE_DETAIL,
+              DHCPSRV_PGSQL_DELETE_EXPIRED_RECLAIMED4)
+        .arg(secs);
+    return (deleteExpiredReclaimedLeasesCommon(secs, DELETE_LEASE4_STATE_EXPIRED));
 }
 
 uint64_t
-PgSqlLeaseMgr::deleteExpiredReclaimedLeases4(const uint32_t) {
-    isc_throw(NotImplemented, "PgSqlLeaseMgr::deleteExpiredReclaimedLeases4"
-              " is not implemented");
+PgSqlLeaseMgr::deleteExpiredReclaimedLeases6(const uint32_t secs) {
+    LOG_DEBUG(dhcpsrv_logger, DHCPSRV_DBG_TRACE_DETAIL,
+              DHCPSRV_PGSQL_DELETE_EXPIRED_RECLAIMED6)
+        .arg(secs);
+    return (deleteExpiredReclaimedLeasesCommon(secs, DELETE_LEASE6_STATE_EXPIRED));
 }
 
 uint64_t
-PgSqlLeaseMgr::deleteExpiredReclaimedLeases6(const uint32_t) {
-    isc_throw(NotImplemented, "PgSqlLeaseMgr::deleteExpiredReclaimedLeases6"
-              " is not implemented");
+PgSqlLeaseMgr::deleteExpiredReclaimedLeasesCommon(const uint32_t secs,
+                                                  StatementIndex statement_index) {
+    PsqlBindArray bind_array;
+
+    // State is reclaimed.
+    bind_array.add(boost::lexical_cast<std::string>(Lease::STATE_EXPIRED_RECLAIMED));
+
+    // Expiration timestamp.
+    std::string expiration_str =
+        PgSqlLeaseExchange::convertToDatabaseTime(time(NULL) - static_cast<time_t>(secs));
+    bind_array.add(expiration_str);
+
+    // Delete leases.
+    return (deleteLeaseCommon(statement_index, bind_array));
 }
 
 string

+ 38 - 5
src/lib/dhcpsrv/pgsql_lease_mgr.h

@@ -112,8 +112,8 @@ struct PsqlBindArray {
 class PgSqlLease4Exchange;
 class PgSqlLease6Exchange;
 
-/// Defines PostgreSQL backend version: 1.0
-const uint32_t PG_CURRENT_VERSION = 1;
+/// Defines PostgreSQL backend version: 2.0
+const uint32_t PG_CURRENT_VERSION = 2;
 const uint32_t PG_CURRENT_MINOR = 0;
 
 /// @brief PostgreSQL Lease Manager
@@ -463,15 +463,19 @@ public:
     /// statements
     enum StatementIndex {
         DELETE_LEASE4,              // Delete from lease4 by address
+        DELETE_LEASE4_STATE_EXPIRED,// Delete expired lease4s in certain state.
         DELETE_LEASE6,              // Delete from lease6 by address
+        DELETE_LEASE6_STATE_EXPIRED,// Delete expired lease6s in certain state.
         GET_LEASE4_ADDR,            // Get lease4 by address
         GET_LEASE4_CLIENTID,        // Get lease4 by client ID
         GET_LEASE4_CLIENTID_SUBID,  // Get lease4 by client ID & subnet ID
         GET_LEASE4_HWADDR,          // Get lease4 by HW address
         GET_LEASE4_HWADDR_SUBID,    // Get lease4 by HW address & subnet ID
+        GET_LEASE4_EXPIRE,          // Get expired lease4
         GET_LEASE6_ADDR,            // Get lease6 by address
         GET_LEASE6_DUID_IAID,       // Get lease6 by DUID and IAID
         GET_LEASE6_DUID_IAID_SUBID, // Get lease6 by DUID, IAID and subnet ID
+        GET_LEASE6_EXPIRE,          // Get expired lease6
         GET_VERSION,                // Obtain version number
         INSERT_LEASE4,              // Add entry to lease4 table
         INSERT_LEASE6,              // Add entry to lease6 table
@@ -620,6 +624,24 @@ private:
     void getLease(StatementIndex stindex, PsqlBindArray& bind_array,
                   Lease6Ptr& result) const;
 
+    /// @brief Get expired leases common code.
+    ///
+    /// This method retrieves expired and not reclaimed leases from the
+    /// lease database. The returned leases are ordered by the expiration
+    /// time. The maximum number of leases to be returned is specified
+    /// as an argument.
+    ///
+    /// @param [out] expired_leases Reference to the container where the
+    ///        retrieved leases are put.
+    /// @param max_leases Maximum number of leases to be returned.
+    /// @param statement_index One of the @c GET_LEASE4_EXPIRE or
+    ///        @c GET_LEASE6_EXPIRE.
+    ///
+    /// @tparam One of the @c Lease4Collection or @c Lease6Collection.
+    template<typename LeaseCollection>
+    void getExpiredLeasesCommon(LeaseCollection& expired_leases,
+                                const size_t max_leases,
+                                StatementIndex statement_index) const;
 
     /// @brief Update lease common code
     ///
@@ -650,12 +672,23 @@ private:
     /// @param bind_array array containing lease values and where clause
     /// parameters for the delete
     ///
-    /// @return true if one or more rows were deleted, false if none were
-    ///         deleted.
+    /// @return Number of deleted leases.
     ///
     /// @throw isc::dhcp::DbOperationError An operation on the open database has
     ///        failed.
-    bool deleteLeaseCommon(StatementIndex stindex, PsqlBindArray& bind_array);
+    uint64_t deleteLeaseCommon(StatementIndex stindex, PsqlBindArray& bind_array);
+
+    /// @brief Delete expired-reclaimed leases.
+    ///
+    /// @param secs Number of seconds since expiration of leases before
+    /// they can be removed. Leases which have expired later than this
+    /// time will not be deleted.
+    /// @param statement_index One of the @c DELETE_LEASE4_STATE_EXPIRED or
+    ///        @c DELETE_LEASE6_STATE_EXPIRED.
+    ///
+    /// @return Number of leases deleted.
+    uint64_t deleteExpiredReclaimedLeasesCommon(const uint32_t secs,
+                                                StatementIndex statement_index);
 
     /// The exchange objects are used for transfer of data to/from the database.
     /// They are pointed-to objects as the contents may change in "const" calls,

+ 32 - 0
src/lib/dhcpsrv/tests/pgsql_lease_mgr_unittest.cc

@@ -393,6 +393,22 @@ TEST_F(PgSqlLeaseMgrTest, lease4InvalidHostname) {
     testLease4InvalidHostname();
 }
 
+/// @brief Check that the expired DHCPv4 leases can be retrieved.
+///
+/// This test adds a number of leases to the lease database and marks
+/// some of them as expired. Then it queries for expired leases and checks
+/// whether only expired leases are returned, and that they are returned in
+/// the order from most to least expired. It also checks that the lease
+/// which is marked as 'reclaimed' is not returned.
+TEST_F(PgSqlLeaseMgrTest, getExpiredLeases4) {
+    testGetExpiredLeases4();
+}
+
+/// @brief Check that expired reclaimed DHCPv4 leases are removed.
+TEST_F(PgSqlLeaseMgrTest, deleteExpiredReclaimedLeases4) {
+    testDeleteExpiredReclaimedLeases4();
+}
+
 ////////////////////////////////////////////////////////////////////////////////
 /// LEASE6 /////////////////////////////////////////////////////////////////////
 ////////////////////////////////////////////////////////////////////////////////
@@ -471,4 +487,20 @@ TEST_F(PgSqlLeaseMgrTest, nullDuid) {
     testNullDuid();
 }
 
+/// @brief Check that the expired DHCPv6 leases can be retrieved.
+///
+/// This test adds a number of leases to the lease database and marks
+/// some of them as expired. Then it queries for expired leases and checks
+/// whether only expired leases are returned, and that they are returned in
+/// the order from most to least expired. It also checks that the lease
+/// which is marked as 'reclaimed' is not returned.
+TEST_F(PgSqlLeaseMgrTest, getExpiredLeases6) {
+    testGetExpiredLeases6();
+}
+
+/// @brief Check that expired reclaimed DHCPv6 leases are removed.
+TEST_F(PgSqlLeaseMgrTest, deleteExpiredReclaimedLeases6) {
+    testDeleteExpiredReclaimedLeases6();
+}
+
 };

+ 30 - 5
src/lib/dhcpsrv/tests/schema_mysql_copy.h

@@ -220,11 +220,12 @@ const char* create_statement[] = {
     "ALTER TABLE lease6 "
         "ADD COLUMN state INT UNSIGNED DEFAULT 0",
 
-    "CREATE INDEX lease4_by_state_expire ON lease4 (state, expire)",
-    "CREATE INDEX lease6_by_state_expire ON lease6 (state, expire)",
+    "CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC)",
+    "CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC)",
 
-    // Production schema includes the lease_state table which maps
-    // the lease states to their names. This is not used in the unit tests
+    // Production schema includes the lease_state table and
+    // lease_hwaddr_source tables which map to the values in lease4
+    // and lease6 tables. This is not used in the unit tests
     // so it is commented out.
 
     /*"CREATE TABLE IF NOT EXISTS lease_state (",
@@ -233,8 +234,32 @@ const char* create_statement[] = {
 
     "INSERT INTO lease_state VALUES (0, \"default\");",
     "INSERT INTO lease_state VALUES (1, \"declined\");",
-    "INSERT INTO lease_state VALUES (2, \"expired-reclaimed\");",*/
+    "INSERT INTO lease_state VALUES (2, \"expired-reclaimed\");",
 
+    "ALTER TABLE lease4 "
+        "ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state) "
+        "REFERENCES lease_state (state)",
+
+    "ALTER TABLE lease6 "
+        "ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state) "
+        "REFERENCES lease_state (state)",
+
+    "ALTER TABLE lease6 "
+        "ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type) "
+        "REFERENCES lease6_types (lease_type)",
+
+    "UPDATE lease_hwaddr_source "
+        "SET name = 'HWADDR_SOURCE_DOCSIS_CMTS' "
+        "WHERE hwaddr_source = 64",
+
+    "INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM')",
+
+    "ALTER TABLE lease_hwaddr_source "
+        "MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL DEFAULT 0",
+
+    "ALTER TABLE lease6 "
+        "ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source) "
+        "REFERENCES lease_hwaddr_source (hwaddr_source)",*/
 
     // Schema upgrade to 4.0 ends here.
 

+ 43 - 1
src/lib/dhcpsrv/tests/schema_pgsql_copy.h

@@ -1,4 +1,4 @@
-// Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+// Copyright (C) 2014-2015 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
@@ -87,6 +87,48 @@ const char* create_statement[] = {
     "INSERT INTO schema_version VALUES (1, 0)",
     "COMMIT",
 
+    // This line concludes creation of database version 1.0.
+
+    // Schema upgrade to 2.0 starts here.
+
+    "ALTER TABLE lease4 "
+        "ADD COLUMN state INT8 DEFAULT 0",
+
+    "ALTER TABLE lease6 "
+        "ADD COLUMN state INT8 DEFAULT 0",
+
+    "CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC)",
+    "CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC)",
+
+    // Production schema includes the lease_state table which maps
+    // the lease states to their names. This is not used in the unit tests
+    // so it is commented out.
+
+    /*"CREATE TABLE lease_state (",
+        "state INT8 PRIMARY KEY NOT NULL,"
+        "name VARCHAR(64) NOT NULL);",
+
+    "ALTER TABLE lease4 "
+        "ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state) "
+        "REFERENCES lease_state (state)",
+
+    "ALTER TABLE lease6 "
+        "ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state) "
+        "REFERENCES lease_state (state)",
+
+    "ALTER TABLE lease6 "
+        "ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type) "
+        "REFERENCES lease6_types (lease_type)",
+
+    "INSERT INTO lease_state VALUES (0, \"default\");",
+    "INSERT INTO lease_state VALUES (1, \"declined\");",
+    "INSERT INTO lease_state VALUES (2, \"expired-reclaimed\");",*/
+
+    "UPDATE schema_version SET version = '2', minor = '0';",
+    "COMMIT",
+
+    // Schema upgrade to 2.0 ends here.
+
     NULL
 };