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

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

/trunk

Fix up a minor SQL issue - missing an FK constraint on revzones.group_id

File size: 4.4 KB
Line 
1-- SQL table/record type upgrade file for dnsadmin 1.0 to 1.2 migration
2
3-- Minor buglet; domains must be unique
4-- ALTER TABLE domains ADD PRIMARY KEY (domain);
5
6CREATE TABLE default_rev_records (
7 record_id serial NOT NULL,
8 group_id integer DEFAULT 1 NOT NULL,
9 host text DEFAULT '' NOT NULL,
10 "type" integer DEFAULT 1 NOT NULL,
11 val text DEFAULT '' NOT NULL,
12 ttl integer DEFAULT 86400 NOT NULL,
13 description text
14);
15
16COPY default_rev_records (record_id, group_id, host, "type", val, ttl, description) FROM stdin;
171 1 hostmaster.ADMINDOMAIN:ns1.ADMINDOMAIN 6 3600:900:1048576:2560 3600
182 1 unused-%r.ADMINDOMAIN 65283 ZONE 3600
193 1 ns2.example.com 2 ZONE 7200 \N
204 1 ns1.example.com 2 ZONE 7200 \N
21\.
22
23SELECT pg_catalog.setval('default_rev_records_record_id_seq', 5, false);
24
25ALTER TABLE domains ADD COLUMN changed boolean;
26UPDATE domains SET changed=false;
27ALTER TABLE domains ALTER COLUMN changed SET DEFAULT true;
28ALTER TABLE domains ALTER COLUMN changed SET NOT NULL;
29-- ~2x performance boost iff most zones are fed to output from the cache
30CREATE INDEX dom_status_index ON domains (status);
31
32CREATE TABLE revzones (
33 rdns_id serial NOT NULL,
34 revnet cidr NOT NULL PRIMARY KEY,
35 group_id integer DEFAULT 1 NOT NULL,
36 description character varying(255) DEFAULT ''::character varying NOT NULL,
37 status integer DEFAULT 1 NOT NULL,
38 zserial integer,
39 sertype character(1) DEFAULT 'D'::bpchar,
40 changed boolean DEFAULT true NOT NULL
41);
42CREATE INDEX rev_status_index ON revzones (status);
43
44ALTER TABLE ONLY revzones
45 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
46
47ALTER TABLE log ADD COLUMN rdns_id INTEGER;
48
49-- Since records are now parented by one or both of a forward or reverse zone,
50-- we can't enforce FK relations on domain_id (or the new rdns_id) since many
51-- records won't have one or the other.
52ALTER TABLE records DROP CONSTRAINT "$1";
53ALTER TABLE records ALTER COLUMN domain_id SET DEFAULT 0;
54ALTER TABLE records ADD COLUMN rdns_id INTEGER DEFAULT 0;
55UPDATE records SET rdns_id=0;
56ALTER TABLE records ALTER COLUMN rdns_id SET NOT NULL;
57-- ~120s -> 75s performance boost on 100K records when always exporting all records
58CREATE INDEX rec_types_index ON records (type);
59-- Further ~1/3 performance gain, same dataset
60CREATE INDEX rec_domain_index ON records (domain_id);
61CREATE INDEX rec_revzone_index ON records (rdns_id);
62
63-- May as well drop and recreate; this is nominally static and loaded from the
64-- DB mainly for subset grouping and sorting convenience. Most of the entries
65-- have also been updated with new subset grouping and sorting data.
66DROP TABLE rectypes;
67CREATE TABLE rectypes (
68 val integer NOT NULL,
69 name character varying(20) NOT NULL,
70 stdflag integer DEFAULT 1 NOT NULL,
71 listorder integer DEFAULT 255 NOT NULL,
72 alphaorder integer DEFAULT 32768 NOT NULL
73);
74
75-- Types are required. NB: these are vaguely read-only too
76-- data from http://www.iana.org/assignments/dns-parameters
77COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
781 A 1 1 1
792 NS 2 9 37
803 MD 5 255 29
814 MF 5 255 30
825 CNAME 2 11 9
836 SOA 0 0 53
847 MB 5 255 28
858 MG 5 255 31
869 MR 5 255 33
8710 NULL 5 255 43
8811 WKS 5 255 64
8912 PTR 3 5 46
9013 HINFO 5 255 18
9114 MINFO 5 255 32
9215 MX 1 10 34
9316 TXT 2 12 60
9417 RP 4 255 48
9518 AFSDB 5 255 4
9619 X25 5 255 65
9720 ISDN 5 255 21
9821 RT 5 255 50
9922 NSAP 5 255 38
10023 NSAP-PTR 5 255 39
10124 SIG 5 255 51
10225 KEY 5 255 23
10326 PX 5 255 47
10427 GPOS 5 255 17
10528 AAAA 1 3 3
10629 LOC 5 255 25
10730 NXT 5 255 44
10831 EID 5 255 15
10932 NIMLOC 5 255 36
11033 SRV 1 13 55
11134 ATMA 5 255 6
11235 NAPTR 5 255 35
11336 KX 5 255 24
11437 CERT 5 255 8
11538 A6 5 3 2
11639 DNAME 5 255 12
11740 SINK 5 255 52
11841 OPT 5 255 45
11942 APL 5 255 5
12043 DS 5 255 14
12144 SSHFP 5 255 56
12245 IPSECKEY 5 255 20
12346 RRSIG 5 255 49
12447 NSEC 5 255 40
12548 DNSKEY 5 255 13
12649 DHCID 5 255 10
12750 NSEC3 5 255 41
12851 NSEC3PARAM 5 255 42
12955 HIP 5 255 19
13099 SPF 5 255 54
131100 UINFO 5 255 62
132101 UID 5 255 61
133102 GID 5 255 16
134103 UNSPEC 5 255 63
135249 TKEY 5 255 58
136250 TSIG 5 255 59
137251 IXFR 5 255 22
138252 AXFR 5 255 7
139253 MAILB 5 255 27
140254 MAILA 5 255 26
14132768 TA 5 255 57
14232769 DLV 5 255 11
143\.
144
145-- Custom types (ab)using the "Private use" range from 65280 to 65534
146COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
14765280 A+PTR 2 2 2
14865281 AAAA+PTR 2 4 4
14965282 PTR template 3 6 2
15065283 A+PTR template 2 7 2
15165284 AAAA+PTR template 8 13 2
15265285 Delegation 2 8 2
153\.
154
155-- Update dbversion
156UPDATE misc SET value='1.2' WHERE key='dbversion';
Note: See TracBrowser for help on using the repository browser.