source: trunk/dns-1.0-1.2.sql@ 372

Last change on this file since 372 was 372, checked in by Kris Deugau, 12 years ago

/trunk

Checkpoint adding location/view support. See #10.

  • minor location list template tweak
  • extend importer to deal with locations on records, and location definitions
  • extend exporter to handle locations

Also:

  • minor SQL error-log cleanup (boolean types use 'y'/'n' or 'true'/'false'). See #25, sort of
  • Fix handling of CNAME exports for reverse zones; the records look ugly but there's no simple way to autoconvert them to the template types on import
  • Fix lurking buglet in tabledef update; we're using a 4-char field for locations to allow for legacy uses.
File size: 5.1 KB
Line 
1-- SQL table/record type upgrade file for dnsadmin 1.0 to 1.2 migration
2
3-- need this before we add any other bits
4CREATE TABLE locations (
5 location character varying (4) PRIMARY KEY,
6 group_id integer NOT NULL DEFAULT 1,
7 iplist text NOT NULL DEFAULT '',
8 description text NOT NULL DEFAULT ''
9);
10
11ALTER TABLE ONLY locations
12 ADD CONSTRAINT "locations_group_id_fkey" FOREIGN KEY (group_id) REFERENCES groups(group_id);
13
14ALTER TABLE permissions ADD COLUMN location_create boolean DEFAULT false NOT NULL;
15ALTER TABLE permissions ADD COLUMN location_edit boolean DEFAULT false NOT NULL;
16ALTER TABLE permissions ADD COLUMN location_delete boolean DEFAULT false NOT NULL;
17ALTER TABLE permissions ADD COLUMN location_view boolean DEFAULT false NOT NULL;
18
19-- Minor buglet; domains must be unique
20-- ALTER TABLE domains ADD PRIMARY KEY (domain);
21
22CREATE TABLE default_rev_records (
23 record_id serial NOT NULL,
24 group_id integer DEFAULT 1 NOT NULL,
25 host text DEFAULT '' NOT NULL,
26 "type" integer DEFAULT 1 NOT NULL,
27 val text DEFAULT '' NOT NULL,
28 ttl integer DEFAULT 86400 NOT NULL,
29 description text
30);
31
32COPY default_rev_records (record_id, group_id, host, "type", val, ttl, description) FROM stdin;
331 1 hostmaster.ADMINDOMAIN:ns1.ADMINDOMAIN 6 3600:900:1048576:2560 3600
342 1 unused-%r.ADMINDOMAIN 65283 ZONE 3600
353 1 ns2.example.com 2 ZONE 7200 \N
364 1 ns1.example.com 2 ZONE 7200 \N
37\.
38
39SELECT pg_catalog.setval('default_rev_records_record_id_seq', 5, false);
40
41ALTER TABLE domains ADD COLUMN changed boolean DEFAULT true NOT NULL;
42ALTER TABLE domains ADD COLUMN default_location character varying (4) DEFAULT '' NOT NULL;
43-- ~2x performance boost iff most zones are fed to output from the cache
44CREATE INDEX dom_status_index ON domains (status);
45
46CREATE TABLE revzones (
47 rdns_id serial NOT NULL,
48 revnet cidr NOT NULL PRIMARY KEY,
49 group_id integer DEFAULT 1 NOT NULL,
50 description character varying(255) DEFAULT ''::character varying NOT NULL,
51 status integer DEFAULT 1 NOT NULL,
52 zserial integer,
53 sertype character(1) DEFAULT 'D'::bpchar,
54 changed boolean DEFAULT true NOT NULL,
55 default_location character varying (4) DEFAULT '' NOT NULL
56);
57CREATE INDEX rev_status_index ON revzones (status);
58
59ALTER TABLE ONLY revzones
60 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
61
62ALTER TABLE log ADD COLUMN rdns_id INTEGER;
63
64-- Since records are now parented by one or both of a forward or reverse zone,
65-- we can't enforce FK relations on domain_id (or the new rdns_id) since many
66-- records won't have one or the other.
67ALTER TABLE records DROP CONSTRAINT "$1";
68ALTER TABLE records ALTER COLUMN domain_id SET DEFAULT 0;
69ALTER TABLE records ADD COLUMN rdns_id INTEGER DEFAULT 0 NOT NULL;
70ALTER TABLE records ADD COLUMN location character varying (4) DEFAULT '' NOT NULL;
71
72-- ~120s -> 75s performance boost on 100K records when always exporting all records
73CREATE INDEX rec_types_index ON records (type);
74-- Further ~1/3 performance gain, same dataset
75CREATE INDEX rec_domain_index ON records (domain_id);
76CREATE INDEX rec_revzone_index ON records (rdns_id);
77
78-- May as well drop and recreate; this is nominally static and loaded from the
79-- DB mainly for subset grouping and sorting convenience. Most of the entries
80-- have also been updated with new subset grouping and sorting data.
81DROP TABLE rectypes;
82CREATE TABLE rectypes (
83 val integer NOT NULL,
84 name character varying(20) NOT NULL,
85 stdflag integer DEFAULT 1 NOT NULL,
86 listorder integer DEFAULT 255 NOT NULL,
87 alphaorder integer DEFAULT 32768 NOT NULL
88);
89
90-- Types are required. NB: these are vaguely read-only too
91-- data from http://www.iana.org/assignments/dns-parameters
92COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
931 A 1 1 1
942 NS 2 9 37
953 MD 5 255 29
964 MF 5 255 30
975 CNAME 2 11 9
986 SOA 0 0 53
997 MB 5 255 28
1008 MG 5 255 31
1019 MR 5 255 33
10210 NULL 5 255 43
10311 WKS 5 255 64
10412 PTR 3 5 46
10513 HINFO 5 255 18
10614 MINFO 5 255 32
10715 MX 1 10 34
10816 TXT 2 12 60
10917 RP 4 255 48
11018 AFSDB 5 255 4
11119 X25 5 255 65
11220 ISDN 5 255 21
11321 RT 5 255 50
11422 NSAP 5 255 38
11523 NSAP-PTR 5 255 39
11624 SIG 5 255 51
11725 KEY 5 255 23
11826 PX 5 255 47
11927 GPOS 5 255 17
12028 AAAA 1 3 3
12129 LOC 5 255 25
12230 NXT 5 255 44
12331 EID 5 255 15
12432 NIMLOC 5 255 36
12533 SRV 1 13 55
12634 ATMA 5 255 6
12735 NAPTR 5 255 35
12836 KX 5 255 24
12937 CERT 5 255 8
13038 A6 5 3 2
13139 DNAME 5 255 12
13240 SINK 5 255 52
13341 OPT 5 255 45
13442 APL 5 255 5
13543 DS 5 255 14
13644 SSHFP 5 255 56
13745 IPSECKEY 5 255 20
13846 RRSIG 5 255 49
13947 NSEC 5 255 40
14048 DNSKEY 5 255 13
14149 DHCID 5 255 10
14250 NSEC3 5 255 41
14351 NSEC3PARAM 5 255 42
14455 HIP 5 255 19
14599 SPF 5 255 54
146100 UINFO 5 255 62
147101 UID 5 255 61
148102 GID 5 255 16
149103 UNSPEC 5 255 63
150249 TKEY 5 255 58
151250 TSIG 5 255 59
152251 IXFR 5 255 22
153252 AXFR 5 255 7
154253 MAILB 5 255 27
155254 MAILA 5 255 26
15632768 TA 5 255 57
15732769 DLV 5 255 11
158\.
159
160-- Custom types (ab)using the "Private use" range from 65280 to 65534
161COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
16265280 A+PTR 2 2 2
16365281 AAAA+PTR 2 4 4
16465282 PTR template 3 6 2
16565283 A+PTR template 2 7 2
16665284 AAAA+PTR template 8 13 2
16765285 Delegation 2 8 2
168\.
169
170-- Update dbversion
171UPDATE misc SET value='1.2' WHERE key='dbversion';
Note: See TracBrowser for help on using the repository browser.