dhcpdb_create.pgsql 8.4 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212
  1. -- Copyright (C) 2012-2013 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 BIND 10 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. --
  40. -- FUNCTION that returns a result set containing the column names for lease4 dumps
  41. DROP FUNCTION IF EXISTS lease4DumpHeader();
  42. CREATE FUNCTION lease4DumpHeader() RETURNS text AS $$
  43. select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname' as text) as result;
  44. $$ LANGUAGE SQL;
  45. --
  46. --
  47. -- FUNCTION that returns a result set containing the data for lease4 dumps
  48. DROP FUNCTION IF EXISTS lease4DumpData();
  49. CREATE FUNCTION lease4DumpData() RETURNS
  50. table (address inet,
  51. hwaddr text,
  52. client_id text,
  53. valid_lifetime bigint,
  54. expire timestamp with time zone,
  55. subnet_id bigint,
  56. fqdn_fwd int,
  57. fqdn_rev int,
  58. hostname text
  59. ) as $$
  60. SELECT ('0.0.0.0'::inet + address),
  61. encode(hwaddr,'hex'),
  62. encode(client_id,'hex'),
  63. valid_lifetime,
  64. expire,
  65. subnet_id,
  66. fqdn_fwd::int,
  67. fqdn_rev::int,
  68. hostname
  69. from lease4;
  70. $$ LANGUAGE SQL;
  71. --
  72. -- Holds the IPv6 leases.
  73. -- N.B. The use of a VARCHAR for the address is temporary for development:
  74. -- it will eventually be replaced by BINARY(16).
  75. CREATE TABLE lease6 (
  76. address VARCHAR(39) PRIMARY KEY NOT NULL, -- IPv6 address
  77. duid BYTEA, -- DUID
  78. valid_lifetime BIGINT, -- Length of the lease (seconds)
  79. expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
  80. subnet_id BIGINT, -- Subnet identification
  81. pref_lifetime BIGINT, -- Preferred lifetime
  82. lease_type SMALLINT, -- Lease type (see lease6_types
  83. -- table for possible values)
  84. iaid INT, -- See Section 10 of RFC 3315
  85. prefix_len SMALLINT, -- For IA_PD only
  86. fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
  87. fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
  88. hostname VARCHAR(255) -- The FQDN of the client
  89. );
  90. -- Create search indexes for lease4 table
  91. -- index by iaid, subnet_id, and duid
  92. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  93. -- ... and a definition of lease6 types. This table is a convenience for
  94. -- users of the database - if they want to view the lease table and use the
  95. -- type names, they can join this table with the lease6 table
  96. CREATE TABLE lease6_types (
  97. lease_type SMALLINT PRIMARY KEY NOT NULL, -- Lease type code.
  98. name VARCHAR(5) -- Name of the lease type
  99. );
  100. START TRANSACTION;
  101. INSERT INTO lease6_types VALUES (0, 'IA_NA'); -- Non-temporary v6 addresses
  102. INSERT INTO lease6_types VALUES (1, 'IA_TA'); -- Temporary v6 addresses
  103. INSERT INTO lease6_types VALUES (2, 'IA_PD'); -- Prefix delegations
  104. COMMIT;
  105. -- Finally, the version of the schema. We start at 0.1 during development.
  106. -- This table is only modified during schema upgrades. For historical reasons
  107. -- (related to the names of the columns in the BIND 10 DNS database file), the
  108. -- first column is called "version" and not "major".
  109. -- NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
  110. -- which defines the schema for the unit tests. If you are updating
  111. -- the version number, the schema has changed: please ensure that
  112. -- schema_copy.h has been updated as well.
  113. CREATE TABLE schema_version (
  114. version INT PRIMARY KEY NOT NULL, -- Major version number
  115. minor INT -- Minor version number
  116. );
  117. START TRANSACTION;
  118. INSERT INTO schema_version VALUES (1, 0);
  119. COMMIT;
  120. --
  121. -- FUNCTION that returns a result set containing the column names for lease6 dumps
  122. DROP FUNCTION IF EXISTS lease6DumpHeader();
  123. CREATE FUNCTION lease6DumpHeader() RETURNS text AS $$
  124. 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;
  125. $$ LANGUAGE SQL;
  126. --
  127. --
  128. -- FUNCTION that returns a result set containing the data for lease6 dumps
  129. DROP FUNCTION IF EXISTS lease6DumpData();
  130. CREATE FUNCTION lease6DumpData() RETURNS
  131. TABLE (
  132. address text,
  133. duid text,
  134. valid_lifetime bigint,
  135. expire timestamp with time zone,
  136. subnet_id bigint,
  137. pref_lifetime bigint,
  138. name text,
  139. iaid integer,
  140. prefix_len smallint,
  141. fqdn_fwd int,
  142. fqdn_rev int,
  143. hostname text
  144. ) AS $$
  145. SELECT (a.address,
  146. encode(a.duid,'hex'),
  147. a.valid_lifetime,
  148. a.expire,
  149. a.subnet_id,
  150. a.pref_lifetime,
  151. b.name,
  152. a.iaid,
  153. a.prefix_len,
  154. a.fqdn_fwd::int,
  155. a.fqdn_rev::int,
  156. a.hostname)
  157. FROM lease6 a left outer join lease6_types b on (a.lease_type = b.lease_type);
  158. $$ LANGUAGE SQL;
  159. --
  160. -- Notes:
  161. -- Indexes
  162. -- =======
  163. -- It is likely that additional indexes will be needed. However, the
  164. -- increase in lookup performance from these will come at the expense
  165. -- of a decrease in performance during insert operations due to the need
  166. -- to update the indexes. For this reason, the need for additional indexes
  167. -- will be determined by experiment during performance tests.
  168. -- The most likely additional indexes will cover the following columns:
  169. -- expire
  170. -- To speed up the deletion of expired leases from the database.
  171. -- hwaddr and client_id
  172. -- For lease stability: if a client requests a new lease, try to find an
  173. -- existing or recently expired lease for it so that it can keep using the
  174. -- same IP address.
  175. -- Field Sizes
  176. -- ===========
  177. -- If any of the VARxxx field sizes are altered, the lengths in the MySQL
  178. -- backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
  179. -- Portability
  180. -- ===========
  181. -- Some columns contain binary data so are stored as BYTEA instead of
  182. -- VARCHAR. This may be non-portable between databases: in this case, the
  183. -- definition should be changed to VARCHAR.