source: trunk/dns.sql@ 89

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

/trunk

SQL tabledef updates:

  • references and definition for longrecs table to contain data for records that need >100 chars
  • Basic initial group permissions switched to include domain and record add/delete/update
  • Initial admin user created with a somewhat better username, and first/last name filled in
File size: 7.9 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
8CREATE TABLE default_records (
9 record_id serial NOT NULL,
[89]10 longrec_id integer,
[50]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
[85]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
[86]52COPY groups (group_id, parent_group_id, permission_id, group_name) FROM stdin;
[85]531 1 1 default
54\.
55
56CREATE TABLE log (
[89]57 log_id serial NOT NULL,
[85]58 domain_id integer,
59 user_id integer,
60 group_id integer,
61 email character varying(60),
62 name character varying(60),
63 entry character varying(200),
64 stamp timestamp with time zone DEFAULT now()
65);
66
67CREATE TABLE permissions (
68 permission_id serial NOT NULL,
69 "admin" boolean DEFAULT false NOT NULL,
70 self_edit boolean DEFAULT false NOT NULL,
71 group_create boolean DEFAULT false NOT NULL,
72 group_edit boolean DEFAULT false NOT NULL,
73 group_delete boolean DEFAULT false NOT NULL,
74 user_create boolean DEFAULT false NOT NULL,
75 user_edit boolean DEFAULT false NOT NULL,
76 user_delete boolean DEFAULT false NOT NULL,
77 domain_create boolean DEFAULT false NOT NULL,
78 domain_edit boolean DEFAULT false NOT NULL,
79 domain_delete boolean DEFAULT false NOT NULL,
80 record_create boolean DEFAULT false NOT NULL,
81 record_edit boolean DEFAULT false NOT NULL,
82 record_delete boolean DEFAULT false NOT NULL,
[86]83 user_id integer UNIQUE,
84 group_id integer UNIQUE
[85]85);
86
87-- Need *two* basic permissions; one for the initial group, one for the default admin user
[86]88COPY 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]891 f f f f f f f f t t t t t t \N 1
[86]902 t f f f f f f f f f f f f f 1 \N
[85]91\.
92
[89]93-- fixme: need to handle looooong records (eg, SPF)
[50]94CREATE TABLE records (
95 domain_id integer NOT NULL,
96 record_id serial NOT NULL,
[89]97 longrec_id integer,
[50]98 host character varying(100) DEFAULT ''::character varying NOT NULL,
99 "type" integer DEFAULT 1 NOT NULL,
100 val character varying(100) DEFAULT ''::character varying NOT NULL,
101 distance integer DEFAULT 0 NOT NULL,
102 weight integer DEFAULT 0 NOT NULL,
103 port integer DEFAULT 0 NOT NULL,
[85]104 ttl integer DEFAULT 7200 NOT NULL,
[50]105 description character varying(255)
106);
107
[89]108CREATE TABLE longrecs (
109 longrec_id serial NOT NULL,
110 recdata text
111);
112
[50]113CREATE TABLE rectypes (
114 val integer NOT NULL,
115 name character varying(12) NOT NULL,
116 stdflag integer DEFAULT 1 NOT NULL,
117 listorder integer DEFAULT 255 NOT NULL
118);
119
120-- Types are required. NB: these are vaguely read-only too
[85]121-- data from http://www.iana.org/assignments/dns-parameters
[50]122COPY rectypes (val, name, stdflag, listorder) FROM stdin;
1231 A 1 1
1242 NS 1 2
1253 MD 2 255
1264 MF 2 255
1275 CNAME 1 6
1286 SOA 0 8
1297 MB 3 255
1308 MG 3 255
1319 MR 3 255
13210 NULL 3 255
13311 WKS 3 255
13412 PTR 2 4
13513 HINFO 3 255
13614 MINFO 3 255
13715 MX 1 3
13816 TXT 1 5
13917 RP 2 255
14018 AFSDB 3 255
14119 X25 3 255
14220 ISDN 3 255
14321 RT 3 255
14422 NSAP 3 255
14523 NSAP-PTR 3 255
14624 SIG 3 255
14725 KEY 3 255
14826 PX 3 255
14927 GPOS 3 255
15028 AAAA 2 2
15129 LOC 3 255
15230 NXT 3 255
15331 EID 3 255
15432 NIMLOC 3 255
15533 SRV 1 7
15634 ATMA 3 255
15735 NAPTR 3 255
15836 KX 3 255
15937 CERT 3 255
16038 A6 3 3
16139 DNAME 3 255
16240 SINK 3 255
16341 OPT 3 255
16442 APL 3 255
16543 DS 3 255
16644 SSHFP 3 255
16745 IPSECKEY 3 255
16846 RRSIG 3 255
16947 NSEC 3 255
17048 DNSKEY 3 255
17149 DHCID 3 255
17250 NSEC3 3 255
17351 NSEC3PARAM 3 255
17455 HIP 3 255
17599 SPF 3 255
176100 UINFO 3 255
177101 UID 3 255
178102 GID 3 255
179103 UNSPEC 3 255
180249 TKEY 3 255
181250 TSIG 3 255
182251 IXFR 3 255
183252 AXFR 3 255
184253 MAILB 3 255
185254 MAILA 3 255
18632768 TA 3 255
18732769 DLV 3 255
188\.
189
190CREATE TABLE users (
191 user_id serial NOT NULL,
192 group_id integer DEFAULT 1 NOT NULL,
193 username character varying(60) NOT NULL,
194 "password" character varying(34) NOT NULL,
[85]195 firstname character varying(60),
196 lastname character varying(60),
[50]197 phone character varying(15),
198 "type" character(1) DEFAULT 'S'::bpchar NOT NULL,
199 status integer DEFAULT 1 NOT NULL,
[85]200 permission_id integer DEFAULT 1 NOT NULL,
201 inherit_perm boolean DEFAULT true NOT NULL
[50]202);
203
204-- create initial default user? may be better to create an "initialize" script or something
[86]205COPY users (user_id, group_id, username, "password", firstname, lastname, phone, "type", status, permission_id, inherit_perm) FROM stdin;
[89]2061 1 admin $1$PfEBUv9d$wV2/UG4gmKk08DLmdE8/d. Initial User \N S 1 2 f
[50]207\.
208
209--
210-- contraints. add these here so initial data doesn't get added strangely.
211--
212
213-- primary keys
[65]214ALTER TABLE ONLY permissions
215 ADD CONSTRAINT permissions_permission_id_key UNIQUE (permission_id);
216
[50]217ALTER TABLE ONLY groups
218 ADD CONSTRAINT groups_group_id_key UNIQUE (group_id);
219
220ALTER TABLE ONLY domains
221 ADD CONSTRAINT domains_pkey PRIMARY KEY ("domain");
222
223ALTER TABLE ONLY domains
224 ADD CONSTRAINT domains_domain_id_key UNIQUE (domain_id);
225
226ALTER TABLE ONLY default_records
227 ADD CONSTRAINT default_records_pkey PRIMARY KEY (record_id);
228
229ALTER TABLE ONLY records
230 ADD CONSTRAINT records_pkey PRIMARY KEY (record_id);
231
232ALTER TABLE ONLY rectypes
233 ADD CONSTRAINT rectypes_pkey PRIMARY KEY (val, name);
234
235ALTER TABLE ONLY users
236 ADD CONSTRAINT users_pkey PRIMARY KEY (username);
237
238ALTER TABLE ONLY users
239 ADD CONSTRAINT uidu UNIQUE (user_id);
240
241-- foreign keys
[65]242-- fixme: permissions FK refs
[50]243ALTER TABLE ONLY domains
244 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
245
246ALTER TABLE ONLY default_records
247 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
248
249ALTER TABLE ONLY records
250 ADD CONSTRAINT "$1" FOREIGN KEY (domain_id) REFERENCES domains(domain_id);
251
252ALTER TABLE ONLY users
253 ADD CONSTRAINT "$1" FOREIGN KEY (group_id) REFERENCES groups(group_id);
254
255ALTER TABLE ONLY groups
256 ADD CONSTRAINT group_parent FOREIGN KEY (parent_group_id) REFERENCES groups(group_id);
[86]257
258-- set starting sequence numbers, since we've inserted data before they're active
259SELECT pg_catalog.setval('default_records_record_id_seq', 8, true);
260SELECT pg_catalog.setval('domains_domain_id_seq', 1, false);
[87]261SELECT pg_catalog.setval('groups_group_id_seq', 1, true);
262SELECT pg_catalog.setval('permissions_permission_id_seq', 2, true);
[86]263SELECT pg_catalog.setval('records_record_id_seq', 1, false);
264SELECT pg_catalog.setval('users_user_id_seq', 2, false);
Note: See TracBrowser for help on using the repository browser.