dhcpdb_create.mysql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285
  1. # Copyright (C) 2012-2013 Internet Systems Consortium.
  2. #
  3. # Permission to use, copy, modify, and distribute this software for any
  4. # purpose with or without fee is hereby granted, provided that the above
  5. # copyright notice and this permission notice appear in all copies.
  6. #
  7. # THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
  8. # DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
  9. # IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
  10. # INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
  11. # INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
  12. # FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
  13. # NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
  14. # WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
  15. # This is the Kea schema specification for MySQL.
  16. #
  17. # The schema is reasonably portable (with the exception of the engine
  18. # specification, which is MySQL-specific). Minor changes might be needed for
  19. # other databases.
  20. # To create the schema, either type the command:
  21. #
  22. # mysql -u <user> -p <password> <database> < dhcpdb_create.mysql
  23. #
  24. # ... at the command prompt, or log in to the MySQL database and at the "mysql>"
  25. # prompt, issue the command:
  26. #
  27. # source dhcpdb_create.mysql
  28. #
  29. # This script is also called from kea-admin, see kea-admin init mysql
  30. #
  31. # Over time, Kea database schema will evolve. Each version is marked with
  32. # major.minor version. This file is organized sequentially, i.e. database
  33. # is initialized to 1.0, then upgraded to 2.0 etc. This may be somewhat
  34. # sub-optimal, but it ensues consistency with upgrade scripts. (It is much
  35. # easier to maintain init and upgrade scripts if they look the same).
  36. # Since initialization is done only once, it's perfromance is not an issue.
  37. # This line starts database initialization to 1.0.
  38. # Holds the IPv4 leases.
  39. CREATE TABLE lease4 (
  40. address INT UNSIGNED PRIMARY KEY NOT NULL, # IPv4 address
  41. hwaddr VARBINARY(20), # Hardware address
  42. client_id VARBINARY(128), # Client ID
  43. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  44. expire TIMESTAMP, # Expiration time of the lease
  45. subnet_id INT UNSIGNED, # Subnet identification
  46. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  47. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  48. hostname VARCHAR(255) # The FQDN of the client
  49. ) ENGINE = INNODB;
  50. # Create search indexes for lease4 table
  51. # index by hwaddr and subnet_id
  52. CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
  53. # index by client_id and subnet_id
  54. CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
  55. # Holds the IPv6 leases.
  56. # N.B. The use of a VARCHAR for the address is temporary for development:
  57. # it will eventually be replaced by BINARY(16).
  58. CREATE TABLE lease6 (
  59. address VARCHAR(39) PRIMARY KEY NOT NULL, # IPv6 address
  60. duid VARBINARY(128), # DUID
  61. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  62. expire TIMESTAMP, # Expiration time of the lease
  63. subnet_id INT UNSIGNED, # Subnet identification
  64. pref_lifetime INT UNSIGNED, # Preferred lifetime
  65. lease_type TINYINT, # Lease type (see lease6_types
  66. # table for possible values)
  67. iaid INT UNSIGNED, # See Section 10 of RFC 3315
  68. prefix_len TINYINT UNSIGNED, # For IA_PD only
  69. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  70. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  71. hostname VARCHAR(255) # The FQDN of the client
  72. ) ENGINE = INNODB;
  73. # Create search indexes for lease4 table
  74. # index by iaid, subnet_id, and duid
  75. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  76. # ... and a definition of lease6 types. This table is a convenience for
  77. # users of the database - if they want to view the lease table and use the
  78. # type names, they can join this table with the lease6 table.
  79. # Make sure those values match Lease6::LeaseType enum (see src/bin/dhcpsrv/
  80. # lease_mgr.h)
  81. CREATE TABLE lease6_types (
  82. lease_type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
  83. name VARCHAR(5) # Name of the lease type
  84. );
  85. START TRANSACTION;
  86. INSERT INTO lease6_types VALUES (0, "IA_NA"); # Non-temporary v6 addresses
  87. INSERT INTO lease6_types VALUES (1, "IA_TA"); # Temporary v6 addresses
  88. INSERT INTO lease6_types VALUES (2, "IA_PD"); # Prefix delegations
  89. COMMIT;
  90. # Finally, the version of the schema. We start at 1.0 during development.
  91. # This table is only modified during schema upgrades. For historical reasons
  92. # (related to the names of the columns in the BIND 10 DNS database file), the
  93. # first column is called "version" and not "major".
  94. #
  95. # NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
  96. # which defines the schema for the unit tests. If you are updating
  97. # the version number, the schema has changed: please ensure that
  98. # schema_copy.h has been updated as well.
  99. CREATE TABLE schema_version (
  100. version INT PRIMARY KEY NOT NULL, # Major version number
  101. minor INT # Minor version number
  102. );
  103. START TRANSACTION;
  104. INSERT INTO schema_version VALUES (1, 0);
  105. COMMIT;
  106. # This line concludes database initalization to version 1.0.
  107. # This line starts database upgrade to version 2.0.
  108. ALTER TABLE lease6
  109. ADD COLUMN hwaddr varbinary(20), # Hardware/MAC address, typically only 6
  110. # bytes is used, but some hardware (e.g.
  111. # Infiniband) use up to 20.
  112. ADD COLUMN hwtype smallint unsigned, # hardware type (16 bits)
  113. ADD COLUMN hwaddr_source int unsigned; # Hardware source. See description
  114. # of lease_hwaddr_source below.
  115. # Kea keeps track of the hardware/MAC address source, i.e. how the address
  116. # was obtained. Depending on the technique and your network topology, it may
  117. # be more or less trustworthy. This table is a convenience for
  118. # users of the database - if they want to view the lease table and use the
  119. # type names, they can join this table with the lease6 table. For details,
  120. # see constants defined in src/lib/dhcp/dhcp/pkt.h for detailed explanation.
  121. CREATE TABLE lease_hwaddr_source (
  122. hwaddr_source INT PRIMARY KEY NOT NULL,
  123. name VARCHAR(40)
  124. );
  125. # Hardware address obtained from raw sockets
  126. INSERT INTO lease_hwaddr_source VALUES (1, "HWADDR_SOURCE_RAW");
  127. # Hardware address converted from IPv6 link-local address with EUI-64
  128. INSERT INTO lease_hwaddr_source VALUES (2, "HWADDR_SOURCE_IPV6_LINK_LOCAL");
  129. # Hardware address extracted from client-id (duid)
  130. INSERT INTO lease_hwaddr_source VALUES (4, "HWADDR_SOURCE_DUID");
  131. # Hardware address extracted from client address relay option (RFC6939)
  132. INSERT INTO lease_hwaddr_source VALUES (8, "HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION");
  133. # Hardware address extracted from remote-id option (RFC4649)
  134. INSERT INTO lease_hwaddr_source VALUES (16, "HWADDR_SOURCE_REMOTE_ID");
  135. # Hardware address extracted from subscriber-id option (RFC4580)
  136. INSERT INTO lease_hwaddr_source VALUES (32, "HWADDR_SOURCE_SUBSCRIBER_ID");
  137. # Hardware address extracted from docsis options
  138. INSERT INTO lease_hwaddr_source VALUES (64, "HWADDR_SOURCE_DOCSIS");
  139. UPDATE schema_version SET version="2", minor="0";
  140. # This line concludes database upgrade to version 2.0.
  141. # This line starts database upgrade to version 3.0.
  142. # Upgrade extending MySQL schema with the ability to store hosts.
  143. CREATE TABLE IF NOT EXISTS hosts (
  144. host_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  145. dhcp_identifier VARBINARY(128) NOT NULL,
  146. dhcp_identifier_type TINYINT NOT NULL,
  147. dhcp4_subnet_id INT UNSIGNED NULL,
  148. dhcp6_subnet_id INT UNSIGNED NULL,
  149. ipv4_address INT UNSIGNED NULL,
  150. hostname VARCHAR(255) NULL,
  151. dhcp4_client_classes VARCHAR(255) NULL,
  152. dhcp6_client_classes VARCHAR(255) NULL,
  153. PRIMARY KEY (host_id),
  154. INDEX key_dhcp4_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC),
  155. INDEX key_dhcp6_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp6_subnet_id ASC)
  156. ) ENGINE=INNODB;
  157. -- -----------------------------------------------------
  158. -- Table `ipv6_reservations`
  159. -- -----------------------------------------------------
  160. CREATE TABLE IF NOT EXISTS ipv6_reservations (
  161. reservation_id INT NOT NULL AUTO_INCREMENT,
  162. address VARCHAR(39) NOT NULL,
  163. prefix_len TINYINT(3) UNSIGNED NOT NULL DEFAULT 128,
  164. type TINYINT(4) UNSIGNED NOT NULL DEFAULT 0,
  165. dhcp6_iaid INT UNSIGNED NULL,
  166. host_id INT UNSIGNED NOT NULL,
  167. PRIMARY KEY (reservation_id),
  168. INDEX fk_ipv6_reservations_host_idx (host_id ASC),
  169. CONSTRAINT fk_ipv6_reservations_Host FOREIGN KEY (host_id)
  170. REFERENCES hosts (host_id)
  171. ON DELETE NO ACTION ON UPDATE NO ACTION
  172. ) ENGINE=INNODB;
  173. -- -----------------------------------------------------
  174. -- Table `dhcp4_options`
  175. -- -----------------------------------------------------
  176. CREATE TABLE IF NOT EXISTS dhcp4_options (
  177. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  178. code TINYINT UNSIGNED NOT NULL,
  179. value BLOB NULL,
  180. formatted_value TEXT NULL,
  181. space VARCHAR(128) NULL,
  182. persistent TINYINT(1) NOT NULL DEFAULT 0,
  183. dhcp_client_class VARCHAR(128) NULL,
  184. dhcp4_subnet_id INT NULL,
  185. host_id INT UNSIGNED NULL,
  186. PRIMARY KEY (option_id),
  187. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  188. INDEX fk_options_host1_idx (host_id ASC),
  189. CONSTRAINT fk_options_host1 FOREIGN KEY (host_id)
  190. REFERENCES hosts (host_id)
  191. ON DELETE NO ACTION ON UPDATE NO ACTION
  192. ) ENGINE=INNODB;
  193. -- -----------------------------------------------------
  194. -- Table `dhcp6_options`
  195. -- -----------------------------------------------------
  196. CREATE TABLE IF NOT EXISTS dhcp6_options (
  197. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  198. code INT UNSIGNED NOT NULL,
  199. value BLOB NULL,
  200. formatted_value TEXT NULL,
  201. space VARCHAR(128) NULL,
  202. persistent TINYINT(1) NOT NULL DEFAULT 0,
  203. dhcp_client_class VARCHAR(128) NULL,
  204. dhcp6_subnet_id INT NULL,
  205. host_id INT UNSIGNED NULL,
  206. PRIMARY KEY (option_id),
  207. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  208. INDEX fk_options_host1_idx (host_id ASC),
  209. CONSTRAINT fk_options_host10 FOREIGN KEY (host_id)
  210. REFERENCES hosts (host_id)
  211. ON DELETE NO ACTION ON UPDATE NO ACTION
  212. ) ENGINE=INNODB;
  213. DELIMITER $$
  214. CREATE TRIGGER host_BDEL BEFORE DELETE ON hosts FOR EACH ROW
  215. -- Edit trigger body code below this line. Do not edit lines above this one
  216. BEGIN
  217. DELETE FROM ipv6_reservations WHERE ipv6_reservations.host_id = OLD.host_id;
  218. END
  219. $$
  220. DELIMITER ;
  221. UPDATE schema_version
  222. SET version = '3', minor = '0';
  223. # This line concludes database upgrade to version 3.0.
  224. # Notes:
  225. #
  226. # Indexes
  227. # =======
  228. # It is likely that additional indexes will be needed. However, the
  229. # increase in lookup performance from these will come at the expense
  230. # of a decrease in performance during insert operations due to the need
  231. # to update the indexes. For this reason, the need for additional indexes
  232. # will be determined by experiment during performance tests.
  233. #
  234. # The most likely additional indexes will cover the following columns:
  235. #
  236. # expire
  237. # To speed up the deletion of expired leases from the database.
  238. #
  239. # hwaddr and client_id
  240. # For lease stability: if a client requests a new lease, try to find an
  241. # existing or recently expired lease for it so that it can keep using the
  242. # same IP address.
  243. #
  244. # Field Sizes
  245. # ===========
  246. # If any of the VARxxx field sizes are altered, the lengths in the MySQL
  247. # backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
  248. #
  249. # Portability
  250. # ===========
  251. # The "ENGINE = INNODB" on some tables is not portable to another database
  252. # and will need to be removed.
  253. #
  254. # Some columns contain binary data so are stored as VARBINARY instead of
  255. # VARCHAR. This may be non-portable between databases: in this case, the
  256. # definition should be changed to VARCHAR.