source: trunk/cgi-bin/ipdb-2.7.psql@ 867

Last change on this file since 867 was 755, checked in by Kris Deugau, 9 years ago

/trunk

Add separate reference copy of ipdb.psql with version indicator for
old DB schema

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