source: trunk/dns.sql@ 245

Last change on this file since 245 was 224, checked in by Kris Deugau, 13 years ago

/trunk

Start adding rDNS (See #26)

  • Initial SQL tabledef, default records, and record types (we'll abuse the reserved range of DNS record types from 65280 to 65534 for some extra custom types)
  • Start passing $webvar{revrec} around similar to $webvar{defrec}
  • Adjust record list page to handle reverse records. Tested on group-default reverse records but should work fine for live zones
  • Add "Reverse Zones" and "Default Reverse Records" to menu
  • While we're rearranging it, add a little more paranoia on some of the SQL
File size: 9.4 KB
RevLine 
[50]1-- these lines could be run as a superuser. alter database name, username, password, group as appropriate.
2-- make sure to alter dnsdb.conf to match
3-- CREATE GROUP dnsdb;
4-- CREATE USER dnsdb WITH UNENCRYPTED PASSWORD 'secret' IN GROUP dnsdb;
5-- CREATE DATABASE dnsdb OWNED BY dnsdb;
6-- SET SESSION AUTHORIZATION 'dnsdb';
7
[212]8-- need a handy place to put eg a DB version identifier - useful for auto-upgrading a DB
9CREATE TABLE misc (
10 misc_id serial NOT NULL,
11 key text DEFAULT '' NOT NULL,
[215]12 value text DEFAULT '' NOT NULL
[212]13);
14
15COPY misc (misc_id, key, value) FROM stdin;
161 dbversion 1.0
17\.
18
[50]19CREATE TABLE default_records (
20 record_id serial NOT NULL,
21 group_id integer DEFAULT 1 NOT NULL,
[130]22 host text DEFAULT '' NOT NULL,
[50]23 "type" integer DEFAULT 1 NOT NULL,
[130]24 val text DEFAULT '' NOT NULL,
[50]25 distance integer DEFAULT 0 NOT NULL,
26 weight integer DEFAULT 0 NOT NULL,
27 port integer DEFAULT 0 NOT NULL,
28 ttl integer DEFAULT 86400 NOT NULL,
[130]29 description text
[50]30);
31
32-- default records for the default group
33COPY default_records (record_id, group_id, host, "type", val, distance, weight, port, ttl, description) FROM stdin;
341 1 ns1.example.com:hostmaster.DOMAIN 6 10800:3600:604800:5400 0 0 0 86400 \N
352 1 DOMAIN 2 ns2.example.com 0 0 0 7200 \N
363 1 DOMAIN 2 ns1.example.com 0 0 0 7200 \N
374 1 DOMAIN 1 10.0.0.4 0 0 0 7200 \N
385 1 DOMAIN 15 mx1.example.com 10 0 0 7200 \N
396 1 www.DOMAIN 5 DOMAIN 0 0 0 10800 \N
407 1 DOMAIN 16 "v=spf1 a mx -all" 0 0 0 10800 \N
41\.
42
[224]43CREATE TABLE default_rev_records (
44 record_id serial NOT NULL,
45 group_id integer DEFAULT 1 NOT NULL,
46 host text DEFAULT '' NOT NULL,
47 "type" integer DEFAULT 1 NOT NULL,
48 val text DEFAULT '' NOT NULL,
49 ttl integer DEFAULT 86400 NOT NULL,
50 description text
51);
52
53COPY default_rev_records (record_id, group_id, host, "type", ip, ttl, description) FROM stdin;
541 1 hostmaster.ADMINDOMAIN:ns1.ADMINDOMAIN 6 3600:900:1048576:2560 3600
552 1 unused-%r.ADMINDOMAIN 65283 ZONE 3600
56\.
57
[85]58CREATE TABLE domains (
59 domain_id serial NOT NULL,
60 "domain" character varying(80) NOT NULL,
61 group_id integer DEFAULT 1 NOT NULL,
62 description character varying(255) DEFAULT ''::character varying NOT NULL,
63 status integer DEFAULT 1 NOT NULL,
64 zserial integer,
65 sertype character(1) DEFAULT 'D'::bpchar
66);
67
[224]68CREATE TABLE revzones (
69 rdns_id serial NOT NULL,
70 revnet cidr NOT NULL,
71 group_id integer DEFAULT 1 NOT NULL,
72 description character varying(255) DEFAULT ''::character varying NOT NULL,
73 status integer DEFAULT 1 NOT NULL,
74 zserial integer,
75 sertype character(1) DEFAULT 'D'::bpchar
76);
77
[85]78CREATE TABLE groups (
79 group_id serial NOT NULL,
80 parent_group_id integer DEFAULT 1 NOT NULL,
81 group_name character varying(255) DEFAULT ''::character varying NOT NULL,
82 permission_id integer DEFAULT 1 NOT NULL,
83 inherit_perm boolean DEFAULT true NOT NULL
84);
85
86-- Provide a basic default group
[86]87COPY groups (group_id, parent_group_id, permission_id, group_name) FROM stdin;
[85]881 1 1 default
89\.
90
[91]91-- entry is text due to possible long entries from AXFR - a domain with "many"
92-- odd records will overflow varchar(200)
[85]93CREATE TABLE log (
[89]94 log_id serial NOT NULL,
[85]95 domain_id integer,
[224]96 rdns_id integer,
[85]97 user_id integer,
98 group_id integer,
99 email character varying(60),
100 name character varying(60),
[91]101 entry text,
[85]102 stamp timestamp with time zone DEFAULT now()
103);
104
105CREATE TABLE permissions (
106 permission_id serial NOT NULL,
107 "admin" boolean DEFAULT false NOT NULL,
108 self_edit boolean DEFAULT false NOT NULL,
109 group_create boolean DEFAULT false NOT NULL,
110 group_edit boolean DEFAULT false NOT NULL,
111 group_delete boolean DEFAULT false NOT NULL,
112 user_create boolean DEFAULT false NOT NULL,
113 user_edit boolean DEFAULT false NOT NULL,
114 user_delete boolean DEFAULT false NOT NULL,
115 domain_create boolean DEFAULT false NOT NULL,
116 domain_edit boolean DEFAULT false NOT NULL,
117 domain_delete boolean DEFAULT false NOT NULL,
118 record_create boolean DEFAULT false NOT NULL,
119 record_edit boolean DEFAULT false NOT NULL,
120 record_delete boolean DEFAULT false NOT NULL,
[86]121 user_id integer UNIQUE,
122 group_id integer UNIQUE
[85]123);
124
125-- Need *two* basic permissions; one for the initial group, one for the default admin user
[86]126COPY permissions (permission_id, admin, self_edit, group_create, group_edit, group_delete, user_create, user_edit, user_delete, domain_create, domain_edit, domain_delete, record_create, record_edit, record_delete, user_id, group_id) FROM stdin;
[89]1271 f f f f f f f f t t t t t t \N 1
[86]1282 t f f f f f f f f f f f f f 1 \N
[85]129\.
130
[224]131-- rdns_id defaults to 0 since many records will not have an associated rDNS entry.
[50]132CREATE TABLE records (
[224]133 domain_id integer NOT NULL DEFAULT 0,
134 rdns_id integer NOT NULL DEFAULT 0,
[50]135 record_id serial NOT NULL,
[130]136 host text DEFAULT '' NOT NULL,
[50]137 "type" integer DEFAULT 1 NOT NULL,
[130]138 val text DEFAULT '' NOT NULL,
[50]139 distance integer DEFAULT 0 NOT NULL,
140 weight integer DEFAULT 0 NOT NULL,
141 port integer DEFAULT 0 NOT NULL,
[85]142 ttl integer DEFAULT 7200 NOT NULL,
[130]143 description text
[50]144);
145
146CREATE TABLE rectypes (
147 val integer NOT NULL,
[224]148 name character varying(20) NOT NULL,
[50]149 stdflag integer DEFAULT 1 NOT NULL,
[102]150 listorder integer DEFAULT 255 NOT NULL,
151 alphaorder integer DEFAULT 32768 NOT NULL
[50]152);
153
154-- Types are required. NB: these are vaguely read-only too
[85]155-- data from http://www.iana.org/assignments/dns-parameters
[102]156COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
1571 A 1 1 1
[224]1582 NS 1 5 37
1593 MD 5 255 29
1604 MF 5 255 30
1615 CNAME 1 7 9
1626 SOA 0 0 53
1637 MB 5 255 28
1648 MG 5 255 31
1659 MR 5 255 33
16610 NULL 5 255 43
16711 WKS 5 255 64
16812 PTR 3 10 46
16913 HINFO 5 255 18
17014 MINFO 5 255 32
17115 MX 1 6 34
17216 TXT 1 8 60
17317 RP 4 255 48
17418 AFSDB 5 255 4
17519 X25 5 255 65
17620 ISDN 5 255 21
17721 RT 5 255 50
17822 NSAP 5 255 38
17923 NSAP-PTR 5 255 39
18024 SIG 5 255 51
18125 KEY 5 255 23
18226 PX 5 255 47
18327 GPOS 5 255 17
18428 AAAA 1 3 3
18529 LOC 5 255 25
18630 NXT 5 255 44
18731 EID 5 255 15
18832 NIMLOC 5 255 36
18933 SRV 1 9 55
19034 ATMA 5 255 6
19135 NAPTR 5 255 35
19236 KX 5 255 24
19337 CERT 5 255 8
19438 A6 5 3 2
19539 DNAME 5 255 12
19640 SINK 5 255 52
19741 OPT 5 255 45
19842 APL 5 255 5
19943 DS 5 255 14
20044 SSHFP 5 255 56
20145 IPSECKEY 5 255 20
20246 RRSIG 5 255 49
20347 NSEC 5 255 40
20448 DNSKEY 5 255 13
20549 DHCID 5 255 10
20650 NSEC3 5 255 41
20751 NSEC3PARAM 5 255 42
20855 HIP 5 255 19
20999 SPF 5 255 54
210100 UINFO 5 255 62
211101 UID 5 255 61
212102 GID 5 255 16
213103 UNSPEC 5 255 63
214249 TKEY 5 255 58
215250 TSIG 5 255 59
216251 IXFR 5 255 22
217252 AXFR 5 255 7
218253 MAILB 5 255 27
219254 MAILA 5 255 26
22032768 TA 5 255 57
22132769 DLV 5 255 11
[50]222\.
223
[224]224-- Custom types (ab)using the "Private use" range from 65280 to 65534
225COPY rectypes (val, name, stdflag, listorder, alphaorder) FROM stdin;
22665280 A+PTR 2 2 2
22765281 AAAA+PTR 2 4 4
22865282 PTR template 3 11 2
22965283 A+PTR template 3 12 2
23065284 AAAA+PTR template 3 13 2
231\.
232
[50]233CREATE TABLE users (
234 user_id serial NOT NULL,
235 group_id integer DEFAULT 1 NOT NULL,
236 username character varying(60) NOT NULL,
237 "password" character varying(34) NOT NULL,
[85]238 firstname character varying(60),
239 lastname character varying(60),
[50]240 phone character varying(15),
241 "type" character(1) DEFAULT 'S'::bpchar NOT NULL,
242 status integer DEFAULT 1 NOT NULL,
[85]243 permission_id integer DEFAULT 1 NOT NULL,
244 inherit_perm boolean DEFAULT true NOT NULL
[50]245);
246
247-- create initial default user? may be better to create an "initialize" script or something
[86]248COPY users (user_id, group_id, username, "password", firstname, lastname, phone, "type", status, permission_id, inherit_perm) FROM stdin;
[89]2491 1 admin $1$PfEBUv9d$wV2/UG4gmKk08DLmdE8/d. Initial User \N S 1 2 f
[50]250\.
251
252--
253-- contraints. add these here so initial data doesn't get added strangely.
254--
255
256-- primary keys
[65]257ALTER TABLE ONLY permissions
258 ADD CONSTRAINT permissions_permission_id_key UNIQUE (permission_id);
259
[50]260ALTER TABLE ONLY groups
261 ADD CONSTRAINT groups_group_id_key UNIQUE (group_id);
262
263ALTER TABLE ONLY domains
264 ADD CONSTRAINT domains_pkey PRIMARY KEY ("domain");
265
266ALTER TABLE ONLY domains
267 ADD CONSTRAINT domains_domain_id_key UNIQUE (domain_id);
268
269ALTER TABLE ONLY default_records
270 ADD CONSTRAINT default_records_pkey PRIMARY KEY (record_id);
271
272ALTER TABLE ONLY records
273 ADD CONSTRAINT records_pkey PRIMARY KEY (record_id);
274
275ALTER TABLE ONLY rectypes
276 ADD CONSTRAINT rectypes_pkey PRIMARY KEY (val, name);
277
278ALTER TABLE ONLY users
279 ADD CONSTRAINT users_pkey PRIMARY KEY (username);
280
281ALTER TABLE ONLY users
282 ADD CONSTRAINT uidu UNIQUE (user_id);
283
284-- foreign keys
[65]285-- fixme: permissions FK refs
[50]286ALTER TABLE ONLY domains
287 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
288
289ALTER TABLE ONLY default_records
290 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
291
292ALTER TABLE ONLY users
293 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
294
295ALTER TABLE ONLY groups
296 ADD CONSTRAINT group_parent FOREIGN KEY (parent_group_id) REFERENCES groups(group_id);
[86]297
298-- set starting sequence numbers, since we've inserted data before they're active
[224]299SELECT pg_catalog.setval('misc_misc_id_seq', 2, false);
300SELECT pg_catalog.setval('default_records_record_id_seq', 8, false);
301SELECT pg_catalog.setval('default_rev_records_record_id_seq', 3, false);
[86]302SELECT pg_catalog.setval('domains_domain_id_seq', 1, false);
[224]303SELECT pg_catalog.setval('groups_group_id_seq', 2, false);
304SELECT pg_catalog.setval('permissions_permission_id_seq', 3, false);
[86]305SELECT pg_catalog.setval('records_record_id_seq', 1, false);
306SELECT pg_catalog.setval('users_user_id_seq', 2, false);
Note: See TracBrowser for help on using the repository browser.