source: branches/stable/cgi-bin/ipdb.psql@ 509

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

/branches/stable

Make the fixed web path at least configurable in one place rather
than completely hardcoded across many files.
Update initial database tabledef SQL
Bump version

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