dhcpdb_create.pgsql 10 KB

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