dhcpdb_create.pgsql 9.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250
  1. -- Copyright (C) 2012-2015 Internet Systems Consortium.
  2. -- Permission to use, copy, modify, and distribute this software for any
  3. -- purpose with or without fee is hereby granted, provided that the above
  4. -- copyright notice and this permission notice appear in all copies.
  5. -- THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
  6. -- DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
  7. -- IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
  8. -- INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
  9. -- INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
  10. -- FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
  11. -- NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
  12. -- WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
  13. -- This is the Kea DHCP schema specification for PostgreSQL.
  14. -- The schema is reasonably portable (with the exception of some field types
  15. -- specification, which are PostgreSQL-specific). Minor changes might be needed
  16. -- for other databases.
  17. -- To create the schema, either type the command:
  18. -- psql -U <user> -W <password> <database> < dhcpdb_create.pgsql
  19. -- ... at the command prompt, or log in to the PostgreSQL database and at the "postgres=#"
  20. -- prompt, issue the command:
  21. -- @dhcpdb_create.pgsql
  22. -- Holds the IPv4 leases.
  23. CREATE TABLE lease4 (
  24. address BIGINT PRIMARY KEY NOT NULL, -- IPv4 address
  25. hwaddr BYTEA, -- Hardware address
  26. client_id BYTEA, -- Client ID
  27. valid_lifetime BIGINT, -- Length of the lease (seconds)
  28. expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
  29. subnet_id BIGINT, -- Subnet identification
  30. fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
  31. fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
  32. hostname VARCHAR(255) -- The FQDN of the client
  33. );
  34. -- Create search indexes for lease4 table
  35. -- index by hwaddr and subnet_id
  36. CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
  37. -- index by client_id and subnet_id
  38. CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
  39. -- Holds the IPv6 leases.
  40. -- N.B. The use of a VARCHAR for the address is temporary for development:
  41. -- it will eventually be replaced by BINARY(16).
  42. CREATE TABLE lease6 (
  43. address VARCHAR(39) PRIMARY KEY NOT NULL, -- IPv6 address
  44. duid BYTEA, -- DUID
  45. valid_lifetime BIGINT, -- Length of the lease (seconds)
  46. expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
  47. subnet_id BIGINT, -- Subnet identification
  48. pref_lifetime BIGINT, -- Preferred lifetime
  49. lease_type SMALLINT, -- Lease type (see lease6_types
  50. -- table for possible values)
  51. iaid INT, -- See Section 10 of RFC 3315
  52. prefix_len SMALLINT, -- For IA_PD only
  53. fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
  54. fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
  55. hostname VARCHAR(255) -- The FQDN of the client
  56. );
  57. -- Create search indexes for lease4 table
  58. -- index by iaid, subnet_id, and duid
  59. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  60. -- ... and a definition of lease6 types. This table is a convenience for
  61. -- users of the database - if they want to view the lease table and use the
  62. -- type names, they can join this table with the lease6 table
  63. CREATE TABLE lease6_types (
  64. lease_type SMALLINT PRIMARY KEY NOT NULL, -- Lease type code.
  65. name VARCHAR(5) -- Name of the lease type
  66. );
  67. START TRANSACTION;
  68. INSERT INTO lease6_types VALUES (0, 'IA_NA'); -- Non-temporary v6 addresses
  69. INSERT INTO lease6_types VALUES (1, 'IA_TA'); -- Temporary v6 addresses
  70. INSERT INTO lease6_types VALUES (2, 'IA_PD'); -- Prefix delegations
  71. COMMIT;
  72. -- Finally, the version of the schema. We start at 0.1 during development.
  73. -- This table is only modified during schema upgrades. For historical reasons
  74. -- (related to the names of the columns in the BIND 10 DNS database file), the
  75. -- first column is called "version" and not "major".
  76. -- NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
  77. -- which defines the schema for the unit tests. If you are updating
  78. -- the version number, the schema has changed: please ensure that
  79. -- schema_copy.h has been updated as well.
  80. CREATE TABLE schema_version (
  81. version INT PRIMARY KEY NOT NULL, -- Major version number
  82. minor INT -- Minor version number
  83. );
  84. START TRANSACTION;
  85. INSERT INTO schema_version VALUES (1, 0);
  86. COMMIT;
  87. --
  88. -- Schema 2.0 specification starts here.
  89. --
  90. -- Add state column to the lease4 table.
  91. ALTER TABLE lease4
  92. ADD COLUMN state INT8 DEFAULT 0;
  93. -- Add state column to the lease6 table.
  94. ALTER TABLE lease6
  95. ADD COLUMN state INT8 DEFAULT 0;
  96. -- Create indexes for querying leases in a given state and segregated
  97. -- by the expiration time. One of the applications is to retrieve all
  98. -- expired leases. However, these indexes can be also used to retrieve
  99. -- leases in a given state regardless of the expiration time.
  100. CREATE INDEX lease4_by_state_expire ON lease4 (state, expire);
  101. CREATE INDEX lease6_by_state_expire ON lease6 (state, expire);
  102. -- Create table holding mapping of the lease states to their names.
  103. -- This is not used in queries from the DHCP server but rather in
  104. -- direct queries from the lease database management tools.
  105. CREATE TABLE lease_state (
  106. state INT8 PRIMARY KEY NOT NULL,
  107. name VARCHAR(64) NOT NULL);
  108. -- Insert currently defined state names.
  109. START TRANSACTION;
  110. INSERT INTO lease_state VALUES (0, 'default');
  111. INSERT INTO lease_state VALUES (1, 'declined');
  112. INSERT INTO lease_state VALUES (2, 'expired-reclaimed');
  113. COMMIT;
  114. --
  115. -- FUNCTION that returns a result set containing the column names for lease4 dumps
  116. DROP FUNCTION IF EXISTS lease4DumpHeader();
  117. CREATE FUNCTION lease4DumpHeader() RETURNS text AS $$
  118. select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname' as text) as result;
  119. $$ LANGUAGE SQL;
  120. --
  121. --
  122. -- FUNCTION that returns a result set containing the data for lease4 dumps
  123. DROP FUNCTION IF EXISTS lease4DumpData();
  124. CREATE FUNCTION lease4DumpData() RETURNS
  125. table (address inet,
  126. hwaddr text,
  127. client_id text,
  128. valid_lifetime bigint,
  129. expire timestamp with time zone,
  130. subnet_id bigint,
  131. fqdn_fwd int,
  132. fqdn_rev int,
  133. hostname text
  134. ) as $$
  135. SELECT ('0.0.0.0'::inet + address),
  136. encode(hwaddr,'hex'),
  137. encode(client_id,'hex'),
  138. valid_lifetime,
  139. expire,
  140. subnet_id,
  141. fqdn_fwd::int,
  142. fqdn_rev::int,
  143. hostname
  144. from lease4;
  145. $$ LANGUAGE SQL;
  146. --
  147. --
  148. -- FUNCTION that returns a result set containing the column names for lease6 dumps
  149. DROP FUNCTION IF EXISTS lease6DumpHeader();
  150. CREATE FUNCTION lease6DumpHeader() RETURNS text AS $$
  151. 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;
  152. $$ LANGUAGE SQL;
  153. --
  154. --
  155. -- FUNCTION that returns a result set containing the data for lease6 dumps
  156. DROP FUNCTION IF EXISTS lease6DumpData();
  157. CREATE FUNCTION lease6DumpData() RETURNS
  158. TABLE (
  159. address text,
  160. duid text,
  161. valid_lifetime bigint,
  162. expire timestamp with time zone,
  163. subnet_id bigint,
  164. pref_lifetime bigint,
  165. name text,
  166. iaid integer,
  167. prefix_len smallint,
  168. fqdn_fwd int,
  169. fqdn_rev int,
  170. hostname text
  171. ) AS $$
  172. SELECT (l.address,
  173. encode(l.duid,'hex'),
  174. l.valid_lifetime,
  175. l.expire,
  176. l.subnet_id,
  177. l.pref_lifetime,
  178. t.name,
  179. l.iaid,
  180. l.prefix_len,
  181. l.fqdn_fwd::int,
  182. l.fqdn_rev::int,
  183. l.hostname)
  184. FROM lease6 l left outer join lease6_types t on (l.lease_type = t.lease_type);
  185. $$ LANGUAGE SQL;
  186. --
  187. -- Set 2.0 schema version.
  188. START TRANSACTION;
  189. UPDATE schema_version
  190. SET version = '2', minor = '0';
  191. COMMIT;
  192. -- Schema 2.0 specification ends here.
  193. -- Notes:
  194. -- Indexes
  195. -- =======
  196. -- It is likely that additional indexes will be needed. However, the
  197. -- increase in lookup performance from these will come at the expense
  198. -- of a decrease in performance during insert operations due to the need
  199. -- to update the indexes. For this reason, the need for additional indexes
  200. -- will be determined by experiment during performance tests.
  201. -- The most likely additional indexes will cover the following columns:
  202. -- hwaddr and client_id
  203. -- For lease stability: if a client requests a new lease, try to find an
  204. -- existing or recently expired lease for it so that it can keep using the
  205. -- same IP address.
  206. -- Field Sizes
  207. -- ===========
  208. -- If any of the VARxxx field sizes are altered, the lengths in the PgSQL
  209. -- backend source file (pgsql_lease_mgr.cc) must be correspondingly changed.
  210. -- Portability
  211. -- ===========
  212. -- Some columns contain binary data so are stored as BYTEA instead of
  213. -- VARCHAR. This may be non-portable between databases: in this case, the
  214. -- definition should be changed to VARCHAR.