dhcpdb_create.mysql 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480
  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 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. #
  86. # NOTE: this MUST be kept in step with src/lib/dhcpsrv/tests/schema_copy.h,
  87. # which defines the schema for the unit tests. If you are updating
  88. # the version number, the schema has changed: please ensure that
  89. # schema_copy.h has been updated as well.
  90. CREATE TABLE schema_version (
  91. version INT PRIMARY KEY NOT NULL, # Major version number
  92. minor INT # Minor version number
  93. ) ENGINE = INNODB;
  94. START TRANSACTION;
  95. INSERT INTO schema_version VALUES (1, 0);
  96. COMMIT;
  97. # This line concludes database initalization to version 1.0.
  98. # This line starts database upgrade to version 2.0.
  99. ALTER TABLE lease6
  100. ADD COLUMN hwaddr varbinary(20), # Hardware/MAC address, typically only 6
  101. # bytes is used, but some hardware (e.g.
  102. # Infiniband) use up to 20.
  103. ADD COLUMN hwtype smallint unsigned, # hardware type (16 bits)
  104. ADD COLUMN hwaddr_source int unsigned; # Hardware source. See description
  105. # of lease_hwaddr_source below.
  106. # Kea keeps track of the hardware/MAC address source, i.e. how the address
  107. # was obtained. Depending on the technique and your network topology, it may
  108. # be more or less trustworthy. This table is a convenience for
  109. # users of the database - if they want to view the lease table and use the
  110. # type names, they can join this table with the lease6 table. For details,
  111. # see constants defined in src/lib/dhcp/dhcp/pkt.h for detailed explanation.
  112. CREATE TABLE lease_hwaddr_source (
  113. hwaddr_source INT PRIMARY KEY NOT NULL,
  114. name VARCHAR(40)
  115. ) ENGINE = INNODB;
  116. # Hardware address obtained from raw sockets
  117. INSERT INTO lease_hwaddr_source VALUES (1, "HWADDR_SOURCE_RAW");
  118. # Hardware address converted from IPv6 link-local address with EUI-64
  119. INSERT INTO lease_hwaddr_source VALUES (2, "HWADDR_SOURCE_IPV6_LINK_LOCAL");
  120. # Hardware address extracted from client-id (duid)
  121. INSERT INTO lease_hwaddr_source VALUES (4, "HWADDR_SOURCE_DUID");
  122. # Hardware address extracted from client address relay option (RFC6939)
  123. INSERT INTO lease_hwaddr_source VALUES (8, "HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION");
  124. # Hardware address extracted from remote-id option (RFC4649)
  125. INSERT INTO lease_hwaddr_source VALUES (16, "HWADDR_SOURCE_REMOTE_ID");
  126. # Hardware address extracted from subscriber-id option (RFC4580)
  127. INSERT INTO lease_hwaddr_source VALUES (32, "HWADDR_SOURCE_SUBSCRIBER_ID");
  128. # Hardware address extracted from docsis options
  129. INSERT INTO lease_hwaddr_source VALUES (64, "HWADDR_SOURCE_DOCSIS");
  130. UPDATE schema_version SET version="2", minor="0";
  131. # This line concludes database upgrade to version 2.0.
  132. # This line starts database upgrade to version 3.0.
  133. # Upgrade extending MySQL schema with the ability to store hosts.
  134. CREATE TABLE IF NOT EXISTS hosts (
  135. host_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  136. dhcp_identifier VARBINARY(128) NOT NULL,
  137. dhcp_identifier_type TINYINT NOT NULL,
  138. dhcp4_subnet_id INT UNSIGNED NULL,
  139. dhcp6_subnet_id INT UNSIGNED NULL,
  140. ipv4_address INT UNSIGNED NULL,
  141. hostname VARCHAR(255) NULL,
  142. dhcp4_client_classes VARCHAR(255) NULL,
  143. dhcp6_client_classes VARCHAR(255) NULL,
  144. PRIMARY KEY (host_id),
  145. INDEX key_dhcp4_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC),
  146. INDEX key_dhcp6_identifier_subnet_id (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp6_subnet_id ASC)
  147. ) ENGINE=INNODB;
  148. -- -----------------------------------------------------
  149. -- Table `ipv6_reservations`
  150. -- -----------------------------------------------------
  151. CREATE TABLE IF NOT EXISTS ipv6_reservations (
  152. reservation_id INT NOT NULL AUTO_INCREMENT,
  153. address VARCHAR(39) NOT NULL,
  154. prefix_len TINYINT(3) UNSIGNED NOT NULL DEFAULT 128,
  155. type TINYINT(4) UNSIGNED NOT NULL DEFAULT 0,
  156. dhcp6_iaid INT UNSIGNED NULL,
  157. host_id INT UNSIGNED NOT NULL,
  158. PRIMARY KEY (reservation_id),
  159. INDEX fk_ipv6_reservations_host_idx (host_id ASC),
  160. CONSTRAINT fk_ipv6_reservations_Host FOREIGN KEY (host_id)
  161. REFERENCES hosts (host_id)
  162. ON DELETE NO ACTION ON UPDATE NO ACTION
  163. ) ENGINE=INNODB;
  164. -- -----------------------------------------------------
  165. -- Table `dhcp4_options`
  166. -- -----------------------------------------------------
  167. CREATE TABLE IF NOT EXISTS dhcp4_options (
  168. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  169. code TINYINT UNSIGNED NOT NULL,
  170. value BLOB NULL,
  171. formatted_value TEXT NULL,
  172. space VARCHAR(128) NULL,
  173. persistent TINYINT(1) NOT NULL DEFAULT 0,
  174. dhcp_client_class VARCHAR(128) NULL,
  175. dhcp4_subnet_id INT NULL,
  176. host_id INT UNSIGNED NULL,
  177. PRIMARY KEY (option_id),
  178. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  179. INDEX fk_options_host1_idx (host_id ASC),
  180. CONSTRAINT fk_options_host1 FOREIGN KEY (host_id)
  181. REFERENCES hosts (host_id)
  182. ON DELETE NO ACTION ON UPDATE NO ACTION
  183. ) ENGINE=INNODB;
  184. -- -----------------------------------------------------
  185. -- Table `dhcp6_options`
  186. -- -----------------------------------------------------
  187. CREATE TABLE IF NOT EXISTS dhcp6_options (
  188. option_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
  189. code INT UNSIGNED NOT NULL,
  190. value BLOB NULL,
  191. formatted_value TEXT NULL,
  192. space VARCHAR(128) NULL,
  193. persistent TINYINT(1) NOT NULL DEFAULT 0,
  194. dhcp_client_class VARCHAR(128) NULL,
  195. dhcp6_subnet_id INT NULL,
  196. host_id INT UNSIGNED NULL,
  197. PRIMARY KEY (option_id),
  198. UNIQUE INDEX option_id_UNIQUE (option_id ASC),
  199. INDEX fk_options_host1_idx (host_id ASC),
  200. CONSTRAINT fk_options_host10 FOREIGN KEY (host_id)
  201. REFERENCES hosts (host_id)
  202. ON DELETE NO ACTION ON UPDATE NO ACTION
  203. ) ENGINE=INNODB;
  204. DELIMITER $$
  205. CREATE TRIGGER host_BDEL BEFORE DELETE ON hosts FOR EACH ROW
  206. -- Edit trigger body code below this line. Do not edit lines above this one
  207. BEGIN
  208. DELETE FROM ipv6_reservations WHERE ipv6_reservations.host_id = OLD.host_id;
  209. END
  210. $$
  211. DELIMITER ;
  212. UPDATE schema_version
  213. SET version = '3', minor = '0';
  214. # This line concludes database upgrade to version 3.0.
  215. # This line starts database upgrade to version 4.0.
  216. # Upgrade extending MySQL schema with the state columns for lease tables.
  217. # Add state column to the lease4 table.
  218. ALTER TABLE lease4
  219. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  220. # Add state column to the lease6 table.
  221. ALTER TABLE lease6
  222. ADD COLUMN state INT UNSIGNED DEFAULT 0;
  223. # Create indexes for querying leases in a given state and segregated
  224. # by the expiration time. One of the applications is to retrieve all
  225. # expired leases. However, these indexes can be also used to retrieve
  226. # leases in a given state regardless of the expiration time.
  227. CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
  228. CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
  229. # Create table holding mapping of the lease states to their names.
  230. # This is not used in queries from the DHCP server but rather in
  231. # direct queries from the lease database management tools.
  232. CREATE TABLE IF NOT EXISTS lease_state (
  233. state INT UNSIGNED PRIMARY KEY NOT NULL,
  234. name VARCHAR(64) NOT NULL
  235. ) ENGINE=INNODB;
  236. # Insert currently defined state names.
  237. INSERT INTO lease_state VALUES (0, "default");
  238. INSERT INTO lease_state VALUES (1, "declined");
  239. INSERT INTO lease_state VALUES (2, "expired-reclaimed");
  240. # Add a constraint that any state value added to the lease4 must
  241. # map to a value in the lease_state table.
  242. ALTER TABLE lease4
  243. ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
  244. REFERENCES lease_state (state);
  245. # Add a constraint that any state value added to the lease6 must
  246. # map to a value in the lease_state table.
  247. ALTER TABLE lease6
  248. ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
  249. REFERENCES lease_state (state);
  250. # Add a constraint that lease type in the lease6 table must map
  251. # to a lease type defined in the lease6_types table.
  252. ALTER TABLE lease6
  253. ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
  254. REFERENCES lease6_types (lease_type);
  255. # Modify the name of one of the HW address sources, and add a new one.
  256. UPDATE lease_hwaddr_source
  257. SET name = 'HWADDR_SOURCE_DOCSIS_CMTS'
  258. WHERE hwaddr_source = 64;
  259. INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
  260. # Add UNSIGNED to match with the lease6.
  261. ALTER TABLE lease_hwaddr_source
  262. MODIFY COLUMN hwaddr_source INT UNSIGNED NOT NULL;
  263. # Add a constraint that non-null hwaddr_source in the lease6 table
  264. # must map to an entry in the lease_hwaddr_source.
  265. ALTER TABLE lease6
  266. ADD CONSTRAINT fk_lease6_hwaddr_source FOREIGN KEY (hwaddr_source)
  267. REFERENCES lease_hwaddr_source (hwaddr_source);
  268. # FUNCTION that returns a result set containing the column names for lease4 dumps
  269. DROP PROCEDURE IF EXISTS lease4DumpHeader;
  270. DELIMITER $$
  271. CREATE PROCEDURE lease4DumpHeader()
  272. BEGIN
  273. SELECT 'address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state';
  274. END $$
  275. DELIMITER ;
  276. # FUNCTION that returns a result set containing the data for lease4 dumps
  277. DROP PROCEDURE IF EXISTS lease4DumpData;
  278. DELIMITER $$
  279. CREATE PROCEDURE lease4DumpData()
  280. BEGIN
  281. SELECT
  282. INET_NTOA(l.address),
  283. IFNULL(HEX(l.hwaddr), ''),
  284. IFNULL(HEX(l.client_id), ''),
  285. l.valid_lifetime,
  286. l.expire,
  287. l.subnet_id,
  288. l.fqdn_fwd,
  289. l.fqdn_rev,
  290. l.hostname,
  291. s.name
  292. FROM
  293. lease4 l
  294. LEFT OUTER JOIN lease_state s on (l.state = s.state)
  295. ORDER BY l.address;
  296. END $$
  297. DELIMITER ;
  298. # FUNCTION that returns a result set containing the column names for lease6 dumps
  299. DROP PROCEDURE IF EXISTS lease6DumpHeader;
  300. DELIMITER $$
  301. CREATE PROCEDURE lease6DumpHeader()
  302. BEGIN
  303. 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';
  304. END $$
  305. DELIMITER ;
  306. # FUNCTION that returns a result set containing the data for lease6 dumps
  307. DROP PROCEDURE IF EXISTS lease6DumpData;
  308. DELIMITER $$
  309. CREATE PROCEDURE lease6DumpData()
  310. BEGIN
  311. SELECT
  312. l.address,
  313. IFNULL(HEX(l.duid), ''),
  314. l.valid_lifetime,
  315. l.expire,
  316. l.subnet_id,
  317. l.pref_lifetime,
  318. IFNULL(t.name, ''),
  319. l.iaid,
  320. l.prefix_len,
  321. l.fqdn_fwd,
  322. l.fqdn_rev,
  323. l.hostname,
  324. IFNULL(HEX(l.hwaddr), ''),
  325. IFNULL(l.hwtype, ''),
  326. IFNULL(h.name, ''),
  327. IFNULL(s.name, '')
  328. FROM lease6 l
  329. left outer join lease6_types t on (l.lease_type = t.lease_type)
  330. left outer join lease_state s on (l.state = s.state)
  331. left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source)
  332. ORDER BY l.address;
  333. END $$
  334. DELIMITER ;
  335. # Update the schema version number
  336. UPDATE schema_version
  337. SET version = '4', minor = '0';
  338. # This line concludes database upgrade to version 4.0.
  339. # In the event hardware address cannot be determined, we need to satisfy
  340. # foreign key constraint between lease6 and lease_hardware_source
  341. INSERT INTO lease_hwaddr_source VALUES (0, "HWADDR_SOURCE_UNKNOWN");
  342. # Update the schema version number
  343. UPDATE schema_version
  344. SET version = '4', minor = '1';
  345. # This line concludes database upgrade to version 4.1.
  346. # Update index used for searching DHCPv4 reservations by identifier and subnet id.
  347. # This index is now unique (to prevent duplicates) and includes DHCPv4 subnet
  348. # identifier.
  349. DROP INDEX key_dhcp4_identifier_subnet_id ON hosts;
  350. CREATE UNIQUE INDEX key_dhcp4_identifier_subnet_id ON hosts (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp4_subnet_id ASC);
  351. # Update index used for searching DHCPv6 reservations by identifier and subnet id.
  352. # This index is now unique to prevent duplicates.
  353. DROP INDEX key_dhcp6_identifier_subnet_id ON hosts;
  354. CREATE UNIQUE INDEX key_dhcp6_identifier_subnet_id ON hosts (dhcp_identifier ASC , dhcp_identifier_type ASC , dhcp6_subnet_id ASC);
  355. # Create index to search for reservations using IP address and subnet id.
  356. # This unique index guarantees that there is only one occurence of the
  357. # particular IPv4 address for a given subnet.
  358. CREATE UNIQUE INDEX key_dhcp4_ipv4_address_subnet_id ON hosts (ipv4_address ASC , dhcp4_subnet_id ASC);
  359. # Create index to search for reservations using address/prefix and prefix
  360. # length.
  361. CREATE UNIQUE INDEX key_dhcp6_address_prefix_len ON ipv6_reservations (address ASC , prefix_len ASC);
  362. # Create a table mapping host identifiers to their names. Values in this
  363. # table are used as a foreign key in hosts table to guarantee that only
  364. # identifiers present in host_identifier_type table are used in hosts
  365. # table.
  366. CREATE TABLE IF NOT EXISTS host_identifier_type (
  367. type TINYINT PRIMARY KEY NOT NULL, # Lease type code.
  368. name VARCHAR(32) # Name of the lease type
  369. ) ENGINE = INNODB;
  370. START TRANSACTION;
  371. INSERT INTO host_identifier_type VALUES (0, "hw-address"); # Non-temporary v6 addresses
  372. INSERT INTO host_identifier_type VALUES (1, "duid"); # Temporary v6 addresses
  373. INSERT INTO host_identifier_type VALUES (2, "circuit-id"); # Prefix delegations
  374. COMMIT;
  375. # Add a constraint that any identifier type value added to the hosts
  376. # must map to a value in the host_identifier_type table.
  377. ALTER TABLE hosts
  378. ADD CONSTRAINT fk_host_identifier_type FOREIGN KEY (dhcp_identifier_type)
  379. REFERENCES host_identifier_type (type);
  380. # Store DHCPv6 option code as 16-bit unsigned integer.
  381. ALTER TABLE dhcp6_options MODIFY code SMALLINT UNSIGNED NOT NULL;
  382. # Subnet identifier is unsigned.
  383. ALTER TABLE dhcp4_options MODIFY dhcp4_subnet_id INT UNSIGNED NULL;
  384. ALTER TABLE dhcp6_options MODIFY dhcp6_subnet_id INT UNSIGNED NULL;
  385. # Update the schema version number
  386. UPDATE schema_version
  387. SET version = '4', minor = '2';
  388. # This line concludes database upgrade to version 4.2.
  389. # Notes:
  390. #
  391. # Indexes
  392. # =======
  393. # It is likely that additional indexes will be needed. However, the
  394. # increase in lookup performance from these will come at the expense
  395. # of a decrease in performance during insert operations due to the need
  396. # to update the indexes. For this reason, the need for additional indexes
  397. # will be determined by experiment during performance tests.
  398. #
  399. # The most likely additional indexes will cover the following columns:
  400. #
  401. # hwaddr and client_id
  402. # For lease stability: if a client requests a new lease, try to find an
  403. # existing or recently expired lease for it so that it can keep using the
  404. # same IP address.
  405. #
  406. # Field Sizes
  407. # ===========
  408. # If any of the VARxxx field sizes are altered, the lengths in the MySQL
  409. # backend source file (mysql_lease_mgr.cc) must be correspondingly changed.
  410. #
  411. # Portability
  412. # ===========
  413. # The "ENGINE = INNODB" on some tables is not portable to another database
  414. # and will need to be removed.
  415. #
  416. # Some columns contain binary data so are stored as VARBINARY instead of
  417. # VARCHAR. This may be non-portable between databases: in this case, the
  418. # definition should be changed to VARCHAR.