source: trunk/dns.sql@ 101

Last change on this file since 101 was 91, checked in by Kris Deugau, 14 years ago

/trunk

SQL tabledef update:

  • Tweak log table definition to cope with looooong entries (mainly from AXFR warnings)

DNSDB.pm:

  • Add domainID and getRecCount subs in DNSDB
  • Return more user-friendly error on attempting to add a domain with no name
  • Nitpick-tweak DB calls and SQL formatting in domainName()
  • Replace placeholderish OK message in importAXFR()

dns.cgi:

  • Trim some more direct SQL out in reclist
  • Uninitialized-variable cleanup in AXFR import
  • Add logging to AXFR import
  • Don't complain about uninitialized variables in record-display
File size: 8.0 KB
Line 
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
8CREATE TABLE default_records (
9 record_id serial NOT NULL,
10 longrec_id integer,
11 group_id integer DEFAULT 1 NOT NULL,
12 host character varying(100) DEFAULT ''::character varying NOT NULL,
13 "type" integer DEFAULT 1 NOT NULL,
14 val character varying(100) DEFAULT ''::character varying NOT NULL,
15 distance integer DEFAULT 0 NOT NULL,
16 weight integer DEFAULT 0 NOT NULL,
17 port integer DEFAULT 0 NOT NULL,
18 ttl integer DEFAULT 86400 NOT NULL,
19 description character varying(255)
20);
21
22-- default records for the default group
23COPY default_records (record_id, group_id, host, "type", val, distance, weight, port, ttl, description) FROM stdin;
241 1 ns1.example.com:hostmaster.DOMAIN 6 10800:3600:604800:5400 0 0 0 86400 \N
252 1 DOMAIN 2 ns2.example.com 0 0 0 7200 \N
263 1 DOMAIN 2 ns1.example.com 0 0 0 7200 \N
274 1 DOMAIN 1 10.0.0.4 0 0 0 7200 \N
285 1 DOMAIN 15 mx1.example.com 10 0 0 7200 \N
296 1 www.DOMAIN 5 DOMAIN 0 0 0 10800 \N
307 1 DOMAIN 16 "v=spf1 a mx -all" 0 0 0 10800 \N
31\.
32
33CREATE TABLE domains (
34 domain_id serial NOT NULL,
35 "domain" character varying(80) NOT NULL,
36 group_id integer DEFAULT 1 NOT NULL,
37 description character varying(255) DEFAULT ''::character varying NOT NULL,
38 status integer DEFAULT 1 NOT NULL,
39 zserial integer,
40 sertype character(1) DEFAULT 'D'::bpchar
41);
42
43CREATE TABLE groups (
44 group_id serial NOT NULL,
45 parent_group_id integer DEFAULT 1 NOT NULL,
46 group_name character varying(255) DEFAULT ''::character varying NOT NULL,
47 permission_id integer DEFAULT 1 NOT NULL,
48 inherit_perm boolean DEFAULT true NOT NULL
49);
50
51-- Provide a basic default group
52COPY groups (group_id, parent_group_id, permission_id, group_name) FROM stdin;
531 1 1 default
54\.
55
56-- entry is text due to possible long entries from AXFR - a domain with "many"
57-- odd records will overflow varchar(200)
58CREATE TABLE log (
59 log_id serial NOT NULL,
60 domain_id integer,
61 user_id integer,
62 group_id integer,
63 email character varying(60),
64 name character varying(60),
65 entry text,
66 stamp timestamp with time zone DEFAULT now()
67);
68
69CREATE TABLE permissions (
70 permission_id serial NOT NULL,
71 "admin" boolean DEFAULT false NOT NULL,
72 self_edit boolean DEFAULT false NOT NULL,
73 group_create boolean DEFAULT false NOT NULL,
74 group_edit boolean DEFAULT false NOT NULL,
75 group_delete boolean DEFAULT false NOT NULL,
76 user_create boolean DEFAULT false NOT NULL,
77 user_edit boolean DEFAULT false NOT NULL,
78 user_delete boolean DEFAULT false NOT NULL,
79 domain_create boolean DEFAULT false NOT NULL,
80 domain_edit boolean DEFAULT false NOT NULL,
81 domain_delete boolean DEFAULT false NOT NULL,
82 record_create boolean DEFAULT false NOT NULL,
83 record_edit boolean DEFAULT false NOT NULL,
84 record_delete boolean DEFAULT false NOT NULL,
85 user_id integer UNIQUE,
86 group_id integer UNIQUE
87);
88
89-- Need *two* basic permissions; one for the initial group, one for the default admin user
90COPY 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;
911 f f f f f f f f t t t t t t \N 1
922 t f f f f f f f f f f f f f 1 \N
93\.
94
95-- fixme: need to handle looooong records (eg, SPF)
96CREATE TABLE records (
97 domain_id integer NOT NULL,
98 record_id serial NOT NULL,
99 longrec_id integer,
100 host character varying(100) DEFAULT ''::character varying NOT NULL,
101 "type" integer DEFAULT 1 NOT NULL,
102 val character varying(100) DEFAULT ''::character varying NOT NULL,
103 distance integer DEFAULT 0 NOT NULL,
104 weight integer DEFAULT 0 NOT NULL,
105 port integer DEFAULT 0 NOT NULL,
106 ttl integer DEFAULT 7200 NOT NULL,
107 description character varying(255)
108);
109
110CREATE TABLE longrecs (
111 longrec_id serial NOT NULL,
112 recdata text
113);
114
115CREATE TABLE rectypes (
116 val integer NOT NULL,
117 name character varying(12) NOT NULL,
118 stdflag integer DEFAULT 1 NOT NULL,
119 listorder integer DEFAULT 255 NOT NULL
120);
121
122-- Types are required. NB: these are vaguely read-only too
123-- data from http://www.iana.org/assignments/dns-parameters
124COPY rectypes (val, name, stdflag, listorder) FROM stdin;
1251 A 1 1
1262 NS 1 2
1273 MD 2 255
1284 MF 2 255
1295 CNAME 1 6
1306 SOA 0 8
1317 MB 3 255
1328 MG 3 255
1339 MR 3 255
13410 NULL 3 255
13511 WKS 3 255
13612 PTR 2 4
13713 HINFO 3 255
13814 MINFO 3 255
13915 MX 1 3
14016 TXT 1 5
14117 RP 2 255
14218 AFSDB 3 255
14319 X25 3 255
14420 ISDN 3 255
14521 RT 3 255
14622 NSAP 3 255
14723 NSAP-PTR 3 255
14824 SIG 3 255
14925 KEY 3 255
15026 PX 3 255
15127 GPOS 3 255
15228 AAAA 2 2
15329 LOC 3 255
15430 NXT 3 255
15531 EID 3 255
15632 NIMLOC 3 255
15733 SRV 1 7
15834 ATMA 3 255
15935 NAPTR 3 255
16036 KX 3 255
16137 CERT 3 255
16238 A6 3 3
16339 DNAME 3 255
16440 SINK 3 255
16541 OPT 3 255
16642 APL 3 255
16743 DS 3 255
16844 SSHFP 3 255
16945 IPSECKEY 3 255
17046 RRSIG 3 255
17147 NSEC 3 255
17248 DNSKEY 3 255
17349 DHCID 3 255
17450 NSEC3 3 255
17551 NSEC3PARAM 3 255
17655 HIP 3 255
17799 SPF 3 255
178100 UINFO 3 255
179101 UID 3 255
180102 GID 3 255
181103 UNSPEC 3 255
182249 TKEY 3 255
183250 TSIG 3 255
184251 IXFR 3 255
185252 AXFR 3 255
186253 MAILB 3 255
187254 MAILA 3 255
18832768 TA 3 255
18932769 DLV 3 255
190\.
191
192CREATE TABLE users (
193 user_id serial NOT NULL,
194 group_id integer DEFAULT 1 NOT NULL,
195 username character varying(60) NOT NULL,
196 "password" character varying(34) NOT NULL,
197 firstname character varying(60),
198 lastname character varying(60),
199 phone character varying(15),
200 "type" character(1) DEFAULT 'S'::bpchar NOT NULL,
201 status integer DEFAULT 1 NOT NULL,
202 permission_id integer DEFAULT 1 NOT NULL,
203 inherit_perm boolean DEFAULT true NOT NULL
204);
205
206-- create initial default user? may be better to create an "initialize" script or something
207COPY users (user_id, group_id, username, "password", firstname, lastname, phone, "type", status, permission_id, inherit_perm) FROM stdin;
2081 1 admin $1$PfEBUv9d$wV2/UG4gmKk08DLmdE8/d. Initial User \N S 1 2 f
209\.
210
211--
212-- contraints. add these here so initial data doesn't get added strangely.
213--
214
215-- primary keys
216ALTER TABLE ONLY permissions
217 ADD CONSTRAINT permissions_permission_id_key UNIQUE (permission_id);
218
219ALTER TABLE ONLY groups
220 ADD CONSTRAINT groups_group_id_key UNIQUE (group_id);
221
222ALTER TABLE ONLY domains
223 ADD CONSTRAINT domains_pkey PRIMARY KEY ("domain");
224
225ALTER TABLE ONLY domains
226 ADD CONSTRAINT domains_domain_id_key UNIQUE (domain_id);
227
228ALTER TABLE ONLY default_records
229 ADD CONSTRAINT default_records_pkey PRIMARY KEY (record_id);
230
231ALTER TABLE ONLY records
232 ADD CONSTRAINT records_pkey PRIMARY KEY (record_id);
233
234ALTER TABLE ONLY rectypes
235 ADD CONSTRAINT rectypes_pkey PRIMARY KEY (val, name);
236
237ALTER TABLE ONLY users
238 ADD CONSTRAINT users_pkey PRIMARY KEY (username);
239
240ALTER TABLE ONLY users
241 ADD CONSTRAINT uidu UNIQUE (user_id);
242
243-- foreign keys
244-- fixme: permissions FK refs
245ALTER TABLE ONLY domains
246 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
247
248ALTER TABLE ONLY default_records
249 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
250
251ALTER TABLE ONLY records
252 ADD CONSTRAINT "$1" FOREIGN KEY (domain_id) REFERENCES domains(domain_id);
253
254ALTER TABLE ONLY users
255 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
256
257ALTER TABLE ONLY groups
258 ADD CONSTRAINT group_parent FOREIGN KEY (parent_group_id) REFERENCES groups(group_id);
259
260-- set starting sequence numbers, since we've inserted data before they're active
261SELECT pg_catalog.setval('default_records_record_id_seq', 8, true);
262SELECT pg_catalog.setval('domains_domain_id_seq', 1, false);
263SELECT pg_catalog.setval('groups_group_id_seq', 1, true);
264SELECT pg_catalog.setval('permissions_permission_id_seq', 2, true);
265SELECT pg_catalog.setval('records_record_id_seq', 1, false);
266SELECT pg_catalog.setval('users_user_id_seq', 2, false);
Note: See TracBrowser for help on using the repository browser.