Browse Source

[master] Merge branch 'trac3080'

Adds support for Postgresql backend to Kea
Thomas Markwalder 11 years ago
parent
commit
1aae8b1fab

+ 75 - 1
configure.ac

@@ -294,7 +294,9 @@ case "$host" in
 	# it should be avoided to rely on 'osx_version' unless there's no
 	# viable alternative.
 	osx_version=`/usr/bin/sw_vers -productVersion`
-	if [ test $osx_version = "10.9" ]; then
+	if [ test $osx_version = "10.9" \
+         -o $osx_version = "10.9.1" \
+         -o $osx_version = "10.9.2" ]; then
 		bind10_undefined_pthread_behavior=yes
 	fi
 
@@ -969,6 +971,58 @@ AC_CHECK_HEADER(sys/filio.h)
 # ... and at the shell level, so Makefile.am can take action depending on this.
 AM_CONDITIONAL(HAVE_MYSQL, test "$MYSQL_CONFIG" != "")
 
+pg_config="no"
+AC_ARG_WITH([dhcp-pgsql],
+  AC_HELP_STRING([--with-dhcp-pgsql=PATH],
+    [path to the PostgreSQL 'pg_config' script]),
+    [pg_config="$withval"])
+
+if test "${pg_config}" = "yes" ; then
+    PG_CONFIG="/usr/bin/pg_config"
+elif test "${pg_config}" != "no" ; then
+    PG_CONFIG="${withval}"
+fi
+
+if test "$PG_CONFIG" != "" ; then
+    if test -d "$PG_CONFIG" -o ! -x "$PG_CONFIG" ; then
+        AC_MSG_ERROR([--with-dhcp-pgsql should point to a pg_config program])
+    fi
+
+    PGSQL_CPPFLAGS=`$PG_CONFIG --cppflags`
+    PGSQL_INCLUDEDIR=`$PG_CONFIG --includedir`
+    PGSQL_CPPFLAGS="$PGSQL_CPPFLAGS -I$PGSQL_INCLUDEDIR"
+    PGSQL_LIBS=`$PG_CONFIG --libdir`
+    PGSQL_LIBS="-L$PGSQL_LIBS -lpq"
+    PGSQL_VERSION=`$PG_CONFIG --version`
+
+    AC_SUBST(PGSQL_CPPFLAGS)
+    AC_SUBST(PGSQL_LIBS)
+
+    # Check that a simple program using PostgreSQL functions can compile and link.
+    CPPFLAGS_SAVED="$CPPFLAGS"
+    LIBS_SAVED="$LIBS"
+
+    CPPFLAGS="$PGSQL_CPPFLAGS $CPPFLAGS"
+    LIBS="$PGSQL_LIBS $LIBS"
+
+    AC_LINK_IFELSE(
+            [AC_LANG_PROGRAM([#include <libpq-fe.h>],
+                             [PGconn * c = PQconnectdb("dbname = 'postgres'");
+                              PQfinish(c);])],
+            [AC_MSG_RESULT([checking for PostgreSQL headers and library... yes])],
+            [AC_MSG_RESULT([checking for PostgreSQL headers and library... no])
+             AC_MSG_ERROR([Needs PostgreSQL library])]
+    )
+
+    CPPFLAGS=$CPPFLAGS_SAVED
+    LIBS=$LIBS_SAVED
+
+    # Note that PostgreSQL is present in the config.h file
+    AC_DEFINE([HAVE_PGSQL], [1], [PostgreSQL is present])
+fi
+
+# ... and at the shell level, so Makefile.am can take action depending on this.
+AM_CONDITIONAL(HAVE_PGSQL, test "$PG_CONFIG" != "")
 
 # Check for log4cplus
 log4cplus_path="yes"
@@ -1743,6 +1797,26 @@ MySQL:
   MYSQL_CPPFLAGS:  ${MYSQL_CPPFLAGS}
   MYSQL_LIBS:      ${MYSQL_LIBS}
 END
+else
+cat >> config.report << END
+
+MySQL: no
+END
+fi
+
+if test "$PGSQL_CPPFLAGS" != "" ; then
+cat >> config.report << END
+
+PostgreSQL:
+  PGSQL_VERSION:   ${PGSQL_VERSION}
+  PGSQL_CPPFLAGS:  ${PGSQL_CPPFLAGS}
+  PGSQL_LIBS:      ${PGSQL_LIBS}
+END
+else
+cat >> config.report << END
+
+PostgreSQL: no
+END
 fi
 
 if test "$enable_gtest" != "no"; then

+ 150 - 23
doc/guide/bind10-guide.xml

@@ -3565,19 +3565,19 @@ then change those defaults with config set Resolver/forward_addresses[0]/address
       <para>
       BIND 10 DHCP stores its leases in a lease database.  The software has been written in
       a way that makes it possible to choose which database product should be used to
-      store the lease information.  At present, only support for MySQL is provided, and that support must
-      be explicitly included when BIND 10 is built.  This section covers the building of
-      BIND 10 with MySQL and the creation of the lease database.
+      store the lease information.  At present, Kea supports 3 database backends: MySQL,
+      PostgreSQL and memfile. To limit external dependencies, both MySQL and PostgreSQL
+      support are disabled by default and only memfile (which is implemented in pure C++)
+      is available. Support for a given database backend must be explicitly included when
+      BIND 10 is built.  This section covers the building of BIND 10 with MySQL and/or PostgreSQL
+      and the creation of the lease database.
       </para>
       <section>
-        <title>Install MySQL</title>
+        <title>Building with MySQL support</title>
         <para>
           Install MySQL according to the instructions for your system.  The client development
           libraries must be installed.
         </para>
-      </section>
-      <section>
-        <title>Build and Install BIND 10</title>
         <para>
           Build and install BIND 10 as described in <xref linkend="installation"/>, with
           the following modification: to enable the MySQL database code, at the
@@ -3590,8 +3590,8 @@ then change those defaults with config set Resolver/forward_addresses[0]/address
           ...if not.
         </para>
       </section>
-      <section id="dhcp-database-create">
-        <title>Create MySQL Database and BIND 10 User</title>
+      <section id="dhcp-mysql-database-create">
+        <title>Create MySQL Database and Kea User</title>
         <para>
           The next task is to create both the lease database and the user under which the servers will
           access it. A number of steps are required:
@@ -3625,6 +3625,108 @@ Bye<userinput/>
 $</screen>
        </para>
      </section>
+
+
+      <section>
+        <title>Building with PostgreSQL support</title>
+        <para>
+          Install PostgreSQL according to the instructions for your system.  The client development
+          libraries must be installed. Client development libraries are often packaged as &quot;libpq&quot;.
+        </para>
+        <para>
+          Build and install BIND 10 as described in <xref linkend="installation"/>, with
+          the following modification: to enable the PostgreSQL database code, at the
+          "configure" step (see <xref linkend="configure"/>), specify the location of the
+          PostgreSQL configuration program "pg_config" with the "--with-dhcp-pgsql" switch,
+          i.e.
+          <screen><userinput>./configure [other-options] --with-dhcp-pgsql</userinput></screen>
+          ...if Postgresql was installed in the default location, or:
+          <screen><userinput>./configure [other-options] --with-dhcp-pgsql=<replaceable>path-to-pg_config</replaceable></userinput></screen>
+          ...if not.
+        </para>
+      </section>
+      <section id="dhcp-pgsql-database-create">
+        <title>Create PostgreSQL Database and Kea User</title>
+        <para>
+          The next task is to create both the lease database and the user under which the servers will
+          access it. A number of steps are required:
+        </para>
+        <para>
+          1. Log into PostgreSQL as "root":
+          <screen>$ <userinput>sudo -u postgres psql postgres</userinput>
+Enter password:<userinput/>
+   :<userinput/>
+postgres=#</screen>
+        </para>
+        <para>
+          2. Create the database:
+          <screen>postgres=# <userinput>CREATE DATABASE <replaceable>database-name</replaceable>;</userinput></screen>
+          ... <replaceable>database-name</replaceable> is the name you have chosen for the database.
+        </para>
+
+         <para>
+          3. Create the user under which Kea will access the database (and give it a password), then grant it access to the database:
+          <screen>postgres=# <userinput>CREATE USER <replaceable>user-name</replaceable> WITH PASSWORD <replaceable>password</replaceable>;</userinput>
+postgres=#> <userinput>GRANT ALL PRIVILEGES ON DATABASE <replaceable>database-name</replaceable> TO <replaceable>user-name</replaceable>;</userinput></screen>
+        </para>
+
+         <para>
+          4. Exit PostgreSQL:
+          <screen>postgres=# <userinput>\q</userinput>
+Bye<userinput/>
+$</screen>
+       </para>
+       <para>
+        5. Create the database tables using the new user's credentials.
+        After entering the following command, you will be prompted for the new
+        user's password. When the command completes you will be returned to
+        the shell prompt. You should see output similiar to following:
+<screen>$ <userinput>psql -d <replaceable>database-name</replaceable> -U <replaceable>user-name</replaceable> -f <replaceable>path-to-bind10</replaceable>/share/bind10/dhcpdb_create.pgsql;</userinput>
+Password for user <replaceable>user-name</replaceable>:
+CREATE TABLE
+CREATE INDEX
+CREATE INDEX
+CREATE TABLE
+CREATE INDEX
+CREATE TABLE
+START TRANSACTION
+INSERT 0 1
+INSERT 0 1
+INSERT 0 1
+COMMIT
+CREATE TABLE
+START TRANSACTION
+INSERT 0 1
+COMMIT
+$
+</screen>
+  </para>
+  <para>
+  If instead you encounter an error such as shown below:
+  </para>
+<screen>
+psql: FATAL:  no pg_hba.conf entry for host "[local]", user "<replaceable>user-name</replaceable>", database "<replaceable>database-name</replaceable>", SSL off
+</screen>
+  <para>
+  This indicates that the Postgresql configuration needs to be modified.
+  Kea uses password authentication when connecting to the database and must
+  have the appropriate entries added to Posgresql's pg_hba.conf file.  This
+  file is normally located in the primary data directory for your Postgresql
+  server. The precise path may vary but the default location for Postgres 9.3
+  on Centos 6.5 is:
+  <filename>/var/lib/pgsql/9.3/data/pg_hba.conf</filename>.
+  Adding lines similiar to following should be sufficient:
+  </para>
+<screen>
+local   <replaceable>database-name</replaceable>    <replaceable>user-name</replaceable>                                 password
+host    <replaceable>database-name</replaceable>    <replaceable>user-name</replaceable>          127.0.0.1/32           password
+host    <replaceable>database-name</replaceable>    <replaceable>user-name</replaceable>          ::1/128                password
+</screen>
+  <para>
+  Please consult your PostgreSQL user manual before making these changes as they
+  may expose your other databases that you run on the same system.
+  </para>
+      </section>
    </section>
 
   </chapter>
@@ -3736,8 +3838,8 @@ Dhcp4/dhcp-ddns/qualifying-suffix	"example.com"	string
       <section>
       <title>Database Configuration</title>
       <para>
-      All leases issued by the server are stored in the lease database.  Currently,
-      the only supported database is MySQL
+      All leases issued by the server are stored in the lease database.  Currently
+      there are 3 database backends available: MySQL, PostgreSQL and experimental memfile.
       <footnote>
       <para>
       The server comes with an in-memory database ("memfile") configured as the default
@@ -3758,12 +3860,13 @@ Dhcp4/dhcp-ddns/qualifying-suffix	"example.com"	string
         </note>
       <para>
       Database configuration is controlled through the Dhcp4/lease-database parameters.
-      The type of the database must be set to MySQL (although the string entered is "mysql"):
+      The type of the database must be set to "mysql", "postgresql" or "memfile":
 <screen>
 &gt; <userinput>config set Dhcp4/lease-database/type "mysql"</userinput>
 </screen>
       Next, the name of the database is to hold the leases must be set: this is the
-      name used when the lease database was created (see <xref linkend="dhcp-database-create"/>).
+      name used when the lease database was created (see <xref linkend="dhcp-mysql-database-create"/>
+      or <xref linkend="dhcp-pgsql-database-create"/>).
 <screen>
 &gt; <userinput>config set Dhcp4/lease-database/name "<replaceable>database-name</replaceable>"</userinput>
 </screen>
@@ -5212,8 +5315,8 @@ Dhcp6/dhcp-ddns/qualifying-suffix   "example.com"   string
       <section>
       <title>Database Configuration</title>
       <para>
-      All leases issued by the server are stored in the lease database.  Currently,
-      the only supported database is MySQL
+      All leases issued by the server are stored in the lease database. Currently
+      there are 3 database backends available: MySQL, PostgreSQL and experimental memfile.
       <footnote>
       <para>
       The server comes with an in-memory database ("memfile") configured as the default
@@ -5234,12 +5337,13 @@ Dhcp6/dhcp-ddns/qualifying-suffix   "example.com"   string
         </note>
       <para>
       Database configuration is controlled through the Dhcp6/lease-database parameters.
-      The type of the database must be set to MySQL (although the string entered is "mysql"):
+      The type of the database must be set to "mysql", "postgresql" or "memfile":
 <screen>
 &gt; <userinput>config set Dhcp6/lease-database/type "mysql"</userinput>
 </screen>
       Next, the name of the database is to hold the leases must be set: this is the
-      name used when the lease database was created (see <xref linkend="dhcp-database-create"/>).
+      name used when the lease database was created (see <xref linkend="dhcp-mysql-database-create"/>
+      or <xref linkend="dhcp-pgsql-database-create"/>).
 <screen>
 &gt; <userinput>config set Dhcp6/lease-database/name "<replaceable>database-name</replaceable>"</userinput>
 </screen>
@@ -6501,13 +6605,36 @@ Dhcp6/dhcp-ddns/qualifying-suffix	"example.com"	string
       development and should be treated as <quote>not implemented
       yet</quote>, rather than actual limitations.</para>
       <itemizedlist>
+          <listitem> <!-- see tickets #3234, #3281 -->
+            <para>
+              On-line configuration has some limitations. Adding new subnets or
+              modifying existing ones work, as is removing the last subnet from
+              the list. However, removing non-last (e.g. removing subnet 1,2 or 3 if
+              there are 4 subnets configured) will cause issues. The problem is
+              caused by simplistic subnet-id assignment. The subnets are always
+              numbered, starting from 1. That subnet-id is then used in leases
+              that are stored in the lease database. Removing non-last subnet will
+              cause the configuration information to mismatch data in the lease
+              database. It is possible to manually update subnet-id fields in
+              MySQL or PostgreSQL database, but it is awkward and error prone
+              process. A better reconfiguration support is planned.
+            </para>
+          </listitem>
 
-        <listitem> <!-- see tickets #3234, #3281 -->
-            <simpara>
-              Removal of a subnet during server reconfiguration may cause renumbering
-              of auto-generated subnet identifiers, as described in section
-              <xref linkend="ipv6-subnet-id"/>.
-            </simpara>
+        <listitem>
+          <para>
+            On startup, the DHCPv6 server does not get the full configuration from
+            BIND 10.  To remedy this, after starting BIND 10, modify any parameter
+            and commit the changes, e.g.
+            <screen>
+&gt; <userinput>config show Dhcp6/renew-timer</userinput>
+Dhcp6/renew-timer	1000	integer	(default)
+&gt; <userinput>config set Dhcp6/renew-timer 1001</userinput>
+&gt; <userinput>config commit</userinput></screen>
+          </para>
+        </listitem>
+        <listitem>
+          <simpara>Temporary addresses are not supported.</simpara>
         </listitem>
         <listitem>
           <simpara>

+ 11 - 2
src/lib/dhcpsrv/Makefile.am

@@ -7,6 +7,9 @@ AM_CPPFLAGS += $(BOOST_INCLUDES)
 if HAVE_MYSQL
 AM_CPPFLAGS += $(MYSQL_CPPFLAGS)
 endif
+if HAVE_PGSQL
+AM_CPPFLAGS += $(PGSQL_CPPFLAGS)
+endif
 
 AM_CXXFLAGS = $(B10_CXXFLAGS)
 
@@ -54,6 +57,9 @@ libb10_dhcpsrv_la_SOURCES += memfile_lease_mgr.cc memfile_lease_mgr.h
 if HAVE_MYSQL
 libb10_dhcpsrv_la_SOURCES += mysql_lease_mgr.cc mysql_lease_mgr.h
 endif
+if HAVE_PGSQL
+libb10_dhcpsrv_la_SOURCES += pgsql_lease_mgr.cc pgsql_lease_mgr.h
+endif
 libb10_dhcpsrv_la_SOURCES += option_space_container.h
 libb10_dhcpsrv_la_SOURCES += pool.cc pool.h
 libb10_dhcpsrv_la_SOURCES += subnet.cc subnet.h
@@ -77,6 +83,9 @@ libb10_dhcpsrv_la_LDFLAGS  = -no-undefined -version-info 3:0:0
 if HAVE_MYSQL
 libb10_dhcpsrv_la_LDFLAGS += $(MYSQL_LIBS)
 endif
+if HAVE_PGSQL
+libb10_dhcpsrv_la_LDFLAGS += $(PGSQL_LIBS)
+endif
 
 if USE_CLANGPP
 # Disable unused parameter warning caused by some of the
@@ -88,8 +97,8 @@ endif
 EXTRA_DIST = dhcpsrv_messages.mes
 
 # Distribute MySQL schema creation script and backend documentation
-EXTRA_DIST += dhcpdb_create.mysql database_backends.dox libdhcpsrv.dox
-dist_pkgdata_DATA = dhcpdb_create.mysql
+EXTRA_DIST += dhcpdb_create.mysql dhcpdb_create.pgsql database_backends.dox libdhcpsrv.dox
+dist_pkgdata_DATA = dhcpdb_create.mysql dhcpdb_create.pgsql
 
 install-data-local:
 	$(mkinstalldirs) $(DESTDIR)$(dhcp_data_dir)

+ 73 - 0
src/lib/dhcpsrv/database_backends.dox

@@ -121,4 +121,77 @@
   The unit tests are run automatically when "make check" is executed (providing
   that BIND 10 has been build with the \--with-dhcp-mysql switch (see the installation
   section in the <a href="http://bind10.isc.org/docs/bind10-guide.html">BIND 10 Guide</a>).
+
+ @subsection dhcp-pgsql-unittest PostgreSQL unit-tests
+
+  Conceptually, the steps required to run PostgreSQL unit-tests are the same as
+  in MySQL. First, a database called <i>keatest</i> must be created. A database
+  user, also called <i>keatest</i> (that will be allowed to log in using password
+  <i>keatest</i>) must be created and given full privileges in that database. The
+  unit tests create the schema in the database before each test and delete it
+  afterwards.
+
+  PostgreSQL set up differs from system to system. Please consult your OS-specific
+  PostgreSQL documentation. The remainder of that section uses Ubuntu 13.10 x64 as
+  example. On Ubuntu, after installing PostgreSQL (with <tt>sudo apt-get install
+  postgresql</tt>), it is installed as user <i>postgres</i>. To create new databases
+  or add new users, initial commands must be issued as user postgres:
+
+@verbatim
+$ sudo -u postgres psql postgres
+[sudo] password for thomson:
+psql (9.1.12)
+Type "help" for help.
+postgres=# CREATE USER keatest WITH PASSWORD 'keatest';
+CREATE ROLE
+postgres=# CREATE DATABASE keatest;
+CREATE DATABASE
+postgres=# GRANT ALL PRIVILEGES ON DATABASE keatest TO keatest;
+GRANT
+postgres=# \q
+@endverbatim
+
+  Now we are back to our regular, unprivileged user. Try to log into the newly
+  created database using keatest credentials:
+@verbatim
+$ psql -d keatest -U keatest
+Password for user keatest:
+psql (9.1.12)
+Type "help" for help.
+
+keatest=>
+@endverbatim
+
+  If instead of seeing keatest=> prompt, your login will be refused with error
+  code about failed peer or indent authentication, it means that PostgreSQL is
+  configured to check unix username and reject login attepts if PostgreSQL names
+  are different. To alter that, PostgreSQL configuration must be changed.
+  Alternatively, you may set up your environment, so the tests would be run from
+  unix account keatest. <tt>/etc/postgresql/9.1/main/pg_hba.conf</tt> config file
+  had to betweaked. It may be in a different location in your system. The following
+  lines:
+
+@verbatim
+local   all             all                                     peer
+host    all             all             127.0.0.1/32            md5
+host    all             all             ::1/128                 md5
+@endverbatim
+
+  were replaced with:
+
+@verbatim
+local   all             all                                     password
+host    all             all             127.0.0.1/32            password
+host    all             all             ::1/128                 password
+@endverbatim
+
+  Please consult your PostgreSQL user manual before applying those changes as
+  those changes may expose your other databases that you run on the same system.
+  In general case, it is a poor idea to run anything of value on a system
+  that runs tests. Use caution!
+
+  The unit tests are run automatically when "make check" is executed (providing
+  that BIND 10 has been build with the \--with-dhcp-pgsql switch (see the installation
+  section in the <a href="http://bind10.isc.org/docs/bind10-guide.html">BIND10 Guide</a>).
+
   */

+ 1 - 1
src/lib/dhcpsrv/dbaccess_parser.cc

@@ -67,7 +67,7 @@ DbAccessParser::build(isc::data::ConstElementPtr config_value) {
 
     // b. Check if the 'type; keyword known and throw an exception if not.
     string dbtype = type_ptr->second;
-    if ((dbtype != "memfile") && (dbtype != "mysql")) {
+    if ((dbtype != "memfile") && (dbtype != "mysql") && (dbtype != "postgresql")) {
         isc_throw(BadValue, "unknown backend database type: " << dbtype);
     }
 

+ 135 - 0
src/lib/dhcpsrv/dhcpdb_create.pgsql

@@ -0,0 +1,135 @@
+-- Copyright (C) 2012-2013  Internet Systems Consortium.
+
+-- Permission to use, copy, modify, and distribute this software for any
+-- purpose with or without fee is hereby granted, provided that the above
+-- copyright notice and this permission notice appear in all copies.
+
+-- THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
+-- DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
+-- IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
+-- INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
+-- INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
+-- FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
+-- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
+-- WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
+
+-- This is the BIND 10 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
+-- for other databases.
+
+-- To create the schema, either type the command:
+
+-- psql -U <user> -W <password> <database> < dhcpdb_create.pgsql
+
+-- ... at the command prompt, or log in to the PostgreSQL database and at the "postgres=#"
+-- prompt, issue the command:
+
+-- @dhcpdb_create.pgsql
+
+
+-- Holds the IPv4 leases.
+CREATE TABLE lease4 (
+    address BIGINT PRIMARY KEY NOT NULL,        -- IPv4 address
+    hwaddr BYTEA,                               -- Hardware address
+    client_id BYTEA,                            -- Client ID
+    valid_lifetime BIGINT,                      -- Length of the lease (seconds)
+    expire TIMESTAMP WITH TIME ZONE,            -- Expiration time of the lease
+    subnet_id BIGINT,                           -- Subnet identification
+    fqdn_fwd BOOLEAN,                           -- Has forward DNS update been performed by a server
+    fqdn_rev BOOLEAN,                           -- Has reverse DNS update been performed by a server
+    hostname VARCHAR(255)                       -- The FQDN of the client
+    );
+
+
+-- Create search indexes for lease4 table
+-- index by hwaddr and subnet_id
+CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
+
+-- index by client_id and subnet_id
+CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
+
+-- Holds the IPv6 leases.
+-- N.B. The use of a VARCHAR for the address is temporary for development:
+-- it will eventually be replaced by BINARY(16).
+CREATE TABLE lease6 (
+    address VARCHAR(39) PRIMARY KEY NOT NULL,   -- IPv6 address
+    duid BYTEA,                                 -- DUID
+    valid_lifetime BIGINT,                      -- Length of the lease (seconds)
+    expire TIMESTAMP WITH TIME ZONE,            -- Expiration time of the lease
+    subnet_id BIGINT,                           -- Subnet identification
+    pref_lifetime BIGINT,                       -- Preferred lifetime
+    lease_type SMALLINT,                        -- Lease type (see lease6_types
+                                                --    table for possible values)
+    iaid INT,                                   -- See Section 10 of RFC 3315
+    prefix_len SMALLINT,                        -- For IA_PD only
+    fqdn_fwd BOOLEAN,                           -- Has forward DNS update been performed by a server
+    fqdn_rev BOOLEAN,                           -- Has reverse DNS update been performed by a server
+    hostname VARCHAR(255)                       -- The FQDN of the client
+    );
+
+-- Create search indexes for lease4 table
+-- index by iaid, subnet_id, and duid
+CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
+
+-- ... and a definition of lease6 types.  This table is a convenience for
+-- users of the database - if they want to view the lease table and use the
+-- type names, they can join this table with the lease6 table
+CREATE TABLE lease6_types (
+    lease_type SMALLINT PRIMARY KEY NOT NULL,   -- Lease type code.
+    name VARCHAR(5)                             -- Name of the lease type
+    );
+START TRANSACTION;
+INSERT INTO lease6_types VALUES (0, 'IA_NA');   -- Non-temporary v6 addresses
+INSERT INTO lease6_types VALUES (1, 'IA_TA');   -- Temporary v6 addresses
+INSERT INTO lease6_types VALUES (2, 'IA_PD');   -- Prefix delegations
+COMMIT;
+
+-- Finally, the version of the schema.  We start at 0.1 during development.
+-- This table is only modified during schema upgrades.  For historical reasons
+-- (related to the names of the columns in the BIND 10 DNS database file), the
+-- first column is called "version" and not "major".
+
+-- NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
+--       which defines the schema for the unit tests.  If you are updating
+--       the version number, the schema has changed: please ensure that
+--       schema_copy.h has been updated as well.
+CREATE TABLE schema_version (
+    version INT PRIMARY KEY NOT NULL,       -- Major version number
+    minor INT                               -- Minor version number
+    );
+START TRANSACTION;
+INSERT INTO schema_version VALUES (1, 0);
+COMMIT;
+
+-- Notes:
+
+-- Indexes
+-- =======
+-- It is likely that additional indexes will be needed.  However, the
+-- increase in lookup performance from these will come at the expense
+-- of a decrease in performance during insert operations due to the need
+-- to update the indexes.  For this reason, the need for additional indexes
+-- will be determined by experiment during performance tests.
+
+-- The most likely additional indexes will cover the following columns:
+
+-- expire
+-- To speed up the deletion of expired leases from the database.
+
+-- hwaddr and client_id
+-- For lease stability: if a client requests a new lease, try to find an
+-- existing or recently expired lease for it so that it can keep using the
+-- same IP address.
+
+-- Field Sizes
+-- ===========
+-- If any of the VARxxx field sizes are altered, the lengths in the MySQL
+-- backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
+
+-- Portability
+-- ===========
+-- Some columns contain binary data so are stored as BYTEA instead of
+-- VARCHAR.  This may be non-portable between databases: in this case, the
+-- definition should be changed to VARCHAR.

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

@@ -375,6 +375,90 @@ lease from the MySQL database for the specified address.
 A debug message issued when the server is attempting to update IPv6
 lease from the MySQL database for the specified address.
 
+% DHCPSRV_PGSQL_ADD_ADDR4 adding IPv4 lease with address %1
+A debug message issued when the server is about to add an IPv4 lease
+with the specified address to the PostgreSQL backend database.
+
+% DHCPSRV_PGSQL_ADD_ADDR6 adding IPv6 lease with address %1
+A debug message issued when the server is about to add an IPv6 lease
+with the specified address to the PostgreSQL backend database.
+
+% DHCPSRV_PGSQL_DEALLOC_ERROR An error occured deallocating SQL statements while closing the PostgreSQL lease database: %1
+This is an error message issued when a DHCP server (either V4 or V6) experienced
+and error freeing database SQL resources as part of closing its connection to
+the Postgresql database.  The connection is closed as part of normal server
+shutdown.  This error is most likely a programmatic issue that is highly
+unlikely to occur or negatively impact server operation.
+
+% DHCPSRV_PGSQL_COMMIT committing to MySQL database
+The code has issued a commit call.  All outstanding transactions will be
+committed to the database.  Note that depending on the PostgreSQL settings,
+the committal may not include a write to disk.
+
+% DHCPSRV_PGSQL_DB opening PostgreSQL lease database: %1
+This informational message is logged when a DHCP server (either V4 or
+V6) is about to open a PostgreSQL lease database.  The parameters of the
+connection including database name and username needed to access it
+(but not the password if any) are logged.
+
+% DHCPSRV_PGSQL_DELETE_ADDR deleting lease for address %1
+A debug message issued when the server is attempting to delete a lease for
+the specified address from the PostgreSQL database for the specified address.
+
+% DHCPSRV_PGSQL_GET_ADDR4 obtaining IPv4 lease for address %1
+A debug message issued when the server is attempting to obtain an IPv4
+lease from the PostgreSQL database for the specified address.
+
+% DHCPSRV_PGSQL_GET_ADDR6 obtaining IPv6 lease for address %1 (lease type %2)
+A debug message issued when the server is attempting to obtain an IPv6
+lease from the PostgreSQL database for the specified address.
+
+% DHCPSRV_PGSQL_GET_CLIENTID obtaining IPv4 leases for client ID %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
+client identification.
+
+% 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
+hardware address.
+
+% DHCPSRV_PGSQL_GET_IAID_DUID obtaining IPv4 leases for IAID %1 and DUID %2, lease type %3
+A debug message issued when the server is attempting to obtain a set of
+IPv6 lease from the PostgreSQL database for a client with the specified IAID
+(Identity Association ID) and DUID (DHCP Unique Identifier).
+
+% DHCPSRV_PGSQL_GET_IAID_SUBID_DUID obtaining IPv4 leases for IAID %1, Subnet ID %2, DUID %3, and lease type %4
+A debug message issued when the server is attempting to obtain an IPv6
+lease from the PostgreSQL database for a client with the specified IAID
+(Identity Association ID), Subnet ID and DUID (DHCP Unique Identifier).
+
+% DHCPSRV_PGSQL_GET_SUBID_CLIENTID obtaining IPv4 lease for subnet ID %1 and client ID %2
+A debug message issued when the server is attempting to obtain an IPv4
+lease from the PostgreSQL database for a client with the specified subnet ID
+and client ID.
+
+% DHCPSRV_PGSQL_GET_SUBID_HWADDR obtaining IPv4 lease for subnet ID %1 and hardware address %2
+A debug message issued when the server is attempting to obtain an IPv4
+lease from the PostgreSQL database for a client with the specified subnet ID
+and hardware address.
+
+% DHCPSRV_PGSQL_GET_VERSION obtaining schema version information
+A debug message issued when the server is about to obtain schema version
+information from the PostgreSQL database.
+
+% DHCPSRV_PGSQL_ROLLBACK rolling back PostgreSQL database
+The code has issued a rollback call.  All outstanding transaction will
+be rolled back and not committed to the database.
+
+% DHCPSRV_PGSQL_UPDATE_ADDR4 updating IPv4 lease for address %1
+A debug message issued when the server is attempting to update IPv4
+lease from the PostgreSQL database for the specified address.
+
+% DHCPSRV_PGSQL_UPDATE_ADDR6 updating IPv6 lease for address %1
+A debug message issued when the server is attempting to update IPv6
+lease from the PostgreSQL database for the specified address.
+
 % DHCPSRV_NOTYPE_DB no 'type' keyword to determine database backend: %1
 This is an error message, logged when an attempt has been made to access
 a database backend, but where no 'type' keyword has been included in

+ 10 - 0
src/lib/dhcpsrv/lease_mgr_factory.cc

@@ -20,6 +20,9 @@
 #ifdef HAVE_MYSQL
 #include <dhcpsrv/mysql_lease_mgr.h>
 #endif
+#ifdef HAVE_PGSQL
+#include <dhcpsrv/pgsql_lease_mgr.h>
+#endif
 
 #include <boost/algorithm/string.hpp>
 #include <boost/foreach.hpp>
@@ -125,6 +128,13 @@ LeaseMgrFactory::create(const std::string& dbaccess) {
         return;
     }
 #endif
+#ifdef HAVE_PGSQL
+    if (parameters[type] == string("postgresql")) {
+        LOG_INFO(dhcpsrv_logger, DHCPSRV_PGSQL_DB).arg(redacted);
+        getLeaseMgrPtr().reset(new PgSqlLeaseMgr(parameters));
+        return;
+    }
+#endif
     if (parameters[type] == string("memfile")) {
         LOG_INFO(dhcpsrv_logger, DHCPSRV_MEMFILE_DB).arg(redacted);
         getLeaseMgrPtr().reset(new Memfile_LeaseMgr(parameters));

File diff suppressed because it is too large
+ 1211 - 0
src/lib/dhcpsrv/pgsql_lease_mgr.cc


+ 607 - 0
src/lib/dhcpsrv/pgsql_lease_mgr.h

@@ -0,0 +1,607 @@
+// Copyright (C) 2013-2014 Internet Systems Consortium, Inc. ("ISC")
+//
+// Permission to use, copy, modify, and/or distribute this software for any
+// purpose with or without fee is hereby granted, provided that the above
+// copyright notice and this permission notice appear in all copies.
+//
+// THE SOFTWARE IS PROVIDED "AS IS" AND ISC DISCLAIMS ALL WARRANTIES WITH
+// REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+// AND FITNESS.  IN NO EVENT SHALL ISC BE LIABLE FOR ANY SPECIAL, DIRECT,
+// INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM
+// LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE
+// OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR
+// PERFORMANCE OF THIS SOFTWARE.
+
+#ifndef PGSQL_LEASE_MGR_H
+#define PGSQL_LEASE_MGR_H
+
+#include <dhcp/hwaddr.h>
+#include <dhcpsrv/lease_mgr.h>
+
+#include <boost/scoped_ptr.hpp>
+#include <boost/utility.hpp>
+#include <libpq-fe.h>
+
+#include <vector>
+
+namespace isc {
+namespace dhcp {
+
+/// @brief An auxiliary structure for marshalling data for compiled statements
+///
+/// It represents a single field used in a query (e.g. one field used in WHERE
+/// or UPDATE clauses).
+struct PgSqlParam {
+    std::string value; ///< The actual value represented as text
+    bool isbinary;     ///< Boolean flag that indicates if data is binary
+    int binarylen;     ///< Specified binary length
+
+    /// @brief Constructor for text parameters
+    ///
+    /// Constructs a text (i.e. non-binary) instance given a string value.
+    /// @param val string containing the text value of the parameter.  The
+    /// default is an empty string which serves as the default or empty
+    /// parameter constructor.
+    PgSqlParam (const std::string& val = "")
+        : value(val), isbinary(false), binarylen(0) {
+    }
+
+    /// @brief Constructor for binary data parameters
+    ///
+    /// Constructs a binary data instance given a vector of binary data.
+    /// @param data vector of binary data from which to set the parameter's
+    /// value.
+    PgSqlParam (const std::vector<uint8_t>& data)
+      : value(data.begin(), data.end()), isbinary(true),
+          binarylen(data.size()) {
+    }
+};
+
+/// @brief Defines all parameters for binding a compiled statement
+typedef std::vector<PgSqlParam> BindParams;
+
+/// @brief Describes a single compiled statement
+struct PgSqlStatementBind {
+    const char* stmt_name; ///< Name of the compiled statement
+    int stmt_nbparams; ///< Number of statement parameters
+};
+
+// Forward definitions (needed for shared_ptr definitions)
+// See pgsql_lease_mgr.cc file for actual class definitions
+class PgSqlLease4Exchange;
+class PgSqlLease6Exchange;
+
+/// Defines PostgreSQL backend version: 1.0
+const uint32_t PG_CURRENT_VERSION = 1;
+const uint32_t PG_CURRENT_MINOR = 0;
+
+/// @brief PostgreSQL Lease Manager
+///
+/// This class provides the \ref isc::dhcp::LeaseMgr interface to the PostgreSQL
+/// database.  Use of this backend presupposes that a PostgreSQL database is
+/// available and that the Kea schema has been created within it.
+class PgSqlLeaseMgr : public LeaseMgr {
+public:
+
+    /// @brief Constructor
+    ///
+    /// Uses the following keywords in the parameters passed to it to
+    /// connect to the database:
+    /// - name - Name of the database to which to connect (mandatory)
+    /// - host - Host to which to connect (optional, defaults to "localhost")
+    /// - user - Username under which to connect (optional)
+    /// - password - Password for "user" on the database (optional)
+    ///
+    /// If the database is successfully opened, the version number in the
+    /// schema_version table will be checked against hard-coded value in
+    /// the implementation file.
+    ///
+    /// Finally, all the SQL commands are pre-compiled.
+    ///
+    /// @param parameters A data structure relating keywords and values
+    ///        concerned with the database.
+    ///
+    /// @throw isc::dhcp::NoDatabaseName Mandatory database name not given
+    /// @throw isc::dhcp::DbOpenError Error opening the database
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    PgSqlLeaseMgr(const ParameterMap& parameters);
+
+    /// @brief Destructor (closes database)
+    virtual ~PgSqlLeaseMgr();
+
+    /// @brief Adds an IPv4 lease
+    ///
+    /// @param lease lease to be added
+    ///
+    /// @result true if the lease was added, false if not (because a lease
+    ///         with the same address was already there).
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual bool addLease(const Lease4Ptr& lease);
+
+    /// @brief Adds an IPv6 lease
+    ///
+    /// @param lease lease to be added
+    ///
+    /// @result true if the lease was added, false if not (because a lease
+    ///         with the same address was already there).
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual bool addLease(const Lease6Ptr& lease);
+
+    /// @brief Returns an IPv4 lease for specified IPv4 address
+    ///
+    /// This method return a lease that is associated with a given address.
+    /// For other query types (by hardware addr, by Client ID) there can be
+    /// several leases in different subnets (e.g. for mobile clients that
+    /// got address in different subnets). However, for a single address
+    /// there can be only one lease, so this method returns a pointer to
+    /// a single lease, not a container of leases.
+    ///
+    /// @param addr address of the searched lease
+    ///
+    /// @return smart pointer to the lease (or NULL if a lease is not found)
+    ///
+    /// @throw isc::dhcp::DataTruncation Data was truncated on retrieval to
+    ///        fit into the space allocated for the result.  This indicates a
+    ///        programming error.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease4Ptr getLease4(const isc::asiolink::IOAddress& addr) const;
+
+    /// @brief Returns existing IPv4 leases for specified hardware address.
+    ///
+    /// Although in the usual case there will be only one lease, for mobile
+    /// clients or clients with multiple static/fixed/reserved leases there
+    /// can be more than one. Thus return type is a container, not a single
+    /// pointer.
+    ///
+    /// @param hwaddr hardware address of the client
+    ///
+    /// @return lease collection
+    ///
+    /// @throw isc::dhcp::DataTruncation Data was truncated on retrieval to
+    ///        fit into the space allocated for the result.  This indicates a
+    ///        programming error.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease4Collection getLease4(const isc::dhcp::HWAddr& hwaddr) const;
+
+    /// @brief Returns existing IPv4 leases for specified hardware address
+    ///        and a subnet
+    ///
+    /// There can be at most one lease for a given HW address in a single
+    /// pool, so this method with either return a single lease or NULL.
+    ///
+    /// @param hwaddr hardware address of the client
+    /// @param subnet_id identifier of the subnet that lease must belong to
+    ///
+    /// @return a pointer to the lease (or NULL if a lease is not found)
+    ///
+    /// @throw isc::dhcp::DataTruncation Data was truncated on retrieval to
+    ///        fit into the space allocated for the result.  This indicates a
+    ///        programming error.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease4Ptr getLease4(const isc::dhcp::HWAddr& hwaddr,
+                                SubnetID subnet_id) const;
+
+    /// @brief Returns existing IPv4 leases for specified client-id
+    ///
+    /// Although in the usual case there will be only one lease, for mobile
+    /// clients or clients with multiple static/fixed/reserved leases there
+    /// can be more than one. Thus return type is a container, not a single
+    /// pointer.
+    ///
+    /// @param clientid client identifier
+    ///
+    /// @return lease collection
+    ///
+    /// @throw isc::dhcp::DataTruncation Data was truncated on retrieval to
+    ///        fit into the space allocated for the result.  This indicates a
+    ///        programming error.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease4Collection getLease4(const ClientId& clientid) const;
+
+    /// @brief Returns IPv4 lease for the specified client identifier, HW
+    /// address and subnet identifier.
+    ///
+    /// @param client_id A client identifier.
+    /// @param hwaddr Hardware address.
+    /// @param subnet_id A subnet identifier.
+    ///
+    /// @return A pointer to the lease or NULL if the lease is not found.
+    /// @throw isc::NotImplemented On every call as this function is currently
+    /// not implemented for the MySQL backend.
+    virtual Lease4Ptr getLease4(const ClientId& client_id, const HWAddr& hwaddr,
+                                SubnetID subnet_id) const;
+
+
+    /// @brief Returns existing IPv4 lease for specified client-id
+    ///
+    /// There can be at most one lease for a given HW address in a single
+    /// pool, so this method with either return a single lease or NULL.
+    ///
+    /// @param clientid client identifier
+    /// @param subnet_id identifier of the subnet that lease must belong to
+    ///
+    /// @return a pointer to the lease (or NULL if a lease is not found)
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease4Ptr getLease4(const ClientId& clientid,
+                                SubnetID subnet_id) const;
+
+    /// @brief Returns existing IPv6 lease for a given IPv6 address.
+    ///
+    /// For a given address, we assume that there will be only one lease.
+    /// The assumption here is that there will not be site or link-local
+    /// addresses used, so there is no way of having address duplication.
+    ///
+    /// @param type specifies lease type: (NA, TA or PD)
+    /// @param addr address of the searched lease
+    ///
+    /// @return smart pointer to the lease (or NULL if a lease is not found)
+    ///
+    /// @throw isc::BadValue record retrieved from database had an invalid
+    ///        lease type field.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease6Ptr getLease6(Lease::Type type,
+                                const isc::asiolink::IOAddress& addr) const;
+
+    /// @brief Returns existing IPv6 leases for a given DUID+IA combination
+    ///
+    /// Although in the usual case there will be only one lease, for mobile
+    /// clients or clients with multiple static/fixed/reserved leases there
+    /// can be more than one. Thus return type is a container, not a single
+    /// pointer.
+    ///
+    /// @param type specifies lease type: (NA, TA or PD)
+    /// @param duid client DUID
+    /// @param iaid IA identifier
+    ///
+    /// @return smart pointer to the lease (or NULL if a lease is not found)
+    ///
+    /// @throw isc::BadValue record retrieved from database had an invalid
+    ///        lease type field.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease6Collection getLeases6(Lease::Type type, const DUID& duid,
+                                       uint32_t iaid) const;
+
+    /// @brief Returns existing IPv6 lease for a given DUID+IA combination
+    ///
+    /// @param type specifies lease type: (NA, TA or PD)
+    /// @param duid client DUID
+    /// @param iaid IA identifier
+    /// @param subnet_id subnet id of the subnet the lease belongs to
+    ///
+    /// @return lease collection (may be empty if no lease is found)
+    ///
+    /// @throw isc::BadValue record retrieved from database had an invalid
+    ///        lease type field.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual Lease6Collection getLeases6(Lease::Type type, const DUID& duid,
+                                        uint32_t iaid, SubnetID subnet_id) const;
+
+    /// @brief Updates IPv4 lease.
+    ///
+    /// Updates the record of the lease in the database (as identified by the
+    /// address) with the data in the passed lease object.
+    ///
+    /// @param lease4 The lease to be updated.
+    ///
+    /// @throw isc::dhcp::NoSuchLease Attempt to update a lease that did not
+    ///        exist.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual void updateLease4(const Lease4Ptr& lease4);
+
+    /// @brief Updates IPv6 lease.
+    ///
+    /// Updates the record of the lease in the database (as identified by the
+    /// address) with the data in the passed lease object.
+    ///
+    /// @param lease6 The lease to be updated.
+    ///
+    /// @throw isc::dhcp::NoSuchLease Attempt to update a lease that did not
+    ///        exist.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual void updateLease6(const Lease6Ptr& lease6);
+
+    /// @brief Deletes a lease.
+    ///
+    /// @param addr Address of the lease to be deleted.  This can be an IPv4
+    ///             address or an IPv6 address.
+    ///
+    /// @return true if deletion was successful, false if no such lease exists
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual bool deleteLease(const isc::asiolink::IOAddress& addr);
+
+    /// @brief Return backend type
+    ///
+    /// Returns the type of the backend (e.g. "mysql", "memfile" etc.)
+    ///
+    /// @return Type of the backend.
+    virtual std::string getType() const {
+        return (std::string("postgresql"));
+    }
+
+    /// @brief Returns name of the database.
+    ///
+    /// @return database name
+    virtual std::string getName() const;
+
+    /// @brief Returns description of the backend.
+    ///
+    /// This description may be multiline text that describes the backend.
+    ///
+    /// @return Description of the backend.
+    virtual std::string getDescription() const;
+
+    /// @brief Returns backend version.
+    ///
+    /// @return Version number as a pair of unsigned integers.  "first" is the
+    ///         major version number, "second" the minor number.
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    virtual std::pair<uint32_t, uint32_t> getVersion() const;
+
+    /// @brief Commit Transactions
+    ///
+    /// Commits all pending database operations.  On databases that don't
+    /// support transactions, this is a no-op.
+    ///
+    /// @throw DbOperationError Iif the commit failed.
+    virtual void commit();
+
+    /// @brief Rollback Transactions
+    ///
+    /// Rolls back all pending database operations.  On databases that don't
+    /// support transactions, this is a no-op.
+    ///
+    /// @throw DbOperationError If the rollback failed.
+    virtual void rollback();
+
+    /// @brief Statement Tags
+    ///
+    /// The contents of the enum are indexes into the list of compiled SQL statements
+    enum StatementIndex {
+        DELETE_LEASE4,              // Delete from lease4 by address
+        DELETE_LEASE6,              // Delete from lease6 by address
+        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_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_VERSION,                // Obtain version number
+        INSERT_LEASE4,              // Add entry to lease4 table
+        INSERT_LEASE6,              // Add entry to lease6 table
+        UPDATE_LEASE4,              // Update a Lease4 entry
+        UPDATE_LEASE6,              // Update a Lease6 entry
+        NUM_STATEMENTS              // Number of statements
+    };
+
+private:
+
+    /// @brief Prepare statements
+    ///
+    /// Creates the prepared statements for all of the SQL statements used
+    /// by the PostgreSQL backend.
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    /// @throw isc::InvalidParameter 'index' is not valid for the vector.  This
+    ///        represents an internal error within the code.
+    void prepareStatements();
+
+    /// @brief Open Database
+    ///
+    /// Opens the database using the information supplied in the parameters
+    /// passed to the constructor.
+    ///
+    /// @throw NoDatabaseName Mandatory database name not given
+    /// @throw DbOpenError Error opening the database
+    void openDatabase();
+
+    /// @brief Add Lease Common Code
+    ///
+    /// This method performs the common actions for both flavours (V4 and V6)
+    /// of the addLease method.  It binds the contents of the lease object to
+    /// the prepared statement and adds it to the database.
+    ///
+    /// @param stindex Index of statemnent being executed
+    /// @param bind MYSQL_BIND array that has been created for the type
+    ///        of lease in question.
+    ///
+    /// @return true if the lease was added, false if it was not added because
+    ///         a lease with that address already exists in the database.
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    bool addLeaseCommon(StatementIndex stindex, BindParams& params);
+
+    /// @brief Get Lease Collection Common Code
+    ///
+    /// This method performs the common actions for obtaining multiple leases
+    /// from the database.
+    ///
+    /// @param stindex Index of statement being executed
+    /// @param params PostgreSQL parameters for the query
+    /// @param exchange Exchange object to use
+    /// @param result Returned collection of Leases Note that any leases in
+    ///        the collection when this method is called are not erased: the
+    ///        new data is appended to the end.
+    /// @param single If true, only a single data item is to be retrieved.
+    ///        If more than one is present, a MultipleRecords exception will
+    ///        be thrown.
+    ///
+    /// @throw isc::dhcp::BadValue Data retrieved from the database was invalid.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    /// @throw isc::dhcp::MultipleRecords Multiple records were retrieved
+    ///        from the database where only one was expected.
+    template <typename Exchange, typename LeaseCollection>
+    void getLeaseCollection(StatementIndex stindex, BindParams& params,
+                            Exchange& exchange, LeaseCollection& result,
+                            bool single = false) const;
+
+    /// @brief Gets Lease4 Collection
+    ///
+    /// Gets a collection of Lease4 objects.  This is just an interface to
+    /// the get lease collection common code.
+    ///
+    /// @param stindex Index of statement being executed
+    /// @param params PostgreSQL parameters for the query
+    /// @param lease LeaseCollection object returned.  Note that any leases in
+    ///        the collection when this method is called are not erased: the
+    ///        new data is appended to the end.
+    ///
+    /// @throw isc::dhcp::BadValue Data retrieved from the database was invalid.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    /// @throw isc::dhcp::MultipleRecords Multiple records were retrieved
+    ///        from the database where only one was expected.
+    void getLeaseCollection(StatementIndex stindex, BindParams& params,
+                            Lease4Collection& result) const {
+        getLeaseCollection(stindex, params, exchange4_, result);
+    }
+
+    /// @brief Get Lease6 Collection
+    ///
+    /// Gets a collection of Lease6 objects.  This is just an interface to
+    /// the get lease collection common code.
+    ///
+    /// @param stindex Index of statement being executed
+    /// @param params PostgreSQL parameters for the query
+    /// @param lease LeaseCollection object returned.  Note that any existing
+    ///        data in the collection is erased first.
+    ///
+    /// @throw isc::dhcp::BadValue Data retrieved from the database was invalid.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    /// @throw isc::dhcp::MultipleRecords Multiple records were retrieved
+    ///        from the database where only one was expected.
+    void getLeaseCollection(StatementIndex stindex, BindParams& params,
+                            Lease6Collection& result) const {
+        getLeaseCollection(stindex, params, exchange6_, result);
+    }
+
+    /// @brief Checks result of the r object
+    ///
+    /// Checks status of the operation passed as first argument and throws
+    /// DbOperationError with details if it is non-success.
+    ///
+    /// @param r result of the last PostgreSQL operation
+    /// @param index will be used to print out compiled statement name
+    ///
+    /// @throw isc::dhcp::DbOperationError Detailed PostgreSQL failure
+    inline void checkStatementError(PGresult* r, StatementIndex index) const;
+
+    /// @brief Converts query parameters to format accepted by PostgreSQL
+    ///
+    /// Converts parameters stored in params into 3 vectors: out_params,
+    /// out_lengths and out_formats.
+    /// @param params input parameters
+    /// @param out_values [out] values of specified parameters
+    /// @param out_lengths [out] lengths of specified values
+    /// @param out_formats [out] specifies format (text (0) or binary (1))
+    inline void convertToQuery(const BindParams& params,
+                               std::vector<const char *>& out_values,
+                               std::vector<int>& out_lengths,
+                               std::vector<int>& out_formats) const;
+
+    /// @brief Get Lease4 Common Code
+    ///
+    /// This method performs the common actions for the various getLease4()
+    /// methods.  It acts as an interface to the getLeaseCollection() method,
+    /// but retrieveing only a single lease.
+    ///
+    /// @param stindex Index of statement being executed
+    /// @param BindParams PostgreSQL array for input parameters
+    /// @param lease Lease4 object returned
+    void getLease(StatementIndex stindex, BindParams& params,
+                  Lease4Ptr& result) const;
+
+    /// @brief Get Lease6 Common Code
+    ///
+    /// This method performs the common actions for the various getLease4()
+    /// methods.  It acts as an interface to the getLeaseCollection() method,
+    /// but retrieveing only a single lease.
+    ///
+    /// @param stindex Index of statement being executed
+    /// @param BindParams PostgreSQL array for input parameters
+    /// @param lease Lease6 object returned
+    void getLease(StatementIndex stindex, BindParams& params,
+                  Lease6Ptr& result) const;
+
+
+    /// @brief Update lease common code
+    ///
+    /// Holds the common code for updating a lease.  It binds the parameters
+    /// to the prepared statement, executes it, then checks how many rows
+    /// were affected.
+    ///
+    /// @param stindex Index of prepared statement to be executed
+    /// @param BindParams Array of PostgreSQL objects representing the parameters.
+    ///        (Note that the number is determined by the number of parameters
+    ///        in the statement.)
+    /// @param lease Pointer to the lease object whose record is being updated.
+    ///
+    /// @throw NoSuchLease Could not update a lease because no lease matches
+    ///        the address given.
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    template <typename LeasePtr>
+    void updateLeaseCommon(StatementIndex stindex, BindParams& params,
+                           const LeasePtr& lease);
+
+    /// @brief Delete lease common code
+    ///
+    /// Holds the common code for deleting a lease.  It binds the parameters
+    /// to the prepared statement, executes the statement and checks to
+    /// see how many rows were deleted.
+    ///
+    /// @param stindex Index of prepared statement to be executed
+    /// @param BindParams Array of PostgreSQL objects representing the parameters.
+    ///        (Note that the number is determined by the number of parameters
+    ///        in the statement.)
+    ///
+    /// @return true if one or more rows were deleted, false if none were
+    ///         deleted.
+    ///
+    /// @throw isc::dhcp::DbOperationError An operation on the open database has
+    ///        failed.
+    bool deleteLeaseCommon(StatementIndex stindex, BindParams& params);
+
+    /// 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,
+    /// while the rest of this object does not.  (At alternative would be to
+    /// declare them as "mutable".)
+    boost::scoped_ptr<PgSqlLease4Exchange> exchange4_; ///< Exchange object
+    boost::scoped_ptr<PgSqlLease6Exchange> exchange6_; ///< Exchange object
+
+    /// A vector of compiled SQL statements
+    std::vector<PgSqlStatementBind> statements_;
+
+    /// PostgreSQL connection handle
+    PGconn* conn_;
+};
+
+}; // end of isc::dhcp namespace
+}; // end of isc namespace
+
+#endif // PGSQL_LEASE_MGR_H

+ 11 - 1
src/lib/dhcpsrv/tests/Makefile.am

@@ -67,8 +67,12 @@ libdhcpsrv_unittests_SOURCES += dhcp_parsers_unittest.cc
 if HAVE_MYSQL
 libdhcpsrv_unittests_SOURCES += mysql_lease_mgr_unittest.cc
 endif
+if HAVE_PGSQL
+libdhcpsrv_unittests_SOURCES += pgsql_lease_mgr_unittest.cc
+endif
 libdhcpsrv_unittests_SOURCES += pool_unittest.cc
-libdhcpsrv_unittests_SOURCES += schema_copy.h
+libdhcpsrv_unittests_SOURCES += schema_mysql_copy.h
+libdhcpsrv_unittests_SOURCES += schema_pgsql_copy.h
 libdhcpsrv_unittests_SOURCES += subnet_unittest.cc
 libdhcpsrv_unittests_SOURCES += test_get_callout_handle.cc test_get_callout_handle.h
 libdhcpsrv_unittests_SOURCES += triplet_unittest.cc
@@ -78,11 +82,17 @@ libdhcpsrv_unittests_CPPFLAGS = $(AM_CPPFLAGS) $(GTEST_INCLUDES) $(LOG4CPLUS_INC
 if HAVE_MYSQL
 libdhcpsrv_unittests_CPPFLAGS += $(MYSQL_CPPFLAGS)
 endif
+if HAVE_PGSQL
+libdhcpsrv_unittests_CPPFLAGS += $(PGSQL_CPPFLAGS)
+endif
 
 libdhcpsrv_unittests_LDFLAGS  = $(AM_LDFLAGS)  $(GTEST_LDFLAGS)
 if HAVE_MYSQL
 libdhcpsrv_unittests_LDFLAGS  += $(MYSQL_LIBS)
 endif
+if HAVE_PGSQL
+libdhcpsrv_unittests_LDFLAGS  += $(PGSQL_LIBS)
+endif
 
 libdhcpsrv_unittests_CXXFLAGS = $(AM_CXXFLAGS)
 if USE_CLANGPP

+ 53 - 43
src/lib/dhcpsrv/tests/mysql_lease_mgr_unittest.cc

@@ -38,7 +38,7 @@ using namespace std;
 namespace {
 
 // This holds statements to create and destroy the schema.
-#include "schema_copy.h"
+#include "schema_mysql_copy.h"
 
 // Connection strings.
 // Database: keatest
@@ -318,6 +318,10 @@ TEST_F(MySqlLeaseMgrTest, checkVersion) {
     EXPECT_EQ(CURRENT_VERSION_MINOR, version.second);
 }
 
+////////////////////////////////////////////////////////////////////////////////
+/// LEASE4 /////////////////////////////////////////////////////////////////////
+////////////////////////////////////////////////////////////////////////////////
+
 /// @brief Basic Lease4 Checks
 ///
 /// Checks that the addLease, getLease4 (by address) and deleteLease (with an
@@ -326,42 +330,11 @@ TEST_F(MySqlLeaseMgrTest, basicLease4) {
     testBasicLease4();
 }
 
-TEST_F(MySqlLeaseMgrTest, testAddGetDelete6) {
-    testAddGetDelete6(false);
-}
-
-
-/// @brief Basic Lease4 Checks
-///
-/// Checks that the addLease, getLease4(by address), getLease4(hwaddr,subnet_id),
-/// updateLease4() and deleteLease (IPv4 address) can handle NULL client-id.
-/// (client-id is optional and may not be present)
-TEST_F(MySqlLeaseMgrTest, lease4NullClientId) {
-    testLease4NullClientId();
-}
-
-/// @brief Verify that too long hostname for Lease4 is not accepted.
-///
-/// Checks that the it is not possible to create a lease when the hostname
-/// length exceeds 255 characters.
-TEST_F(MySqlLeaseMgrTest, lease4InvalidHostname) {
-    testLease4InvalidHostname();
-}
-
-/// @brief Basic Lease6 Checks
-///
-/// Checks that the addLease, getLease6 (by address) and deleteLease (with an
-/// IPv6 address) works.
-TEST_F(MySqlLeaseMgrTest, basicLease6) {
-    testBasicLease6();
-}
-
-/// @brief Verify that too long hostname for Lease6 is not accepted.
+/// @brief Lease4 update tests
 ///
-/// Checks that the it is not possible to create a lease when the hostname
-/// length exceeds 255 characters.
-TEST_F(MySqlLeaseMgrTest, lease6InvalidHostname) {
-    testLease6InvalidHostname();
+/// Checks that we are able to update a lease in the database.
+TEST_F(MySqlLeaseMgrTest, updateLease4) {
+    testUpdateLease4();
 }
 
 /// @brief Check GetLease4 methods - access by Hardware Address
@@ -426,6 +399,49 @@ TEST_F(MySqlLeaseMgrTest, getLease4ClientIdSubnetId) {
     testGetLease4ClientIdSubnetId();
 }
 
+/// @brief Basic Lease4 Checks
+///
+/// Checks that the addLease, getLease4(by address), getLease4(hwaddr,subnet_id),
+/// updateLease4() and deleteLease (IPv4 address) can handle NULL client-id.
+/// (client-id is optional and may not be present)
+TEST_F(MySqlLeaseMgrTest, lease4NullClientId) {
+    testLease4NullClientId();
+}
+
+/// @brief Verify that too long hostname for Lease4 is not accepted.
+///
+/// Checks that the it is not possible to create a lease when the hostname
+/// length exceeds 255 characters.
+TEST_F(MySqlLeaseMgrTest, lease4InvalidHostname) {
+    testLease4InvalidHostname();
+}
+
+////////////////////////////////////////////////////////////////////////////////
+/// LEASE6 /////////////////////////////////////////////////////////////////////
+////////////////////////////////////////////////////////////////////////////////
+
+// Test checks whether simple add, get and delete operations are possible
+// on Lease6
+TEST_F(MySqlLeaseMgrTest, testAddGetDelete6) {
+    testAddGetDelete6(false);
+}
+
+/// @brief Basic Lease6 Checks
+///
+/// Checks that the addLease, getLease6 (by address) and deleteLease (with an
+/// IPv6 address) works.
+TEST_F(MySqlLeaseMgrTest, basicLease6) {
+    testBasicLease6();
+}
+
+/// @brief Verify that too long hostname for Lease6 is not accepted.
+///
+/// Checks that the it is not possible to create a lease when the hostname
+/// length exceeds 255 characters.
+TEST_F(MySqlLeaseMgrTest, lease6InvalidHostname) {
+    testLease6InvalidHostname();
+}
+
 /// @brief Check GetLease6 methods - access by DUID/IAID
 ///
 /// Adds leases to the database and checks that they can be accessed via
@@ -457,17 +473,11 @@ TEST_F(MySqlLeaseMgrTest, getLease6DuidIaidSubnetId) {
     testGetLease6DuidIaidSubnetId();
 }
 
+// Test checks that getLease6() works with different DUID sizes
 TEST_F(MySqlLeaseMgrTest, getLease6DuidIaidSubnetIdSize) {
     testGetLease6DuidIaidSubnetIdSize();
 }
 
-/// @brief Lease4 update tests
-///
-/// Checks that we are able to update a lease in the database.
-TEST_F(MySqlLeaseMgrTest, updateLease4) {
-    testUpdateLease4();
-}
-
 /// @brief Lease6 update tests
 ///
 /// Checks that we are able to update a lease in the database.

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

@@ -0,0 +1,456 @@
+// Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+//
+// Permission to use, copy, modify, and/or distribute this software for any
+// purpose with or without fee is hereby granted, provided that the above
+// copyright notice and this permission notice appear in all copies.
+//
+// THE SOFTWARE IS PROVIDED "AS IS" AND ISC DISCLAIMS ALL WARRANTIES WITH
+// REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+// AND FITNESS.  IN NO EVENT SHALL ISC BE LIABLE FOR ANY SPECIAL, DIRECT,
+// INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM
+// LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE
+// OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR
+// PERFORMANCE OF THIS SOFTWARE.
+
+#include <config.h>
+
+#include <asiolink/io_address.h>
+#include <dhcpsrv/lease_mgr_factory.h>
+#include <dhcpsrv/pgsql_lease_mgr.h>
+#include <dhcpsrv/tests/test_utils.h>
+#include <dhcpsrv/tests/generic_lease_mgr_unittest.h>
+#include <exceptions/exceptions.h>
+
+
+#include <gtest/gtest.h>
+
+#include <algorithm>
+#include <iostream>
+#include <sstream>
+#include <string>
+#include <utility>
+
+using namespace isc;
+using namespace isc::asiolink;
+using namespace isc::dhcp;
+using namespace isc::dhcp::test;
+using namespace std;
+
+namespace {
+
+// This holds statements to create and destroy the schema.
+#include "schema_pgsql_copy.h"
+
+// Connection strings.
+// Database: keatest
+// Host: localhost
+// Username: keatest
+// Password: keatest
+const char* VALID_TYPE = "type=postgresql";
+const char* INVALID_TYPE = "type=unknown";
+const char* VALID_NAME = "name=keatest";
+const char* INVALID_NAME = "name=invalidname";
+const char* VALID_HOST = "host=localhost";
+const char* INVALID_HOST = "host=invalidhost";
+const char* VALID_USER = "user=keatest";
+const char* INVALID_USER = "user=invaliduser";
+const char* VALID_PASSWORD = "password=keatest";
+const char* INVALID_PASSWORD = "password=invalid";
+
+// Given a combination of strings above, produce a connection string.
+string connectionString(const char* type, const char* name, const char* host,
+                        const char* user, const char* password) {
+    const string space = " ";
+    string result = "";
+
+    if (type != NULL) {
+        result += string(type);
+    }
+    if (name != NULL) {
+        if (! result.empty()) {
+            result += space;
+        }
+        result += string(name);
+    }
+
+    if (host != NULL) {
+        if (! result.empty()) {
+            result += space;
+        }
+        result += string(host);
+    }
+
+    if (user != NULL) {
+        if (! result.empty()) {
+            result += space;
+        }
+        result += string(user);
+    }
+
+    if (password != NULL) {
+        if (! result.empty()) {
+            result += space;
+        }
+        result += string(password);
+    }
+
+    return (result);
+}
+
+// Return valid connection string
+string
+validConnectionString() {
+    return (connectionString(VALID_TYPE, VALID_NAME, VALID_HOST,
+                             VALID_USER, VALID_PASSWORD));
+}
+
+// @brief Clear everything from the database
+//
+// There is no error checking in this code: if something fails, one of the
+// tests will (should) fall over.
+void destroySchema() {
+    // Open database
+    PGconn * conn = 0;
+    conn = PQconnectdb("host = 'localhost' user = 'keatest'"
+                       " password = 'keatest' dbname = 'keatest'");
+
+    PGresult * r;
+    // Get rid of everything in it.
+    for (int i = 0; destroy_statement[i] != NULL; ++i) {
+        r = PQexec(conn, destroy_statement[i]);
+        PQclear(r);
+    }
+
+    PQfinish(conn);
+}
+
+// @brief Create the Schema
+//
+// Creates all the tables in what is assumed to be an empty database.
+//
+// There is no error checking in this code: if it fails, one of the tests
+// will fall over.
+void createSchema() {
+    // Open database
+    PGconn * conn = 0;
+    conn = PQconnectdb("host = 'localhost' user = 'keatest'"
+                       " password = 'keatest' dbname = 'keatest'");
+
+    PGresult * r;
+    // Get rid of everything in it.
+    for (int i = 0; create_statement[i] != NULL; ++i) {
+        r = PQexec(conn, create_statement[i]);
+        PQclear(r);
+    }
+
+    PQfinish(conn);
+}
+
+/// @brief Test fixture class for testing PostgreSQL Lease Manager
+///
+/// Opens the database prior to each test and closes it afterwards.
+/// All pending transactions are deleted prior to closure.
+
+class PgSqlLeaseMgrTest : public GenericLeaseMgrTest {
+public:
+    /// @brief Constructor
+    ///
+    /// Deletes everything from the database and opens it.
+    PgSqlLeaseMgrTest() {
+
+        // Ensure schema is the correct one.
+        destroySchema();
+        createSchema();
+
+        // Connect to the database
+        try {
+            LeaseMgrFactory::create(validConnectionString());
+        } catch (...) {
+            std::cerr << "*** ERROR: unable to open database. The test\n"
+                         "*** environment is broken and must be fixed before\n"
+                         "*** the PostgreSQL tests will run correctly.\n"
+                         "*** The reason for the problem is described in the\n"
+                         "*** accompanying exception output.\n";
+            throw;
+        }
+        lmptr_ = &(LeaseMgrFactory::instance());
+    }
+
+    /// @brief Destructor
+    ///
+    /// Rolls back all pending transactions.  The deletion of lmptr_ will close
+    /// the database.  Then reopen it and delete everything created by the test.
+    virtual ~PgSqlLeaseMgrTest() {
+        lmptr_->rollback();
+        LeaseMgrFactory::destroy();
+        destroySchema();
+    }
+
+    /// @brief Reopen the database
+    ///
+    /// Closes the database and re-open it.  Anything committed should be
+    /// visible.
+    void reopen() {
+        LeaseMgrFactory::destroy();
+        LeaseMgrFactory::create(validConnectionString());
+        lmptr_ = &(LeaseMgrFactory::instance());
+    }
+
+};
+
+/// @brief Check that database can be opened
+///
+/// This test checks if the PgSqlLeaseMgr can be instantiated.  This happens
+/// only if the database can be opened.  Note that this is not part of the
+/// PgSqlLeaseMgr test fixure set.  This test checks that the database can be
+/// opened: the fixtures assume that and check basic operations.
+
+TEST(PgSqlOpenTest, OpenDatabase) {
+
+    // Schema needs to be created for the test to work.
+    destroySchema();
+    createSchema();
+
+    // Check that lease manager open the database opens correctly and tidy up.
+    //  If it fails, print the error message.
+    try {
+        LeaseMgrFactory::create(validConnectionString());
+        EXPECT_NO_THROW((void) LeaseMgrFactory::instance());
+        LeaseMgrFactory::destroy();
+    } catch (const isc::Exception& ex) {
+        FAIL() << "*** ERROR: unable to open database, reason:\n"
+               << "    " << ex.what() << "\n"
+               << "*** The test environment is broken and must be fixed\n"
+               << "*** before the PostgreSQL tests will run correctly.\n";
+    }
+    // Check that attempting to get an instance of the lease manager when
+    // none is set throws an exception.
+    EXPECT_THROW(LeaseMgrFactory::instance(), NoLeaseManager);
+
+    // Check that wrong specification of backend throws an exception.
+    // (This is really a check on LeaseMgrFactory, but is convenient to
+    // perform here.)
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        NULL, VALID_NAME, VALID_HOST, INVALID_USER, VALID_PASSWORD)),
+        InvalidParameter);
+
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        INVALID_TYPE, VALID_NAME, VALID_HOST, VALID_USER, VALID_PASSWORD)),
+        InvalidType);
+
+    // Check that invalid login data causes an exception.
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        VALID_TYPE, INVALID_NAME, VALID_HOST, VALID_USER, VALID_PASSWORD)),
+        DbOpenError);
+
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        VALID_TYPE, VALID_NAME, INVALID_HOST, VALID_USER, VALID_PASSWORD)),
+        DbOpenError);
+
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        VALID_TYPE, VALID_NAME, VALID_HOST, INVALID_USER, VALID_PASSWORD)),
+        DbOpenError);
+
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        VALID_TYPE, VALID_NAME, VALID_HOST, VALID_USER, INVALID_PASSWORD)),
+        DbOpenError);
+
+    // Check for missing parameters
+    EXPECT_THROW(LeaseMgrFactory::create(connectionString(
+        VALID_TYPE, NULL, VALID_HOST, INVALID_USER, VALID_PASSWORD)),
+        NoDatabaseName);
+
+    // Tidy up after the test
+    destroySchema();
+}
+
+/// @brief Check the getType() method
+///
+/// getType() returns a string giving the type of the backend, which should
+/// always be "postgresql".
+TEST_F(PgSqlLeaseMgrTest, getType) {
+    EXPECT_EQ(std::string("postgresql"), lmptr_->getType());
+}
+
+/// @brief Check getName() returns correct database name
+TEST_F(PgSqlLeaseMgrTest, getName) {
+    EXPECT_EQ(std::string("keatest"), lmptr_->getName());
+}
+
+/// @brief Check that getVersion() returns the expected version
+TEST_F(PgSqlLeaseMgrTest, checkVersion) {
+    // Check version
+    pair<uint32_t, uint32_t> version;
+    ASSERT_NO_THROW(version = lmptr_->getVersion());
+    EXPECT_EQ(PG_CURRENT_VERSION, version.first);
+    EXPECT_EQ(PG_CURRENT_MINOR, version.second);
+}
+
+////////////////////////////////////////////////////////////////////////////////
+/// LEASE4 /////////////////////////////////////////////////////////////////////
+////////////////////////////////////////////////////////////////////////////////
+
+/// @brief Basic Lease4 Checks
+///
+/// Checks that the addLease, getLease4 (by address) and deleteLease (with an
+/// IPv4 address) works.
+TEST_F(PgSqlLeaseMgrTest, basicLease4) {
+    testBasicLease4();
+}
+
+/// @brief Lease4 update tests
+///
+/// Checks that we are able to update a lease in the database.
+TEST_F(PgSqlLeaseMgrTest, updateLease4) {
+    testUpdateLease4();
+}
+
+/// @brief Check GetLease4 methods - access by Hardware Address
+TEST_F(PgSqlLeaseMgrTest, getLease4HWAddr1) {
+    testGetLease4HWAddr1();
+}
+
+/// @brief Check GetLease4 methods - access by Hardware Address
+TEST_F(PgSqlLeaseMgrTest, getLease4HWAddr2) {
+    testGetLease4HWAddr2();
+}
+
+// @brief Get lease4 by hardware address (2)
+//
+// Check that the system can cope with getting a hardware address of
+// any size.
+TEST_F(PgSqlLeaseMgrTest, getLease4HWAddrSize) {
+    testGetLease4HWAddrSize();
+}
+
+/// @brief Check GetLease4 methods - access by Hardware Address & Subnet ID
+///
+/// Adds leases to the database and checks that they can be accessed via
+/// a combination of hardware address and subnet ID
+TEST_F(PgSqlLeaseMgrTest, getLease4HwaddrSubnetId) {
+    testGetLease4HWAddrSubnetId();
+}
+
+// @brief Get lease4 by hardware address and subnet ID (2)
+//
+// Check that the system can cope with getting a hardware address of
+// any size.
+TEST_F(PgSqlLeaseMgrTest, getLease4HWAddrSubnetIdSize) {
+    testGetLease4HWAddrSubnetIdSize();
+}
+
+// This test was derived from memfile.
+TEST_F(PgSqlLeaseMgrTest, getLease4ClientId) {
+    testGetLease4ClientId();
+}
+
+/// @brief Check GetLease4 methods - access by Client ID
+///
+/// Adds leases to the database and checks that they can be accessed via
+/// the Client ID.
+TEST_F(PgSqlLeaseMgrTest, getLease4ClientId2) {
+    testGetLease4ClientId2();
+}
+
+// @brief Get Lease4 by client ID (2)
+//
+// Check that the system can cope with a client ID of any size.
+TEST_F(PgSqlLeaseMgrTest, getLease4ClientIdSize) {
+    testGetLease4ClientIdSize();
+}
+
+/// @brief Check GetLease4 methods - access by Client ID & Subnet ID
+///
+/// Adds leases to the database and checks that they can be accessed via
+/// a combination of client and subnet IDs.
+TEST_F(PgSqlLeaseMgrTest, getLease4ClientIdSubnetId) {
+    testGetLease4ClientIdSubnetId();
+}
+
+/// @brief Basic Lease4 Checks
+///
+/// Checks that the addLease, getLease4(by address), getLease4(hwaddr,subnet_id),
+/// updateLease4() and deleteLease (IPv4 address) can handle NULL client-id.
+/// (client-id is optional and may not be present)
+TEST_F(PgSqlLeaseMgrTest, lease4NullClientId) {
+    testLease4NullClientId();
+}
+
+/// @brief Verify that too long hostname for Lease4 is not accepted.
+///
+/// Checks that the it is not possible to create a lease when the hostname
+/// length exceeds 255 characters.
+TEST_F(PgSqlLeaseMgrTest, lease4InvalidHostname) {
+    testLease4InvalidHostname();
+}
+
+////////////////////////////////////////////////////////////////////////////////
+/// LEASE6 /////////////////////////////////////////////////////////////////////
+////////////////////////////////////////////////////////////////////////////////
+
+// Test checks whether simple add, get and delete operations are possible
+// on Lease6
+TEST_F(PgSqlLeaseMgrTest, testAddGetDelete6) {
+    testAddGetDelete6(false);
+}
+
+/// @brief Basic Lease6 Checks
+///
+/// Checks that the addLease, getLease6 (by address) and deleteLease (with an
+/// IPv6 address) works.
+TEST_F(PgSqlLeaseMgrTest, basicLease6) {
+    testBasicLease6();
+}
+
+/// @brief Verify that too long hostname for Lease6 is not accepted.
+///
+/// Checks that the it is not possible to create a lease when the hostname
+/// length exceeds 255 characters.
+TEST_F(PgSqlLeaseMgrTest, lease6InvalidHostname) {
+    testLease6InvalidHostname();
+}
+
+/// @brief Check GetLease6 methods - access by DUID/IAID
+///
+/// Adds leases to the database and checks that they can be accessed via
+/// a combination of DUID and IAID.
+TEST_F(PgSqlLeaseMgrTest, getLeases6DuidIaid) {
+    testGetLeases6DuidIaid();
+}
+
+// Check that the system can cope with a DUID of allowed size.
+TEST_F(PgSqlLeaseMgrTest, getLeases6DuidSize) {
+    testGetLeases6DuidSize();
+}
+
+/// @brief Check that getLease6 methods discriminate by lease type.
+///
+/// Adds six leases, two per lease type all with the same duid and iad but
+/// with alternating subnet_ids.
+/// It then verifies that all of getLeases6() method variants correctly
+/// discriminate between the leases based on lease type alone.
+TEST_F(PgSqlLeaseMgrTest, lease6LeaseTypeCheck) {
+    testLease6LeaseTypeCheck();
+}
+
+/// @brief Check GetLease6 methods - access by DUID/IAID/SubnetID
+///
+/// Adds leases to the database and checks that they can be accessed via
+/// a combination of DIUID and IAID.
+TEST_F(PgSqlLeaseMgrTest, getLease6DuidIaidSubnetId) {
+    testGetLease6DuidIaidSubnetId();
+}
+
+// Test checks that getLease6() works with different DUID sizes
+TEST_F(PgSqlLeaseMgrTest, getLease6DuidIaidSubnetIdSize) {
+    testGetLease6DuidIaidSubnetIdSize();
+}
+
+/// @brief Lease6 update tests
+///
+/// Checks that we are able to update a lease in the database.
+TEST_F(PgSqlLeaseMgrTest, updateLease6) {
+    testUpdateLease6();
+}
+
+};

