dhcpdb_create.mysql 6.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141
  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 BIND 10 DHCP 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. # Holds the IPv4 leases.
  29. CREATE TABLE lease4 (
  30. address INT UNSIGNED PRIMARY KEY NOT NULL, # IPv4 address
  31. hwaddr VARBINARY(20), # Hardware address
  32. client_id VARBINARY(128), # Client ID
  33. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  34. expire TIMESTAMP, # Expiration time of the lease
  35. subnet_id INT UNSIGNED, # Subnet identification
  36. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  37. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  38. hostname VARCHAR(255) # The FQDN of the client
  39. ) ENGINE = INNODB;
  40. # Create search indexes for lease4 table
  41. # index by hwaddr and subnet_id
  42. CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
  43. # index by client_id and subnet_id
  44. CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
  45. # Holds the IPv6 leases.
  46. # N.B. The use of a VARCHAR for the address is temporary for development:
  47. # it will eventually be replaced by BINARY(16).
  48. CREATE TABLE lease6 (
  49. address VARCHAR(39) PRIMARY KEY NOT NULL, # IPv6 address
  50. duid VARBINARY(128), # DUID
  51. valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
  52. expire TIMESTAMP, # Expiration time of the lease
  53. subnet_id INT UNSIGNED, # Subnet identification
  54. pref_lifetime INT UNSIGNED, # Preferred lifetime
  55. lease_type TINYINT, # Lease type (see lease6_types
  56. # table for possible values)
  57. iaid INT UNSIGNED, # See Section 10 of RFC 3315
  58. prefix_len TINYINT UNSIGNED, # For IA_PD only
  59. fqdn_fwd BOOL, # Has forward DNS update been performed by a server
  60. fqdn_rev BOOL, # Has reverse DNS update been performed by a server
  61. hostname VARCHAR(255) # The FQDN of the client
  62. ) ENGINE = INNODB;
  63. # Create search indexes for lease4 table
  64. # index by iaid, subnet_id, and duid
  65. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  66. # ... and a definition of lease6 types. This table is a convenience for
  67. # users of the database - if they want to view the lease table and use the
  68. # type names, they can join this table with the lease6 table.
  69. # Make sure those values match Lease6::LeaseType enum (see src/bin/dhcpsrv/
  70. # lease_mgr.h)
  71. CREATE TABLE lease6_types (
  72. lease_type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
  73. name VARCHAR(5) # Name of the lease type
  74. );
  75. START TRANSACTION;
  76. INSERT INTO lease6_types VALUES (0, "IA_NA"); # Non-temporary v6 addresses
  77. INSERT INTO lease6_types VALUES (1, "IA_TA"); # Temporary v6 addresses
  78. INSERT INTO lease6_types VALUES (2, "IA_PD"); # Prefix delegations
  79. COMMIT;
  80. # Finally, the version of the schema. We start at 0.1 during development.
  81. # This table is only modified during schema upgrades. For historical reasons
  82. # (related to the names of the columns in the BIND 10 DNS database file), the
  83. # first column is called "version" and not "major".
  84. #
  85. # NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
  86. # which defines the schema for the unit tests. If you are updating
  87. # the version number, the schema has changed: please ensure that
  88. # schema_copy.h has been updated as well.
  89. CREATE TABLE schema_version (
  90. version INT PRIMARY KEY NOT NULL, # Major version number
  91. minor INT # Minor version number
  92. );
  93. START TRANSACTION;
  94. INSERT INTO schema_version VALUES (1, 0);
  95. COMMIT;
  96. # Notes:
  97. #
  98. # Indexes
  99. # =======
  100. # It is likely that additional indexes will be needed. However, the
  101. # increase in lookup performance from these will come at the expense
  102. # of a decrease in performance during insert operations due to the need
  103. # to update the indexes. For this reason, the need for additional indexes
  104. # will be determined by experiment during performance tests.
  105. #
  106. # The most likely additional indexes will cover the following columns:
  107. #
  108. # expire
  109. # To speed up the deletion of expired leases from the database.
  110. #
  111. # hwaddr and client_id
  112. # For lease stability: if a client requests a new lease, try to find an
  113. # existing or recently expired lease for it so that it can keep using the
  114. # same IP address.
  115. #
  116. # Field Sizes
  117. # ===========
  118. # If any of the VARxxx field sizes are altered, the lengths in the MySQL
  119. # backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
  120. #
  121. # Portability
  122. # ===========
  123. # The "ENGINE = INNODB" on some tables is not portablea to another database
  124. # and will need to be removed.
  125. #
  126. # Some columns contain binary data so are stored as VARBINARY instead of
  127. # VARCHAR. This may be non-portable between databases: in this case, the
  128. # definition should be changed to VARCHAR.