2
0
mirror of https://gitlab.isc.org/isc-projects/kea synced 2025-09-05 16:35:23 +00:00
Files
kea/src/lib/dhcpsrv/dhcpdb_create.mysql

121 lines
5.2 KiB
Plaintext
Raw Normal View History

2012-10-22 20:43:49 +01:00
# Copyright (C) 2012 Internet Systems Consortium.
#
# Permission to use, copy, modify, and distribute this software for any
# purpose with or without fee is hereby granted, provided that the above
# copyright notice and this permission notice appear in all copies.
#
# THE SOFTWARE IS PROVIDED "AS IS" AND INTERNET SYSTEMS CONSORTIUM
# DISCLAIMS ALL WARRANTIES WITH REGARD TO THIS SOFTWARE INCLUDING ALL
# IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS. IN NO EVENT SHALL
# INTERNET SYSTEMS CONSORTIUM BE LIABLE FOR ANY SPECIAL, DIRECT,
# INDIRECT, OR CONSEQUENTIAL DAMAGES OR ANY DAMAGES WHATSOEVER RESULTING
# FROM LOSS OF USE, DATA OR PROFITS, WHETHER IN AN ACTION OF CONTRACT,
# NEGLIGENCE OR OTHER TORTIOUS ACTION, ARISING OUT OF OR IN CONNECTION
# WITH THE USE OR PERFORMANCE OF THIS SOFTWARE.
# This is the BIND 10 DHCP schema specification for MySQL.
#
# The schema is reasonably portable (with the exception of the engine
# specification, which is MySQL-specific). Minor changes might be needed for
# other databases.
# To create the schema, either type the command:
#
# mysql -u <user> -p <password> <database> < dhcpdb_create.mysql
#
# ... at the command prompt, or log in to the MySQL database and at the "mysql>"
# prompt, issue the command:
#
# source dhcpdb_create.mysql
2012-10-22 20:43:49 +01:00
# Holds the IPv4 leases.
CREATE TABLE lease4 (
address INT UNSIGNED PRIMARY KEY NOT NULL, # IPv4 address
hwaddr VARBINARY(20), # Hardware address
client_id VARBINARY(128), # Client ID
valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
expire TIMESTAMP, # Expiration time of the lease
subnet_id INT UNSIGNED # Subnet identification
2012-10-22 20:43:49 +01:00
) ENGINE = INNODB;
# Holds the IPv6 leases.
# N.B. The use of a VARCHAR for the address is temporary for development:
# it will eventually be replaced by BINARY(16).
2012-10-22 20:43:49 +01:00
CREATE TABLE lease6 (
address VARCHAR(39) PRIMARY KEY NOT NULL, # IPv6 address
duid VARBINARY(128), # DUID
valid_lifetime INT UNSIGNED, # Length of the lease (seconds)
expire TIMESTAMP, # Expiration time of the lease
subnet_id INT UNSIGNED, # Subnet identification
pref_lifetime INT UNSIGNED, # Preferred lifetime
lease_type TINYINT, # Lease type (see lease6_types
# table for possible values)
iaid INT UNSIGNED, # See Section 10 of RFC 3315
prefix_len TINYINT UNSIGNED # For IA_PD only
2012-10-22 20:43:49 +01:00
) ENGINE = INNODB;
# ... and a definition of lease6 types. This table is a convenience for
# users of the database - if they want to view the lease table and use the
# type names, they can join this table with the lease6 table
CREATE TABLE lease6_types (
lease_type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
name VARCHAR(5) # Name of the lease type
2012-10-22 20:43:49 +01:00
);
START TRANSACTION;
2012-10-22 20:43:49 +01:00
INSERT INTO lease6_types VALUES (0, "IA_NA"); # Non-temporary v6 addresses
INSERT INTO lease6_types VALUES (1, "IA_TA"); # Temporary v6 addresses
INSERT INTO lease6_types VALUES (2, "IA_PD"); # Prefix delegations
COMMIT;
2012-10-22 20:43:49 +01:00
# Finally, the version of the schema. We start at 0.1 during development.
# This table is only modified during schema upgrades. For historical reasons
# (related to the names of the columns in the BIND 10 DNS database file), the
# first column is called "version" and not "major".
#
# NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
# which defines the schema for the unit tests. If you are updating
# the version number, the schema has changed: please ensure that
# schema_copy.h has been updated as well.
2012-10-22 20:43:49 +01:00
CREATE TABLE schema_version (
version INT PRIMARY KEY NOT NULL, # Major version number
minor INT # Minor version number
2012-10-22 20:43:49 +01:00
);
START TRANSACTION;
INSERT INTO schema_version VALUES (1, 0);
2012-10-22 20:43:49 +01:00
COMMIT;
# Notes:
#
# Indexes
# =======
2012-10-22 20:43:49 +01:00
# It is likely that additional indexes will be needed. However, the
# increase in lookup performance from these will come at the expense
# of a decrease in performance during insert operations due to the need
# to update the indexes. For this reason, the need for additional indexes
# will be determined by experiment during performance tests.
#
# The most likely additional indexes will cover the following columns:
#
# expire
# To speed up the deletion of expired leases from the database.
#
# hwaddr and client_id
# For lease stability: if a client requests a new lease, try to find an
# existing or recently expired lease for it so that it can keep using the
# same IP address.
#
# Field Sizes
# ===========
# If any of the VARxxx field sizes are altered, the lengths in the MySQL
# backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
#
# Portability
# ===========
# The "ENGINE = INNODB" on some tables is not portablea to another database
# and will need to be removed.
#
# Some columns contain binary data so are stored as VARBINARY instead of
# VARCHAR. This may be non-portable between databases: in this case, the
# definition should be changed to VARCHAR.