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

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

/trunk

First stage implementation of export caching for performance. See #38.
A lot of the actual performance boost comes from indexes on a couple of
columns in WHERE clauses:

  • status column on domains and revzones
  • type, domain_id and rdns_id columns on records

Net speedup on ~100K records and ~3K zones was
~120s -> 20s (no cache) -> 4s (cache active)

File size: 4.3 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 log ADD COLUMN rdns_id INTEGER;
45
46-- Since records are now parented by one or both of a forward or reverse zone,
47-- we can't enforce FK relations on domain_id (or the new rdns_id) since many
48-- records won't have one or the other.
49ALTER TABLE records DROP CONSTRAINT "$1";
50ALTER TABLE records ALTER COLUMN domain_id SET DEFAULT 0;
51ALTER TABLE records ADD COLUMN rdns_id INTEGER DEFAULT 0;
52UPDATE records SET rdns_id=0;
53ALTER TABLE records ALTER COLUMN rdns_id SET NOT NULL;
54-- ~120s -> 75s performance boost on 100K records when always exporting all records
55CREATE INDEX rec_types_index ON records (type);
56-- Further ~1/3 performance gain, same dataset
57CREATE INDEX rec_domain_index ON records (domain_id);
58CREATE INDEX rec_revzone_index ON records (rdns_id);
59
60-- May as well drop and recreate; this is nominally static and loaded from the
61-- DB mainly for subset grouping and sorting convenience. Most of the entries
62-- have also been updated with new subset grouping and sorting data.
63DROP TABLE rectypes;
64CREATE TABLE rectypes (
65 val integer NOT NULL,
66 name character varying(20) NOT NULL,
67 stdflag integer DEFAULT 1 NOT NULL,
68 listorder integer DEFAULT 255 NOT NULL,
69 alphaorder integer DEFAULT 32768 NOT NULL
70);
71
72-- Types are required. NB: these are vaguely read-only too
73-- data from http://www.iana.org/assignments/dns-parameters
74COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
751 A 1 1 1
762 NS 2 9 37
773 MD 5 255 29
784 MF 5 255 30
795 CNAME 2 11 9
806 SOA 0 0 53
817 MB 5 255 28
828 MG 5 255 31
839 MR 5 255 33
8410 NULL 5 255 43
8511 WKS 5 255 64
8612 PTR 3 5 46
8713 HINFO 5 255 18
8814 MINFO 5 255 32
8915 MX 1 10 34
9016 TXT 2 12 60
9117 RP 4 255 48
9218 AFSDB 5 255 4
9319 X25 5 255 65
9420 ISDN 5 255 21
9521 RT 5 255 50
9622 NSAP 5 255 38
9723 NSAP-PTR 5 255 39
9824 SIG 5 255 51
9925 KEY 5 255 23
10026 PX 5 255 47
10127 GPOS 5 255 17
10228 AAAA 1 3 3
10329 LOC 5 255 25
10430 NXT 5 255 44
10531 EID 5 255 15
10632 NIMLOC 5 255 36
10733 SRV 1 13 55
10834 ATMA 5 255 6
10935 NAPTR 5 255 35
11036 KX 5 255 24
11137 CERT 5 255 8
11238 A6 5 3 2
11339 DNAME 5 255 12
11440 SINK 5 255 52
11541 OPT 5 255 45
11642 APL 5 255 5
11743 DS 5 255 14
11844 SSHFP 5 255 56
11945 IPSECKEY 5 255 20
12046 RRSIG 5 255 49
12147 NSEC 5 255 40
12248 DNSKEY 5 255 13
12349 DHCID 5 255 10
12450 NSEC3 5 255 41
12551 NSEC3PARAM 5 255 42
12655 HIP 5 255 19
12799 SPF 5 255 54
128100 UINFO 5 255 62
129101 UID 5 255 61
130102 GID 5 255 16
131103 UNSPEC 5 255 63
132249 TKEY 5 255 58
133250 TSIG 5 255 59
134251 IXFR 5 255 22
135252 AXFR 5 255 7
136253 MAILB 5 255 27
137254 MAILA 5 255 26
13832768 TA 5 255 57
13932769 DLV 5 255 11
140\.
141
142-- Custom types (ab)using the "Private use" range from 65280 to 65534
143COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
14465280 A+PTR 2 2 2
14565281 AAAA+PTR 2 4 4
14665282 PTR template 3 6 2
14765283 A+PTR template 2 7 2
14865284 AAAA+PTR template 8 13 2
14965285 Delegation 2 8 2
150\.
151
152-- Update dbversion
153UPDATE misc SET value='1.2' WHERE key='dbversion';
Note: See TracBrowser for help on using the repository browser.