dhcpdb_create.mysql 20 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508
  1. # Copyright (C) 2012-2016 Internet Systems Consortium.
  2. #
  3. # This Source Code Form is subject to the terms of the Mozilla Public
  4. # License, v. 2.0. If a copy of the MPL was not distributed with this
  5. # file, You can obtain one at http://mozilla.org/MPL/2.0/.
  6. # This is the Kea schema specification for MySQL.
  7. #
  8. # The schema is reasonably portable (with the exception of the engine
  9. # specification, which is MySQL-specific). Minor changes might be needed for
  10. # other databases.
  11. # To create the schema, either type the command:
  12. #
  13. # mysql -u <user> -p <password> <database> < dhcpdb_create.mysql
  14. #
  15. # ... at the command prompt, or log in to the MySQL database and at the "mysql>"
  16. # prompt, issue the command:
  17. #
  18. # source dhcpdb_create.mysql
  19. #
  20. # This script is also called from kea-admin, see kea-admin lease-init mysql
  21. #
  22. # Over time, Kea database schema will evolve. Each version is marked with
  23. # major.minor version. This file is organized sequentially, i.e. database
  24. # is initialized to 1.0, then upgraded to 2.0 etc. This may be somewhat
  25. # sub-optimal, but it ensues consistency with upgrade scripts. (It is much
  26. # easier to maintain init and upgrade scripts if they look the same).
  27. # Since initialization is done only once, it's perfromance is not an issue.
  28. # This line starts database initialization to 1.0.
  29. # Holds the IPv4 leases.
  30. CREATE TABLE lease4 (
  31. address INT UNSIGNED PRIMARY KEY NOT NULL, # IPv4 address
  32. hwaddr VARBINARY(20), # Hardware address
  33. client_id VARBINARY(128), # Client ID
  34. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  35. expire TIMESTAMP, # Expiration time of the lease
  36. subnet_id INT UNSIGNED, # Subnet identification
  37. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  38. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  39. hostname VARCHAR(255) # The FQDN of the client
  40. ) ENGINE = INNODB;
  41. # Create search indexes for lease4 table
  42. # index by hwaddr and subnet_id
  43. CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
  44. # index by client_id and subnet_id
  45. CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
  46. # Holds the IPv6 leases.
  47. # N.B. The use of a VARCHAR for the address is temporary for development:
  48. # it will eventually be replaced by BINARY(16).
  49. CREATE TABLE lease6 (
  50. address VARCHAR(39) PRIMARY KEY NOT NULL, # IPv6 address
  51. duid VARBINARY(128), # DUID
  52. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  53. expire TIMESTAMP, # Expiration time of the lease
  54. subnet_id INT UNSIGNED, # Subnet identification
  55. pref_lifetime INT UNSIGNED, # Preferred lifetime
  56. lease_type TINYINT, # Lease type (see lease6_types
  57. # table for possible values)
  58. iaid INT UNSIGNED, # See Section 10 of RFC 3315
  59. prefix_len TINYINT UNSIGNED, # For IA_PD only
  60. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  61. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  62. hostname VARCHAR(255) # The FQDN of the client
  63. ) ENGINE = INNODB;
  64. # Create search indexes for lease4 table
  65. # index by iaid, subnet_id, and duid
  66. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  67. # ... and a definition of lease6 types. This table is a convenience for
  68. # users of the database - if they want to view the lease table and use the
  69. # type names, they can join this table with the lease6 table.
  70. # Make sure those values match Lease6::LeaseType enum (see src/bin/dhcpsrv/
  71. # lease_mgr.h)
  72. CREATE TABLE lease6_types (
  73. lease_type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
  74. name VARCHAR(5) # Name of the lease type
  75. ) ENGINE = INNODB;
  76. START TRANSACTION;
  77. INSERT INTO lease6_types VALUES (0, "IA_NA"); # Non-temporary v6 addresses
  78. INSERT INTO lease6_types VALUES (1, "IA_TA"); # Temporary v6 addresses
  79. INSERT INTO lease6_types VALUES (2, "IA_PD"); # Prefix delegations
  80. COMMIT;
  81. # Finally, the version of the schema. We start at 1.0 during development.
  82. # This table is only modified during schema upgrades. For historical reasons
  83. # (related to the names of the columns in the BIND 10 DNS database file), the
  84. # first column is called "version" and not "major".
  85. CREATE TABLE schema_version (
  86. version INT PRIMARY KEY NOT NULL, # Major version number
  87. minor INT # Minor version number
  88. ) ENGINE = INNODB;
  89. START TRANSACTION;
  90. INSERT INTO schema_version VALUES (1, 0);
  91. COMMIT;
  92. # This line concludes database initalization to version 1.0.
  93. # This line starts database upgrade to version 2.0.
  94. ALTER TABLE lease6
  95. ADD COLUMN hwaddr varbinary(20), # Hardware/MAC address, typically only 6
  96. # bytes is used, but some hardware (e.g.
  97. # Infiniband) use up to 20.
  98. ADD COLUMN hwtype smallint unsigned, # hardware type (16 bits)
  99. ADD COLUMN hwaddr_source int unsigned; # Hardware source. See description
  100. # of lease_hwaddr_source below.
  101. # Kea keeps track of the hardware/MAC address source, i.e. how the address
  102. # was obtained. Depending on the technique and your network topology, it may
  103. # be more or less trustworthy. This table is a convenience for
  104. # users of the database - if they want to view the lease table and use the
  105. # type names, they can join this table with the lease6 table. For details,
  106. # see constants defined in src/lib/dhcp/dhcp/pkt.h for detailed explanation.
  107. CREATE TABLE lease_hwaddr_source (
  108. hwaddr_source INT PRIMARY KEY NOT NULL,
  109. name VARCHAR(40)
  110. ) ENGINE = INNODB;
  111. # Hardware address obtained from raw sockets
  112. INSERT INTO lease_hwaddr_source VALUES (1, "HWADDR_SOURCE_RAW");
  113. # Hardware address converted from IPv6 link-local address with EUI-64
  114. INSERT INTO lease_hwaddr_source VALUES (2, "HWADDR_SOURCE_IPV6_LINK_LOCAL");
  115. # Hardware address extracted from client-id (duid)
  116. INSERT INTO lease_hwaddr_source VALUES (4, "HWADDR_SOURCE_DUID");
  117. # Hardware address extracted from client address relay option (RFC6939)
  118. INSERT INTO lease_hwaddr_source VALUES (8, "HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION");
  119. # Hardware address extracted from remote-id option (RFC4649)
  120. INSERT INTO lease_hwaddr_source VALUES (16, "HWADDR_SOURCE_REMOTE_ID");
  121. # Hardware address extracted from subscriber-id option (RFC4580)
  122. INSERT INTO lease_hwaddr_source VALUES (32, "HWADDR_SOURCE_SUBSCRIBER_ID");
  123. # Hardware address extracted from docsis options
  124. INSERT INTO lease_hwaddr_source VALUES (64, "HWADDR_SOURCE_DOCSIS");
  125. UPDATE schema_version SET version="2", minor="0";
  126. # This line concludes database upgrade to version 2.0.
  127. # This line starts database upgrade to version 3.0.
  128. # Upgrade extending MySQL schema with the ability to store hosts.
  129. CREATE TABLE IF NOT EXISTS hosts (
  130. host_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  131. dhcp_identifier VARBINARY(128) NOT NULL,
  132. dhcp_identifier_type TINYINT NOT NULL,
  133. dhcp4_subnet_id INT UNSIGNED NULL,
  134. dhcp6_subnet_id INT UNSIGNED NULL,
  135. ipv4_address INT UNSIGNED NULL,
  136. hostname VARCHAR(255) NULL,
  137. dhcp4_client_classes VARCHAR(255) NULL,
  138. dhcp6_client_classes VARCHAR(255) NULL,
  139. PRIMARY KEY (host_id),
  140. INDEX key_dhcp4_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC),
  141. INDEX key_dhcp6_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp6_subnet_id ASC)
  142. ) ENGINE=INNODB;
  143. -- -----------------------------------------------------
  144. -- Table `ipv6_reservations`
  145. -- -----------------------------------------------------
  146. CREATE TABLE IF NOT EXISTS ipv6_reservations (
  147. reservation_id INT NOT NULL AUTO_INCREMENT,
  148. address VARCHAR(39) NOT NULL,
  149. prefix_len TINYINT(3) UNSIGNED NOT NULL DEFAULT 128,
  150. type TINYINT(4) UNSIGNED NOT NULL DEFAULT 0,
  151. dhcp6_iaid INT UNSIGNED NULL,
  152. host_id INT UNSIGNED NOT NULL,
  153. PRIMARY KEY (reservation_id),
  154. INDEX fk_ipv6_reservations_host_idx (host_id ASC),
  155. CONSTRAINT fk_ipv6_reservations_Host FOREIGN KEY (host_id)
  156. REFERENCES hosts (host_id)
  157. ON DELETE NO ACTION ON UPDATE NO ACTION
  158. ) ENGINE=INNODB;
  159. -- -----------------------------------------------------
  160. -- Table `dhcp4_options`
  161. -- -----------------------------------------------------
  162. CREATE TABLE IF NOT EXISTS dhcp4_options (
  163. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  164. code TINYINT UNSIGNED NOT NULL,
  165. value BLOB NULL,
  166. formatted_value TEXT NULL,
  167. space VARCHAR(128) NULL,
  168. persistent TINYINT(1) NOT NULL DEFAULT 0,
  169. dhcp_client_class VARCHAR(128) NULL,
  170. dhcp4_subnet_id INT NULL,
  171. host_id INT UNSIGNED NULL,
  172. PRIMARY KEY (option_id),
  173. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  174. INDEX fk_options_host1_idx (host_id ASC),
  175. CONSTRAINT fk_options_host1 FOREIGN KEY (host_id)
  176. REFERENCES hosts (host_id)
  177. ON DELETE NO ACTION ON UPDATE NO ACTION
  178. ) ENGINE=INNODB;
  179. -- -----------------------------------------------------
  180. -- Table `dhcp6_options`
  181. -- -----------------------------------------------------
  182. CREATE TABLE IF NOT EXISTS dhcp6_options (
  183. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  184. code INT UNSIGNED NOT NULL,
  185. value BLOB NULL,
  186. formatted_value TEXT NULL,
  187. space VARCHAR(128) NULL,
  188. persistent TINYINT(1) NOT NULL DEFAULT 0,
  189. dhcp_client_class VARCHAR(128) NULL,
  190. dhcp6_subnet_id INT NULL,
  191. host_id INT UNSIGNED NULL,
  192. PRIMARY KEY (option_id),
  193. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  194. INDEX fk_options_host1_idx (host_id ASC),
  195. CONSTRAINT fk_options_host10 FOREIGN KEY (host_id)
  196. REFERENCES hosts (host_id)
  197. ON DELETE NO ACTION ON UPDATE NO ACTION
  198. ) ENGINE=INNODB;
  199. DELIMITER $$
  200. CREATE TRIGGER host_BDEL BEFORE DELETE ON hosts FOR EACH ROW
  201. -- Edit trigger body code below this line. Do not edit lines above this one
  202. BEGIN
  203. DELETE FROM ipv6_reservations WHERE ipv6_reservations.host_id = OLD.host_id;
  204. END
  205. $$
  206. DELIMITER ;
  207. UPDATE schema_version
  208. SET version = '3', minor = '0';
  209. # This line concludes database upgrade to version 3.0.
  210. # This line starts database upgrade to version 4.0.
  211. # Upgrade extending MySQL schema with the state columns for lease tables.
  212. # Add state column to the lease4 table.
  213. ALTER TABLE lease4
  214. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  215. # Add state column to the lease6 table.
  216. ALTER TABLE lease6
  217. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  218. # Create indexes for querying leases in a given state and segregated
  219. # by the expiration time. One of the applications is to retrieve all
  220. # expired leases. However, these indexes can be also used to retrieve
  221. # leases in a given state regardless of the expiration time.
  222. CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
  223. CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
  224. # Create table holding mapping of the lease states to their names.
  225. # This is not used in queries from the DHCP server but rather in
  226. # direct queries from the lease database management tools.
  227. CREATE TABLE IF NOT EXISTS lease_state (
  228. state INT UNSIGNED PRIMARY KEY NOT NULL,
  229. name VARCHAR(64) NOT NULL
  230. ) ENGINE=INNODB;
  231. # Insert currently defined state names.
  232. INSERT INTO lease_state VALUES (0, "default");
  233. INSERT INTO lease_state VALUES (1, "declined");
  234. INSERT INTO lease_state VALUES (2, "expired-reclaimed");
  235. # Add a constraint that any state value added to the lease4 must
  236. # map to a value in the lease_state table.
  237. ALTER TABLE lease4
  238. ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
  239. REFERENCES lease_state (state);
  240. # Add a constraint that any state value added to the lease6 must
  241. # map to a value in the lease_state table.
  242. ALTER TABLE lease6
  243. ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
  244. REFERENCES lease_state (state);
  245. # Add a constraint that lease type in the lease6 table must map
  246. # to a lease type defined in the lease6_types table.
  247. ALTER TABLE lease6
  248. ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
  249. REFERENCES lease6_types (lease_type);
  250. # Modify the name of one of the HW address sources, and add a new one.
  251. UPDATE lease_hwaddr_source
  252. SET name = 'HWADDR_SOURCE_DOCSIS_CMTS'
  253. WHERE hwaddr_source = 64;
  254. INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
  255. # Add UNSIGNED to match with the lease6.
  256. ALTER TABLE lease_hwaddr_source
  257. MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL;
  258. # Add a constraint that non-null hwaddr_source in the lease6 table
  259. # must map to an entry in the lease_hwaddr_source.
  260. ALTER TABLE lease6
  261. ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source)
  262. REFERENCES lease_hwaddr_source (hwaddr_source);
  263. # FUNCTION that returns a result set containing the column names for lease4 dumps
  264. DROP PROCEDURE IF EXISTS lease4DumpHeader;
  265. DELIMITER $$
  266. CREATE PROCEDURE lease4DumpHeader()
  267. BEGIN
  268. SELECT 'address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state';
  269. END $$
  270. DELIMITER ;
  271. # FUNCTION that returns a result set containing the data for lease4 dumps
  272. DROP PROCEDURE IF EXISTS lease4DumpData;
  273. DELIMITER $$
  274. CREATE PROCEDURE lease4DumpData()
  275. BEGIN
  276. SELECT
  277. INET_NTOA(l.address),
  278. IFNULL(HEX(l.hwaddr), ''),
  279. IFNULL(HEX(l.client_id), ''),
  280. l.valid_lifetime,
  281. l.expire,
  282. l.subnet_id,
  283. l.fqdn_fwd,
  284. l.fqdn_rev,
  285. l.hostname,
  286. s.name
  287. FROM
  288. lease4 l
  289. LEFT OUTER JOIN lease_state s on (l.state = s.state)
  290. ORDER BY l.address;
  291. END $$
  292. DELIMITER ;
  293. # FUNCTION that returns a result set containing the column names for lease6 dumps
  294. DROP PROCEDURE IF EXISTS lease6DumpHeader;
  295. DELIMITER $$
  296. CREATE PROCEDURE lease6DumpHeader()
  297. BEGIN
  298. SELECT 'address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,hwaddr,hwtype,hwaddr_source,state';
  299. END $$
  300. DELIMITER ;
  301. # FUNCTION that returns a result set containing the data for lease6 dumps
  302. DROP PROCEDURE IF EXISTS lease6DumpData;
  303. DELIMITER $$
  304. CREATE PROCEDURE lease6DumpData()
  305. BEGIN
  306. SELECT
  307. l.address,
  308. IFNULL(HEX(l.duid), ''),
  309. l.valid_lifetime,
  310. l.expire,
  311. l.subnet_id,
  312. l.pref_lifetime,
  313. IFNULL(t.name, ''),
  314. l.iaid,
  315. l.prefix_len,
  316. l.fqdn_fwd,
  317. l.fqdn_rev,
  318. l.hostname,
  319. IFNULL(HEX(l.hwaddr), ''),
  320. IFNULL(l.hwtype, ''),
  321. IFNULL(h.name, ''),
  322. IFNULL(s.name, '')
  323. FROM lease6 l
  324. left outer join lease6_types t on (l.lease_type = t.lease_type)
  325. left outer join lease_state s on (l.state = s.state)
  326. left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source)
  327. ORDER BY l.address;
  328. END $$
  329. DELIMITER ;
  330. # Update the schema version number
  331. UPDATE schema_version
  332. SET version = '4', minor = '0';
  333. # This line concludes database upgrade to version 4.0.
  334. # In the event hardware address cannot be determined, we need to satisfy
  335. # foreign key constraint between lease6 and lease_hardware_source
  336. INSERT INTO lease_hwaddr_source VALUES (0, "HWADDR_SOURCE_UNKNOWN");
  337. # Update the schema version number
  338. UPDATE schema_version
  339. SET version = '4', minor = '1';
  340. # This line concludes database upgrade to version 4.1.
  341. # Update index used for searching DHCPv4 reservations by identifier and subnet id.
  342. # This index is now unique (to prevent duplicates) and includes DHCPv4 subnet
  343. # identifier.
  344. DROP INDEX key_dhcp4_identifier_subnet_id ON hosts;
  345. CREATE UNIQUE INDEX key_dhcp4_identifier_subnet_id ON hosts (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp4_subnet_id ASC);
  346. # Update index used for searching DHCPv6 reservations by identifier and subnet id.
  347. # This index is now unique to prevent duplicates.
  348. DROP INDEX key_dhcp6_identifier_subnet_id ON hosts;
  349. CREATE UNIQUE INDEX key_dhcp6_identifier_subnet_id ON hosts (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp6_subnet_id ASC);
  350. # Create index to search for reservations using IP address and subnet id.
  351. # This unique index guarantees that there is only one occurence of the
  352. # particular IPv4 address for a given subnet.
  353. CREATE UNIQUE INDEX key_dhcp4_ipv4_address_subnet_id ON hosts (ipv4_address ASC , dhcp4_subnet_id ASC);
  354. # Create index to search for reservations using address/prefix and prefix
  355. # length.
  356. CREATE UNIQUE INDEX key_dhcp6_address_prefix_len ON ipv6_reservations (address ASC , prefix_len ASC);
  357. # Create a table mapping host identifiers to their names. Values in this
  358. # table are used as a foreign key in hosts table to guarantee that only
  359. # identifiers present in host_identifier_type table are used in hosts
  360. # table.
  361. CREATE TABLE IF NOT EXISTS host_identifier_type (
  362. type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
  363. name VARCHAR(32) # Name of the lease type
  364. ) ENGINE = INNODB;
  365. START TRANSACTION;
  366. INSERT INTO host_identifier_type VALUES (0, "hw-address"); # Non-temporary v6 addresses
  367. INSERT INTO host_identifier_type VALUES (1, "duid"); # Temporary v6 addresses
  368. INSERT INTO host_identifier_type VALUES (2, "circuit-id"); # Prefix delegations
  369. COMMIT;
  370. # Add a constraint that any identifier type value added to the hosts
  371. # must map to a value in the host_identifier_type table.
  372. ALTER TABLE hosts
  373. ADD CONSTRAINT fk_host_identifier_type FOREIGN KEY (dhcp_identifier_type)
  374. REFERENCES host_identifier_type (type);
  375. # Store DHCPv6 option code as 16-bit unsigned integer.
  376. ALTER TABLE dhcp6_options MODIFY code SMALLINT UNSIGNED NOT NULL;
  377. # Subnet identifier is unsigned.
  378. ALTER TABLE dhcp4_options MODIFY dhcp4_subnet_id INT UNSIGNED NULL;
  379. ALTER TABLE dhcp6_options MODIFY dhcp6_subnet_id INT UNSIGNED NULL;
  380. # Scopes associate DHCP options stored in dhcp4_options and
  381. # dhcp6_options tables with hosts, subnets, classes or indicate
  382. # that they are global options.
  383. CREATE TABLE IF NOT EXISTS dhcp_option_scope (
  384. scope_id TINYINT UNSIGNED PRIMARY KEY NOT NULL,
  385. scope_name VARCHAR(32)
  386. ) ENGINE = INNODB;
  387. START TRANSACTION;
  388. INSERT INTO dhcp_option_scope VALUES (0, "global");
  389. INSERT INTO dhcp_option_scope VALUES (1, "subnet");
  390. INSERT INTO dhcp_option_scope VALUES (2, "client-class");
  391. INSERT INTO dhcp_option_scope VALUES (3, "host");
  392. COMMIT;
  393. # Add scopes into table holding DHCPv4 options
  394. ALTER TABLE dhcp4_options ADD COLUMN scope_id TINYINT UNSIGNED NOT NULL;
  395. ALTER TABLE dhcp4_options
  396. ADD CONSTRAINT fk_dhcp4_option_scope FOREIGN KEY (scope_id)
  397. REFERENCES dhcp_option_scope (scope_id);
  398. # Add scopes into table holding DHCPv6 options
  399. ALTER TABLE dhcp6_options ADD COLUMN scope_id TINYINT UNSIGNED NOT NULL;
  400. ALTER TABLE dhcp6_options
  401. ADD CONSTRAINT fk_dhcp6_option_scope FOREIGN KEY (scope_id)
  402. REFERENCES dhcp_option_scope (scope_id);
  403. # Add columns holding reservations for siaddr, sname and file fields
  404. # carried within DHCPv4 message.
  405. ALTER TABLE hosts ADD COLUMN dhcp4_next_server INT UNSIGNED NULL;
  406. ALTER TABLE hosts ADD COLUMN dhcp4_server_hostname VARCHAR(64) NULL;
  407. ALTER TABLE hosts ADD COLUMN dhcp4_boot_file_name VARCHAR(128) NULL;
  408. # Update the schema version number
  409. UPDATE schema_version
  410. SET version = '4', minor = '2';
  411. # This line concludes database upgrade to version 4.2.
  412. # Notes:
  413. #
  414. # Indexes
  415. # =======
  416. # It is likely that additional indexes will be needed. However, the
  417. # increase in lookup performance from these will come at the expense
  418. # of a decrease in performance during insert operations due to the need
  419. # to update the indexes. For this reason, the need for additional indexes
  420. # will be determined by experiment during performance tests.
  421. #
  422. # The most likely additional indexes will cover the following columns:
  423. #
  424. # hwaddr and client_id
  425. # For lease stability: if a client requests a new lease, try to find an
  426. # existing or recently expired lease for it so that it can keep using the
  427. # same IP address.
  428. #
  429. # Field Sizes
  430. # ===========
  431. # If any of the VARxxx field sizes are altered, the lengths in the MySQL
  432. # backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
  433. #
  434. # Portability
  435. # ===========
  436. # The "ENGINE = INNODB" on some tables is not portable to another database
  437. # and will need to be removed.
  438. #
  439. # Some columns contain binary data so are stored as VARBINARY instead of
  440. # VARCHAR. This may be non-portable between databases: in this case, the
  441. # definition should be changed to VARCHAR.