1 | DROP DATABASE ipdb; |
---|
2 | |
---|
3 | CREATE USER ipdb WITH PASSWORD 'ipdbpwd'; |
---|
4 | |
---|
5 | CREATE DATABASE ipdb; |
---|
6 | |
---|
7 | -- Need to do this or our triggers don't work. Why do we need to do this? |
---|
8 | CREATE FUNCTION "plpgsql_call_handler" () RETURNS language_handler AS '$libdir/plpgsql' LANGUAGE C; |
---|
9 | CREATE TRUSTED LANGUAGE "plpgsql" HANDLER "plpgsql_call_handler"; |
---|
10 | |
---|
11 | UPDATE pg_database SET datdba=(SELECT usesysid FROM pg_shadow WHERE usename='ipdb') |
---|
12 | WHERE datname='ipdb'; |
---|
13 | |
---|
14 | \connect ipdb ipdb |
---|
15 | |
---|
16 | CREATE TABLE "customers" ( |
---|
17 | "custid" character varying(16) DEFAULT '' NOT NULL, |
---|
18 | "name" character varying(64), |
---|
19 | "street" character varying(25), |
---|
20 | "street2" character varying(25), |
---|
21 | "city" character varying(30), |
---|
22 | "province" character(2), |
---|
23 | "country" character(2), |
---|
24 | "pocode" character varying(7), |
---|
25 | "phone" character varying(15), |
---|
26 | "tech_handle" character varying(50), |
---|
27 | "abuse_handle" character varying(50), |
---|
28 | "admin_handle" character varying(50), |
---|
29 | "def_rdns" character varying(40), |
---|
30 | "special" text, |
---|
31 | Constraint "customers_pkey" Primary Key ("custid") |
---|
32 | ); |
---|
33 | |
---|
34 | REVOKE ALL on "customers" from PUBLIC; |
---|
35 | GRANT ALL on "customers" to "ipdb"; |
---|
36 | |
---|
37 | CREATE TABLE "masterblocks" ( |
---|
38 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY, |
---|
39 | "ctime" timestamp DEFAULT now(), |
---|
40 | "mtime" timestamp DEFAULT now(), |
---|
41 | "rwhois" character(1) DEFAULT 'n' NOT NULL |
---|
42 | ); |
---|
43 | |
---|
44 | REVOKE ALL on "masterblocks" from PUBLIC; |
---|
45 | GRANT ALL on "masterblocks" to "ipdb"; |
---|
46 | |
---|
47 | CREATE TABLE "routed" ( |
---|
48 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY, |
---|
49 | "maskbits" integer DEFAULT 128, |
---|
50 | "city" character varying(30) DEFAULT '', |
---|
51 | "ctime" timestamp DEFAULT now() |
---|
52 | ); |
---|
53 | |
---|
54 | REVOKE ALL on "routed" from PUBLIC; |
---|
55 | GRANT ALL on "routed" to "ipdb"; |
---|
56 | GRANT SELECT on "routed" to "ipdb"; |
---|
57 | |
---|
58 | CREATE TABLE "temp" ( |
---|
59 | "ofs" integer |
---|
60 | ); |
---|
61 | |
---|
62 | REVOKE ALL on "temp" from PUBLIC; |
---|
63 | GRANT ALL on "temp" to "ipdb"; |
---|
64 | |
---|
65 | CREATE TABLE "freeblocks" ( |
---|
66 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY, |
---|
67 | "maskbits" integer DEFAULT 128, |
---|
68 | "city" character varying(30) DEFAULT '', |
---|
69 | "routed" character(1) DEFAULT 'n' |
---|
70 | ); |
---|
71 | |
---|
72 | REVOKE ALL on "freeblocks" from PUBLIC; |
---|
73 | GRANT ALL on "freeblocks" to "ipdb"; |
---|
74 | |
---|
75 | CREATE TABLE "poolips" ( |
---|
76 | "pool" cidr DEFAULT '255.255.255.255/32' NOT NULL, |
---|
77 | "ip" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY, |
---|
78 | "oldcustid" character varying(16) DEFAULT '' NOT NULL, |
---|
79 | "city" character varying(30) DEFAULT '' NOT NULL, |
---|
80 | "type" character(2) DEFAULT '' NOT NULL, |
---|
81 | "available" character(1) DEFAULT 'y' NOT NULL, |
---|
82 | "notes" text DEFAULT '' NOT NULL, |
---|
83 | "description" character varying(64) DEFAULT '' NOT NULL, |
---|
84 | "circuitid" character varying(128) DEFAULT '' NOT NULL, |
---|
85 | "privdata" text DEFAULT '' NOT NULL, |
---|
86 | "custid" character varying(16) DEFAULT '', |
---|
87 | "createstamp" timestamp DEFAULT now(), |
---|
88 | "modifystamp" timestamp DEFAULT now(), |
---|
89 | CHECK (((available = 'y'::bpchar) OR (available = 'n'::bpchar))) |
---|
90 | ); |
---|
91 | |
---|
92 | REVOKE ALL on "poolips" from PUBLIC; |
---|
93 | GRANT ALL on "poolips" to "ipdb"; |
---|
94 | |
---|
95 | CREATE TABLE "allocations" ( |
---|
96 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY, |
---|
97 | "oldcustid" character varying(16) DEFAULT '', |
---|
98 | "type" character(2) DEFAULT '', |
---|
99 | "city" character varying(30) DEFAULT '', |
---|
100 | "description" character varying(64) DEFAULT '', |
---|
101 | "notes" text DEFAULT '', |
---|
102 | "maskbits" integer DEFAULT 128, |
---|
103 | "circuitid" character varying(128) DEFAULT '', |
---|
104 | "createstamp" timestamp DEFAULT now(), |
---|
105 | "modifystamp" timestamp DEFAULT now(), |
---|
106 | "privdata" text DEFAULT '' NOT NULL, |
---|
107 | "custid" character varying(16) DEFAULT '', |
---|
108 | swip character(1) DEFAULT 'n' |
---|
109 | ); |
---|
110 | |
---|
111 | REVOKE ALL on "allocations" from PUBLIC; |
---|
112 | GRANT ALL on "allocations" to "ipdb"; |
---|
113 | |
---|
114 | CREATE VIEW "searchme" as SELECT allocations.cidr, allocations.custid, allocations."type", allocations.city, allocations.description, allocations.notes, allocations.oldcustid, allocations.circuitid FROM allocations UNION SELECT poolips.ip, poolips.custid, poolips.type, poolips.city, poolips.description, poolips.notes, poolips.oldcustid, poolips.circuitid FROM poolips; |
---|
115 | |
---|
116 | REVOKE ALL on "searchme" from PUBLIC; |
---|
117 | GRANT ALL on "searchme" to "ipdb"; |
---|
118 | |
---|
119 | CREATE TABLE "alloctypes" ( |
---|
120 | "type" character(2) DEFAULT '' NOT NULL PRIMARY KEY, |
---|
121 | "listname" character varying(40) DEFAULT '', |
---|
122 | "dispname" character varying(40) DEFAULT '', |
---|
123 | "listorder" integer DEFAULT 0, |
---|
124 | "def_custid" character varying(16) DEFAULT '', |
---|
125 | "arin_netname" character varying(20) DEFAULT 'ISP' |
---|
126 | ); |
---|
127 | |
---|
128 | -- |
---|
129 | -- Name: alloctypes; Type: TABLE DATA; Schema: public; Owner: ipdb |
---|
130 | -- |
---|
131 | |
---|
132 | COPY alloctypes ("type", listname, dispname, listorder, def_custid, arin_netname) FROM stdin; |
---|
133 | cn Customer netblock Customer netblock 0 ISPCUST |
---|
134 | si Static IP - Server pool Server pool IP 20 ISP |
---|
135 | ci Static IP - Cable Static cable IP 21 ISP |
---|
136 | di Static IP - DSL Static DSL IP 22 ISP |
---|
137 | mi Static IP - Dialup Static dialup IP 23 ISP |
---|
138 | wi Static IP - Wireless Static wireless IP 24 ISP |
---|
139 | sd Static Pool - Servers Server pool 40 6750400 ISP |
---|
140 | cd Static Pool - Cable Cable pool 41 CBL-BUS ISP-STATIC-CABLE |
---|
141 | dp Static Pool - DSL DSL pool 42 DSL-BUS ISP-STATIC-DSL |
---|
142 | mp Static Pool - Dialup Static dialup pool 43 DIAL-BUS ISP-STATIC-DIAL |
---|
143 | wp Static Pool - Wireless Static wireless pool 44 WL-BUS ISP-STATIC-WIFI |
---|
144 | en End-use netblock End-use netblock 100 6750400 ISP |
---|
145 | me Dialup netblock Dialup netblock 101 DIAL-RES ISP-DIAL |
---|
146 | de Dynamic DSL block Dynamic DSL block 102 DSL-RES ISP-DSL |
---|
147 | ce Dynamic cable block Dynamic cable block 103 CBL-RES ISP-CABLE |
---|
148 | we Dynamic WiFi block Dynamic WiFi block 104 WL-RES ISP-WIFI |
---|
149 | ve Dynamic VoIP block Dynamic VoIP block 105 DYN-VOIP ISP |
---|
150 | li Static IP - LAN/POP Static LAN/POP IP 190 NOC-VPN ISP |
---|
151 | ai Static IP - Managment Static management IP 192 NOC-VPN ISP |
---|
152 | bi Static IP - Wifi CPE Wifi CPE IP 193 ISP |
---|
153 | ld Static Pool - LAN/POP LAN pool 195 NOC-VPN ISP |
---|
154 | ad Static Pool - Managment Management pool 196 NOC-VPN ISP |
---|
155 | bd Static pool - Wifi CPE Wifi CPE pool 197 ISP |
---|
156 | in Internal netblock Internal netblock 199 6750400 ISP |
---|
157 | wc Reserve for CORE/WAN blocks CORE/WAN blocks 200 6750400 ISP |
---|
158 | pc Reserve for dynamic-route DSL netblocks Dynamic-route netblocks 201 6750400 ISP-STATIC-DSL |
---|
159 | ac Reserve for ATM ATM blocks 202 6750400 ISP |
---|
160 | fc Reserve for fibre Fibre blocks 203 6750400 ISP |
---|
161 | wr CORE/WAN block CORE/WAN block 220 6750400 ISP |
---|
162 | pr Dynamic-route DSL netblock (cust) Dynamic-route DSL (cust) 221 ISPCUST |
---|
163 | ar ATM block ATM block 222 ISP |
---|
164 | fr Fibre Fibre 223 ISP |
---|
165 | rm Routing Routed netblock 500 6750400 ISP |
---|
166 | mm Master block Master block 999 6750400 ISP |
---|
167 | \. |
---|
168 | |
---|
169 | REVOKE ALL on "alloctypes" from PUBLIC; |
---|
170 | GRANT ALL on "alloctypes" to "ipdb"; |
---|
171 | |
---|
172 | CREATE TABLE "cities" ( |
---|
173 | "id" serial NOT NULL PRIMARY KEY, |
---|
174 | "city" character varying(30) DEFAULT '' NOT NULL, |
---|
175 | "routing" character(1) DEFAULT 'n' NOT NULL |
---|
176 | ); |
---|
177 | |
---|
178 | REVOKE ALL on "cities" from PUBLIC; |
---|
179 | GRANT ALL on "cities" to "ipdb"; |
---|
180 | |
---|
181 | -- |
---|
182 | -- Trigger and matching function to update modifystamp on allocations, poolips |
---|
183 | -- |
---|
184 | CREATE FUNCTION up_modtime () RETURNS OPAQUE AS ' |
---|
185 | BEGIN |
---|
186 | NEW.modifystamp := ''now''; |
---|
187 | RETURN NEW; |
---|
188 | END; |
---|
189 | ' LANGUAGE 'plpgsql'; |
---|
190 | |
---|
191 | CREATE TRIGGER up_modtime BEFORE UPDATE ON allocations |
---|
192 | FOR EACH ROW EXECUTE PROCEDURE up_modtime(); |
---|
193 | |
---|
194 | CREATE TRIGGER up_modtime BEFORE UPDATE ON poolips |
---|
195 | FOR EACH ROW EXECUTE PROCEDURE up_modtime(); |
---|
196 | |
---|
197 | -- |
---|
198 | -- User data table - required for proper ACLs |
---|
199 | -- |
---|
200 | |
---|
201 | CREATE TABLE "users" ( |
---|
202 | "username" varchar(16) NOT NULL PRIMARY KEY, |
---|
203 | "password" varchar(16) DEFAULT '', |
---|
204 | "acl" varchar(16) DEFAULT 'b' |
---|
205 | ); |
---|
206 | |
---|
207 | -- Default password is admin |
---|
208 | INSERT INTO users VALUES ('admin','luef5C4XumqIs','bacdsA'); |
---|
209 | |
---|
210 | CREATE TABLE "dns" ( |
---|
211 | "ip" inet NOT NULL PRIMARY KEY, |
---|
212 | "hostname" character varying(128), |
---|
213 | "auto" character(1) DEFAULT 'y' |
---|
214 | ); |
---|
215 | |
---|
216 | -- Network nodes - allows finding customers affected by a broken <x> quickly |
---|
217 | CREATE TABLE noderef ( |
---|
218 | block inet NOT NULL PRIMARY KEY, |
---|
219 | node_id integer |
---|
220 | ); |
---|
221 | |
---|
222 | CREATE TABLE nodes ( |
---|
223 | node_id serial NOT NULL PRIMARY KEY, |
---|
224 | node_type character varying(2), |
---|
225 | node_name character varying(40), |
---|
226 | node_ip inet |
---|
227 | ); |
---|