dhcpdb_create.pgsql 19 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526
  1. -- Copyright (C) 2012-2017 Internet Systems Consortium, Inc. ("ISC")
  2. -- This Source Code Form is subject to the terms of the Mozilla Public
  3. -- License, v. 2.0. If a copy of the MPL was not distributed with this
  4. -- file, You can obtain one at http://mozilla.org/MPL/2.0/.
  5. -- This is the Kea DHCP schema specification for PostgreSQL.
  6. -- The schema is reasonably portable (with the exception of some field types
  7. -- specification, which are PostgreSQL-specific). Minor changes might be needed
  8. -- for other databases.
  9. -- To create the schema, either type the command:
  10. -- psql -U <user> -W <password> <database> < dhcpdb_create.pgsql
  11. -- ... at the command prompt, or log in to the PostgreSQL database and at the "postgres=#"
  12. -- prompt, issue the command:
  13. -- @dhcpdb_create.pgsql
  14. -- Start a single transaction for the Entire script
  15. START TRANSACTION;
  16. -- Holds the IPv4 leases.
  17. CREATE TABLE lease4 (
  18. address BIGINT PRIMARY KEY NOT NULL, -- IPv4 address
  19. hwaddr BYTEA, -- Hardware address
  20. client_id BYTEA, -- Client ID
  21. valid_lifetime BIGINT, -- Length of the lease (seconds)
  22. expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
  23. subnet_id BIGINT, -- Subnet identification
  24. fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
  25. fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
  26. hostname VARCHAR(255) -- The FQDN of the client
  27. );
  28. -- Create search indexes for lease4 table
  29. -- index by hwaddr and subnet_id
  30. CREATE INDEX lease4_by_hwaddr_subnet_id ON lease4 (hwaddr, subnet_id);
  31. -- index by client_id and subnet_id
  32. CREATE INDEX lease4_by_client_id_subnet_id ON lease4 (client_id, subnet_id);
  33. -- Holds the IPv6 leases.
  34. -- N.B. The use of a VARCHAR for the address is temporary for development:
  35. -- it will eventually be replaced by BINARY(16).
  36. CREATE TABLE lease6 (
  37. address VARCHAR(39) PRIMARY KEY NOT NULL, -- IPv6 address
  38. duid BYTEA, -- DUID
  39. valid_lifetime BIGINT, -- Length of the lease (seconds)
  40. expire TIMESTAMP WITH TIME ZONE, -- Expiration time of the lease
  41. subnet_id BIGINT, -- Subnet identification
  42. pref_lifetime BIGINT, -- Preferred lifetime
  43. lease_type SMALLINT, -- Lease type (see lease6_types
  44. -- table for possible values)
  45. iaid INT, -- See Section 10 of RFC 3315
  46. prefix_len SMALLINT, -- For IA_PD only
  47. fqdn_fwd BOOLEAN, -- Has forward DNS update been performed by a server
  48. fqdn_rev BOOLEAN, -- Has reverse DNS update been performed by a server
  49. hostname VARCHAR(255) -- The FQDN of the client
  50. );
  51. -- Create search indexes for lease4 table
  52. -- index by iaid, subnet_id, and duid
  53. CREATE INDEX lease6_by_iaid_subnet_id_duid ON lease6 (iaid, subnet_id, duid);
  54. -- ... and a definition of lease6 types. This table is a convenience for
  55. -- users of the database - if they want to view the lease table and use the
  56. -- type names, they can join this table with the lease6 table
  57. CREATE TABLE lease6_types (
  58. lease_type SMALLINT PRIMARY KEY NOT NULL, -- Lease type code.
  59. name VARCHAR(5) -- Name of the lease type
  60. );
  61. INSERT INTO lease6_types VALUES (0, 'IA_NA'); -- Non-temporary v6 addresses
  62. INSERT INTO lease6_types VALUES (1, 'IA_TA'); -- Temporary v6 addresses
  63. INSERT INTO lease6_types VALUES (2, 'IA_PD'); -- Prefix delegations
  64. -- Finally, the version of the schema. We start at 0.1 during development.
  65. -- This table is only modified during schema upgrades. For historical reasons
  66. -- (related to the names of the columns in the BIND 10 DNS database file), the
  67. -- first column is called "version" and not "major".
  68. CREATE TABLE schema_version (
  69. version INT PRIMARY KEY NOT NULL, -- Major version number
  70. minor INT -- Minor version number
  71. );
  72. INSERT INTO schema_version VALUES (1, 0);
  73. --
  74. -- Schema 2.0 specification starts here.
  75. --
  76. -- Add state column to the lease4 table.
  77. ALTER TABLE lease4
  78. ADD COLUMN state INT8 DEFAULT 0;
  79. -- Add state column to the lease6 table.
  80. ALTER TABLE lease6
  81. ADD COLUMN state INT8 DEFAULT 0;
  82. -- Create indexes for querying leases in a given state and segregated
  83. -- by the expiration time. One of the applications is to retrieve all
  84. -- expired leases. However, these indexes can be also used to retrieve
  85. -- leases in a given state regardless of the expiration time.
  86. CREATE INDEX lease4_by_state_expire ON lease4 (state ASC, expire ASC);
  87. CREATE INDEX lease6_by_state_expire ON lease6 (state ASC, expire ASC);
  88. -- Create table holding mapping of the lease states to their names.
  89. -- This is not used in queries from the DHCP server but rather in
  90. -- direct queries from the lease database management tools.
  91. CREATE TABLE lease_state (
  92. state INT8 PRIMARY KEY NOT NULL,
  93. name VARCHAR(64) NOT NULL);
  94. -- Insert currently defined state names.
  95. INSERT INTO lease_state VALUES (0, 'default');
  96. INSERT INTO lease_state VALUES (1, 'declined');
  97. INSERT INTO lease_state VALUES (2, 'expired-reclaimed');
  98. -- Add a constraint that any state value added to the lease4 must
  99. -- map to a value in the lease_state table.
  100. ALTER TABLE lease4
  101. ADD CONSTRAINT fk_lease4_state FOREIGN KEY (state)
  102. REFERENCES lease_state (state);
  103. -- Add a constraint that any state value added to the lease6 must
  104. -- map to a value in the lease_state table.
  105. ALTER TABLE lease6
  106. ADD CONSTRAINT fk_lease6_state FOREIGN KEY (state)
  107. REFERENCES lease_state (state);
  108. -- Add a constraint that lease type in the lease6 table must map
  109. -- to a lease type defined in the lease6_types table.
  110. ALTER TABLE lease6
  111. ADD CONSTRAINT fk_lease6_type FOREIGN KEY (lease_type)
  112. REFERENCES lease6_types (lease_type);
  113. --
  114. -- FUNCTION that returns a result set containing the column names for lease4 dumps.
  115. DROP FUNCTION IF EXISTS lease4DumpHeader();
  116. CREATE FUNCTION lease4DumpHeader() RETURNS text AS $$
  117. select cast('address,hwaddr,client_id,valid_lifetime,expire,subnet_id,fqdn_fwd,fqdn_rev,hostname,state' as text) as result;
  118. $$ LANGUAGE SQL;
  119. --
  120. --
  121. -- FUNCTION that returns a result set containing the data for lease4 dumps.
  122. DROP FUNCTION IF EXISTS lease4DumpData();
  123. CREATE FUNCTION lease4DumpData() RETURNS
  124. table (address inet,
  125. hwaddr text,
  126. client_id text,
  127. valid_lifetime bigint,
  128. expire timestamp with time zone,
  129. subnet_id bigint,
  130. fqdn_fwd int,
  131. fqdn_rev int,
  132. hostname text,
  133. state text
  134. ) as $$
  135. SELECT ('0.0.0.0'::inet + l.address),
  136. encode(l.hwaddr,'hex'),
  137. encode(l.client_id,'hex'),
  138. l.valid_lifetime,
  139. l.expire,
  140. l.subnet_id,
  141. l.fqdn_fwd::int,
  142. l.fqdn_rev::int,
  143. l.hostname,
  144. s.name
  145. FROM lease4 l
  146. left outer join lease_state s on (l.state = s.state);
  147. $$ LANGUAGE SQL;
  148. --
  149. --
  150. -- FUNCTION that returns a result set containing the column names for lease6 dumps.
  151. DROP FUNCTION IF EXISTS lease6DumpHeader();
  152. CREATE FUNCTION lease6DumpHeader() RETURNS text AS $$
  153. select cast('address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state' as text) as result;
  154. $$ LANGUAGE SQL;
  155. --
  156. --
  157. -- FUNCTION that returns a result set containing the data for lease6 dumps.
  158. DROP FUNCTION IF EXISTS lease6DumpData();
  159. CREATE FUNCTION lease6DumpData() RETURNS
  160. TABLE (
  161. address text,
  162. duid text,
  163. valid_lifetime bigint,
  164. expire timestamp with time zone,
  165. subnet_id bigint,
  166. pref_lifetime bigint,
  167. name text,
  168. iaid integer,
  169. prefix_len smallint,
  170. fqdn_fwd int,
  171. fqdn_rev int,
  172. hostname text,
  173. state text
  174. ) AS $$
  175. SELECT (l.address,
  176. encode(l.duid,'hex'),
  177. l.valid_lifetime,
  178. l.expire,
  179. l.subnet_id,
  180. l.pref_lifetime,
  181. t.name,
  182. l.iaid,
  183. l.prefix_len,
  184. l.fqdn_fwd::int,
  185. l.fqdn_rev::int,
  186. l.hostname,
  187. s.name)
  188. FROM lease6 l
  189. left outer join lease6_types t on (l.lease_type = t.lease_type)
  190. left outer join lease_state s on (l.state = s.state);
  191. $$ LANGUAGE SQL;
  192. --
  193. -- Set 2.0 schema version.
  194. UPDATE schema_version
  195. SET version = '2', minor = '0';
  196. -- Schema 2.0 specification ends here.
  197. -- Upgrade to schema 3.0 begins here:
  198. --
  199. -- Table structure for table host_identifier_type.
  200. --
  201. CREATE TABLE host_identifier_type (
  202. type SMALLINT PRIMARY KEY NOT NULL,
  203. name VARCHAR(32) DEFAULT NULL
  204. );
  205. INSERT INTO host_identifier_type VALUES (0, 'hw-address');
  206. INSERT INTO host_identifier_type VALUES (1, 'duid');
  207. INSERT INTO host_identifier_type VALUES (2, 'circuit-id');
  208. INSERT INTO host_identifier_type VALUES (3, 'client-id');
  209. --
  210. -- Table structure for table dhcp_option_scope.
  211. --
  212. CREATE TABLE dhcp_option_scope (
  213. scope_id SMALLINT PRIMARY KEY NOT NULL,
  214. scope_name varchar(32) DEFAULT NULL
  215. );
  216. INSERT INTO dhcp_option_scope VALUES (0, 'global');
  217. INSERT INTO dhcp_option_scope VALUES (1, 'subnet');
  218. INSERT INTO dhcp_option_scope VALUES (2, 'client-class');
  219. INSERT INTO dhcp_option_scope VALUES (3, 'host');
  220. --
  221. -- Table structure for table hosts.
  222. --
  223. -- Primary key and unique constraints automatically create indexes,
  224. -- foreign key constraints do not.
  225. CREATE TABLE hosts (
  226. host_id SERIAL PRIMARY KEY NOT NULL,
  227. dhcp_identifier BYTEA NOT NULL,
  228. dhcp_identifier_type SMALLINT NOT NULL,
  229. dhcp4_subnet_id INT DEFAULT NULL,
  230. dhcp6_subnet_id INT DEFAULT NULL,
  231. ipv4_address BIGINT DEFAULT NULL,
  232. hostname VARCHAR(255) DEFAULT NULL,
  233. dhcp4_client_classes VARCHAR(255) DEFAULT NULL,
  234. dhcp6_client_classes VARCHAR(255) DEFAULT NULL,
  235. CONSTRAINT key_dhcp4_ipv4_address_subnet_id UNIQUE (ipv4_address, dhcp4_subnet_id),
  236. CONSTRAINT key_dhcp4_identifier_subnet_id UNIQUE (dhcp_identifier, dhcp_identifier_type, dhcp4_subnet_id),
  237. CONSTRAINT key_dhcp6_identifier_subnet_id UNIQUE (dhcp_identifier, dhcp_identifier_type, dhcp6_subnet_id),
  238. CONSTRAINT fk_host_identifier_type FOREIGN KEY (dhcp_identifier_type) REFERENCES host_identifier_type (type)
  239. ON DELETE CASCADE
  240. );
  241. CREATE INDEX fk_host_identifier_type ON hosts (dhcp_identifier_type);
  242. --
  243. -- Table structure for table dhcp4_options.
  244. --
  245. CREATE TABLE dhcp4_options (
  246. option_id SERIAL PRIMARY KEY NOT NULL,
  247. code SMALLINT NOT NULL,
  248. value BYTEA,
  249. formatted_value TEXT,
  250. space VARCHAR(128) DEFAULT NULL,
  251. persistent BOOLEAN NOT NULL DEFAULT 'f',
  252. dhcp_client_class VARCHAR(128) DEFAULT NULL,
  253. dhcp4_subnet_id INT DEFAULT NULL,
  254. host_id INT DEFAULT NULL,
  255. scope_id SMALLINT NOT NULL,
  256. CONSTRAINT fk_options_host1 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE,
  257. CONSTRAINT fk_dhcp4_option_scode FOREIGN KEY (scope_id) REFERENCES dhcp_option_scope (scope_id) ON DELETE CASCADE
  258. );
  259. CREATE INDEX fk_dhcp4_options_host1_idx ON dhcp4_options (host_id);
  260. CREATE INDEX fk_dhcp4_options_scope_idx ON dhcp4_options (scope_id);
  261. --
  262. -- Table structure for table dhcp6_options.
  263. --
  264. CREATE TABLE dhcp6_options (
  265. option_id SERIAL PRIMARY KEY NOT NULL,
  266. code INT NOT NULL,
  267. value BYTEA,
  268. formatted_value TEXT,
  269. space VARCHAR(128) DEFAULT NULL,
  270. persistent BOOLEAN NOT NULL DEFAULT 'f',
  271. dhcp_client_class VARCHAR(128) DEFAULT NULL,
  272. dhcp6_subnet_id INT DEFAULT NULL,
  273. host_id INT DEFAULT NULL,
  274. scope_id SMALLINT NOT NULL,
  275. CONSTRAINT fk_options_host10 FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE,
  276. CONSTRAINT fk_dhcp6_option_scode FOREIGN KEY (scope_id) REFERENCES dhcp_option_scope (scope_id) ON DELETE CASCADE
  277. );
  278. CREATE INDEX fk_dhcp6_options_host1_idx ON dhcp6_options (host_id);
  279. CREATE INDEX fk_dhcp6_options_scope_idx ON dhcp6_options (scope_id);
  280. --
  281. -- Table structure for table ipv6_reservations.
  282. --
  283. CREATE TABLE ipv6_reservations (
  284. reservation_id SERIAL PRIMARY KEY NOT NULL,
  285. address VARCHAR(39) NOT NULL,
  286. prefix_len SMALLINT NOT NULL DEFAULT '128',
  287. type SMALLINT NOT NULL DEFAULT '0',
  288. dhcp6_iaid INT DEFAULT NULL,
  289. host_id INT NOT NULL,
  290. CONSTRAINT key_dhcp6_address_prefix_len UNIQUE (address, prefix_len),
  291. CONSTRAINT fk_ipv6_reservations_host FOREIGN KEY (host_id) REFERENCES hosts (host_id) ON DELETE CASCADE
  292. );
  293. CREATE INDEX fk_ipv6_reservations_host_idx ON ipv6_reservations (host_id);
  294. --
  295. -- Table structure for table lease_hwaddr_source.
  296. --
  297. CREATE TABLE lease_hwaddr_source (
  298. hwaddr_source INT PRIMARY KEY NOT NULL,
  299. name VARCHAR(40) DEFAULT NULL
  300. );
  301. -- Hardware address obtained from raw sockets.
  302. INSERT INTO lease_hwaddr_source VALUES (1, 'HWADDR_SOURCE_RAW');
  303. -- Hardware address converted from IPv6 link-local address with EUI-64.
  304. INSERT INTO lease_hwaddr_source VALUES (2, 'HWADDR_SOURCE_IPV6_LINK_LOCAL');
  305. -- Hardware address extracted from client-id (duid).
  306. INSERT INTO lease_hwaddr_source VALUES (4, 'HWADDR_SOURCE_DUID');
  307. -- Hardware address extracted from client address relay option (RFC6939).
  308. INSERT INTO lease_hwaddr_source VALUES (8, 'HWADDR_SOURCE_CLIENT_ADDR_RELAY_OPTION');
  309. -- Hardware address extracted from remote-id option (RFC4649).
  310. INSERT INTO lease_hwaddr_source VALUES (16, 'HWADDR_SOURCE_REMOTE_ID');
  311. -- Hardware address extracted from subscriber-id option (RFC4580).
  312. INSERT INTO lease_hwaddr_source VALUES (32, 'HWADDR_SOURCE_SUBSCRIBER_ID');
  313. -- Hardware address extracted from docsis options.
  314. INSERT INTO lease_hwaddr_source VALUES (64, 'HWADDR_SOURCE_DOCSIS_CMTS');
  315. INSERT INTO lease_hwaddr_source VALUES (128, 'HWADDR_SOURCE_DOCSIS_MODEM');
  316. -- In the event hardware address cannot be determined, we need to satisfy
  317. -- foreign key constraint between lease6 and lease_hardware_source.
  318. INSERT INTO lease_hwaddr_source VALUES (0, 'HWADDR_SOURCE_UNKNOWN');
  319. -- Adding ORDER BY clause to sort by lease address.
  320. --
  321. -- FUNCTION that returns a result set containing the data for lease4 dumps.
  322. DROP FUNCTION IF EXISTS lease4DumpData();
  323. CREATE FUNCTION lease4DumpData() RETURNS
  324. table (address inet,
  325. hwaddr text,
  326. client_id text,
  327. valid_lifetime bigint,
  328. expire timestamp with time zone,
  329. subnet_id bigint,
  330. fqdn_fwd int,
  331. fqdn_rev int,
  332. hostname text,
  333. state text
  334. ) as $$
  335. SELECT ('0.0.0.0'::inet + l.address),
  336. encode(l.hwaddr,'hex'),
  337. encode(l.client_id,'hex'),
  338. l.valid_lifetime,
  339. l.expire,
  340. l.subnet_id,
  341. l.fqdn_fwd::int,
  342. l.fqdn_rev::int,
  343. l.hostname,
  344. s.name
  345. FROM lease4 l
  346. left outer join lease_state s on (l.state = s.state)
  347. ORDER BY l.address;
  348. $$ LANGUAGE SQL;
  349. --
  350. -- Add new columns to lease6.
  351. ALTER TABLE lease6
  352. ADD COLUMN hwaddr BYTEA DEFAULT NULL,
  353. ADD COLUMN hwtype SMALLINT DEFAULT NULL,
  354. ADD COLUMN hwaddr_source SMALLINT DEFAULT NULL;
  355. --
  356. -- FUNCTION that returns a result set containing the column names for lease6 dumps.
  357. DROP FUNCTION IF EXISTS lease6DumpHeader();
  358. CREATE FUNCTION lease6DumpHeader() RETURNS text AS $$
  359. select cast('address,duid,valid_lifetime,expire,subnet_id,pref_lifetime,lease_type,iaid,prefix_len,fqdn_fwd,fqdn_rev,hostname,state,hwaddr,hwtype,hwaddr_source' as text) as result;
  360. $$ LANGUAGE SQL;
  361. --
  362. --
  363. -- FUNCTION that returns a result set containing the data for lease6 dumps.
  364. DROP FUNCTION IF EXISTS lease6DumpData();
  365. CREATE FUNCTION lease6DumpData() RETURNS
  366. TABLE (
  367. address text,
  368. duid text,
  369. valid_lifetime bigint,
  370. expire timestamp with time zone,
  371. subnet_id bigint,
  372. pref_lifetime bigint,
  373. name text,
  374. iaid integer,
  375. prefix_len smallint,
  376. fqdn_fwd int,
  377. fqdn_rev int,
  378. hostname text,
  379. state text,
  380. hwaddr text,
  381. hwtype smallint,
  382. hwaddr_source text
  383. ) AS $$
  384. SELECT (l.address,
  385. encode(l.duid,'hex'),
  386. l.valid_lifetime,
  387. l.expire,
  388. l.subnet_id,
  389. l.pref_lifetime,
  390. t.name,
  391. l.iaid,
  392. l.prefix_len,
  393. l.fqdn_fwd::int,
  394. l.fqdn_rev::int,
  395. l.hostname,
  396. s.name,
  397. encode(l.hwaddr,'hex'),
  398. l.hwtype,
  399. h.name
  400. )
  401. FROM lease6 l
  402. left outer join lease6_types t on (l.lease_type = t.lease_type)
  403. left outer join lease_state s on (l.state = s.state)
  404. left outer join lease_hwaddr_source h on (l.hwaddr_source = h.hwaddr_source)
  405. ORDER BY l.address;
  406. $$ LANGUAGE SQL;
  407. -- Add columns holding reservations for siaddr, sname and file fields
  408. -- carried within DHCPv4 message.
  409. ALTER TABLE hosts ADD COLUMN dhcp4_next_server BIGINT DEFAULT NULL;
  410. ALTER TABLE hosts ADD COLUMN dhcp4_server_hostname VARCHAR(64) DEFAULT NULL;
  411. ALTER TABLE hosts ADD COLUMN dhcp4_boot_file_name VARCHAR(128) DEFAULT NULL;
  412. -- Set 3.0 schema version.
  413. UPDATE schema_version
  414. SET version = '3', minor = '0';
  415. -- Schema 3.0 specification ends here.
  416. -- This is a placeholder for the changes between 3.0 and 3.1. Even if there
  417. -- are no further changes the schema version should be set to 3.1, because
  418. -- we have added a missing 'client-id' host reservation type entry in the
  419. -- 3.0 -> 3.1 upgrade script. This entry had been accidentally omitted when
  420. -- the 2.0 -> 3.0 upgrade script was created.
  421. -- Set 3.1 schema version.
  422. UPDATE schema_version
  423. SET version = '3', minor = '1';
  424. -- Commit the script transaction.
  425. COMMIT;
  426. -- Notes:
  427. -- Indexes
  428. -- =======
  429. -- It is likely that additional indexes will be needed. However, the
  430. -- increase in lookup performance from these will come at the expense
  431. -- of a decrease in performance during insert operations due to the need
  432. -- to update the indexes. For this reason, the need for additional indexes
  433. -- will be determined by experiment during performance tests.
  434. -- The most likely additional indexes will cover the following columns:
  435. -- hwaddr and client_id
  436. -- For lease stability: if a client requests a new lease, try to find an
  437. -- existing or recently expired lease for it so that it can keep using the
  438. -- same IP address.
  439. -- Field Sizes
  440. -- ===========
  441. -- If any of the VARxxx field sizes are altered, the lengths in the PgSQL
  442. -- backend source file (pgsql_lease_mgr.cc) must be correspondingly changed.
  443. -- Portability
  444. -- ===========
  445. -- Some columns contain binary data so are stored as BYTEA instead of
  446. -- VARCHAR. This may be non-portable between databases: in this case, the
  447. -- definition should be changed to VARCHAR.