src/lib/dhcpsrv/tests/schema_copy.h → src/lib/dhcpsrv/tests/schema_mysql_copy.h


+ 95 - 0
src/lib/dhcpsrv/tests/schema_pgsql_copy.h

@@ -0,0 +1,95 @@
+// Copyright (C) 2014 Internet Systems Consortium, Inc. ("ISC")
+//
+// Permission to use, copy, modify, and/or distribute this software for any
+// purpose with or without fee is hereby granted, provided that the above
+// copyright notice and this permission notice appear in all copies.
+//
+// THE SOFTWARE IS PROVIDED "AS IS" AND ISC DISCLAIMS ALL WARRANTIES WITH
+// REGARD TO THIS SOFTWARE INCLUDING ALL IMPLIED WARRANTIES OF MERCHANTABILITY
+// AND FITNESS.  IN NO EVENT SHALL ISC BE LIABLE FOR ANY SPECIAL, DIRECT,
+// INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING FROM
+// LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT, NEGLIGENCE
+// OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION WITH THE USE OR
+// PERFORMANCE OF THIS SOFTWARE.
+
+#ifndef SCHEMA_COPY_H
+#define SCHEMA_COPY_H
+
+namespace {
+
+// What follows is a set of statements that creates a copy of the schema
+// in the test database.  It is used by the PostgreSQL unit test prior to each
+// test.
+//
+// Each SQL statement is a single string.  The statements are not terminated
+// by semicolons, and the strings must end with a comma.  The final line
+// statement must be NULL (not in quotes)
+
+// NOTE: This file mirrors the schema in src/lib/dhcpsrv/dhcpdb_create.pgsql.
+//       If this file is altered, please ensure that any change is compatible
+//       with the schema in dhcpdb_create.pgsql.
+
+// Deletion of existing tables.
+
+const char* destroy_statement[] = {
+    "DROP TABLE lease4",
+    "DROP TABLE lease6",
+    "DROP TABLE lease6_types",
+    "DROP TABLE schema_version",
+    NULL
+};
+
+// Creation of the new tables.
+
+const char* create_statement[] = {
+    "START TRANSACTION",
+    "CREATE TABLE lease4 ("
+    "address BIGINT PRIMARY KEY NOT NULL,"
+    "hwaddr BYTEA,"
+    "client_id BYTEA,"
+    "valid_lifetime BIGINT,"
+    "expire TIMESTAMP WITH TIME ZONE,"
+    "subnet_id BIGINT,"
+    "fqdn_fwd BOOLEAN,"
+    "fqdn_rev BOOLEAN,"
+    "hostname VARCHAR(255)"
+    ")",
+
+    "CREATE TABLE lease6 ("
+    "address VARCHAR(39) PRIMARY KEY NOT NULL,"
+    "duid BYTEA,"
+    "valid_lifetime BIGINT,"
+    "expire TIMESTAMP WITH TIME ZONE,"
+    "subnet_id BIGINT,"
+    "pref_lifetime BIGINT,"
+    "lease_type SMALLINT,"
+    "iaid BIGINT,"
+    "prefix_len SMALLINT,"
+    "fqdn_fwd BOOLEAN,"
+    "fqdn_rev BOOLEAN,"
+    "hostname VARCHAR(255)"
+    ")",
+
+    "CREATE TABLE lease6_types ("
+    "lease_type SMALLINT PRIMARY KEY NOT NULL,"
+    "name VARCHAR(5)"
+    ")",
+
+    "INSERT INTO lease6_types VALUES (0, 'IA_NA')",
+    "INSERT INTO lease6_types VALUES (1, 'IA_TA')",
+    "INSERT INTO lease6_types VALUES (2, 'IA_PD')",
+
+    "CREATE TABLE schema_version ("
+        "version INT PRIMARY KEY NOT NULL,"
+        "minor INT"
+        ")",
+
+    "INSERT INTO schema_version VALUES (1, 0)",
+    "COMMIT",
+
+    NULL
+};
+
+};  // Anonymous namespace
+
+#endif // SCHEMA_COPY_H