source: trunk/cgi-bin/ipdb.psql@ 285

Last change on this file since 285 was 285, checked in by Kris Deugau, 19 years ago

/trunk help.html

Tweak up new search system to work properly - searchme view
was missing the 'notes' field.
Tweak quick search to search CustIDs for alphanumerics.

File size: 6.3 KB
Line 
1CREATE DATABASE ipdb;
2
3\connect ipdb ipdb
4
5CREATE TABLE "customers" (
6 "custid" character varying(16) DEFAULT '' NOT NULL,
7 "name" character varying(64),
8 "street" character varying(25),
9 "street2" character varying(25),
10 "city" character varying(30),
11 "province" character(2),
12 "pocode" character varying(7),
13 "phone" character varying(15),
14 "abuse" character varying(50),
15 "def_rdns" character varying(40),
16 "description" text,
17 Constraint "customers_pkey" Primary Key ("custid")
18);
19
20REVOKE ALL on "customers" from PUBLIC;
21GRANT ALL on "customers" to "kdeugau";
22GRANT ALL on "customers" to "ipdb";
23
24CREATE TABLE "masterblocks" (
25 "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
26 "ctime" timestamp DEFAULT now()
27);
28
29REVOKE ALL on "masterblocks" from PUBLIC;
30GRANT ALL on "masterblocks" to "kdeugau";
31GRANT ALL on "masterblocks" to "ipdb";
32
33CREATE TABLE "routed" (
34 "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
35 "maskbits" integer DEFAULT 128,
36 "city" character varying(30) DEFAULT '',
37 "ctime" timestamp DEFAULT now()
38);
39
40REVOKE ALL on "routed" from PUBLIC;
41GRANT ALL on "routed" to "kdeugau";
42GRANT ALL on "routed" to "ipdb";
43
44CREATE TABLE "temp" (
45 "ofs" integer
46);
47
48REVOKE ALL on "temp" from PUBLIC;
49GRANT ALL on "temp" to "kdeugau";
50GRANT ALL on "temp" to "ipdb";
51
52CREATE TABLE "freeblocks" (
53 "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
54 "maskbits" integer DEFAULT 128,
55 "city" character varying(30) DEFAULT '',
56 "routed" character(1) DEFAULT 'n'
57);
58
59REVOKE ALL on "freeblocks" from PUBLIC;
60GRANT ALL on "freeblocks" to "kdeugau";
61GRANT ALL on "freeblocks" to "ipdb";
62
63CREATE TABLE "poolips" (
64 "pool" cidr DEFAULT '255.255.255.255/32' NOT NULL,
65 "ip" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
66 "custid" character varying(16) DEFAULT '' NOT NULL,
67 "city" character varying(30) DEFAULT '' NOT NULL,
68 "type" character(2) DEFAULT '' NOT NULL,
69 "available" character(1) DEFAULT 'y' NOT NULL,
70 "notes" text DEFAULT '' NOT NULL,
71 "description" character varying(64) DEFAULT '' NOT NULL,
72 "circuitid" character varying(128) DEFAULT '' NOT NULL,
73 "privdata" text DEFAULT '' NOT NULL,
74 "newcustid" integer,
75 "createstamp" timestamp DEFAULT now(),
76 "modifystamp" timestamp DEFAULT now(),
77 CHECK (((available = 'y'::bpchar) OR (available = 'n'::bpchar)))
78);
79
80REVOKE ALL on "poolips" from PUBLIC;
81GRANT ALL on "poolips" to "kdeugau";
82GRANT ALL on "poolips" to "ipdb";
83
84CREATE TABLE "allocations" (
85 "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
86 "custid" character varying(16) DEFAULT '',
87 "type" character(2) DEFAULT '',
88 "city" character varying(30) DEFAULT '',
89 "description" character varying(64) DEFAULT '',
90 "notes" text DEFAULT '',
91 "maskbits" integer DEFAULT 128,
92 "circuitid" character varying(128) DEFAULT '',
93 "createstamp" timestamp DEFAULT now(),
94 "modifystamp" timestamp DEFAULT now(),
95 "privdata" text DEFAULT '' NOT NULL,
96 "newcustid" integer
97);
98
99REVOKE ALL on "allocations" from PUBLIC;
100GRANT ALL on "allocations" to "kdeugau";
101GRANT ALL on "allocations" to "ipdb";
102
103CREATE VIEW "searchme" as SELECT allocations.cidr, allocations.custid, allocations."type", allocations.city, allocations.description, allocations.notes FROM allocations UNION SELECT poolips.ip, poolips.custid, poolips.type, poolips.city, poolips.description, poolips.notes FROM poolips;
104
105REVOKE ALL on "searchme" from PUBLIC;
106GRANT ALL on "searchme" to "kdeugau";
107GRANT ALL on "searchme" to "ipdb";
108
109CREATE TABLE "alloctypes" (
110 "type" character(2) DEFAULT '' NOT NULL PRIMARY KEY,
111 "listname" character varying(40) DEFAULT '',
112 "dispname" character varying(40) DEFAULT '',
113 "listorder" integer DEFAULT 0,
114 "def_custid" character varying(16) DEFAULT ''
115);
116
117REVOKE ALL on "alloctypes" from PUBLIC;
118GRANT ALL on "alloctypes" to "kdeugau";
119GRANT ALL on "alloctypes" to "ipdb";
120
121CREATE TABLE "cities" (
122 "id" serial NOT NULL PRIMARY KEY,
123 "city" character varying(30) DEFAULT '' NOT NULL,
124 "routing" character(1) DEFAULT 'n' NOT NULL
125);
126
127REVOKE ALL on "cities" from PUBLIC;
128GRANT ALL on "cities" to "kdeugau";
129GRANT ALL on "cities" to "ipdb";
130
131CREATE TABLE "alloctypes" (
132 "type" character(2) DEFAULT '' NOT NULL,
133 "listname" character varying(40) DEFAULT '',
134 "dispname" character varying(40) DEFAULT '',
135 "listorder" integer DEFAULT 0,
136 "def_custid" character varying(16) DEFAULT '',
137 Constraint "alloctypes_pkey" Primary Key ("type")
138);
139
140REVOKE ALL on "alloctypes" from PUBLIC;
141GRANT ALL on "alloctypes" to "kdeugau";
142GRANT ALL on "alloctypes" to "ipdb";
143
144COPY "alloctypes" FROM stdin;
145cd Static Pool - Cable Cable pool 41 CBL-BUS
146dp Static Pool - DSL DSL pool 42 DSL-BUS
147mp Static Pool - Dialup Static dialup pool 43 DIAL-BUS
148wp Static Pool - Wireless Static wireless pool 44 WL-BUS
149mm Master block Master block 999 6750400
150in Internal netblock Internal netblock 990 6750400
151sd Static Pool - Servers Server pool 40 6750400
152cn Customer netblock Customer netblock 0
153ci Static IP - Cable Static cable IP 21
154di Static IP - DSL Static DSL IP 22
155mi Static IP - Dialup Static dialup IP 23
156wi Static IP - Wireless Static wireless IP 24
157si Static IP - Server pool Server pool IP 20 6750400
158wc Reserve for WAN blocks WAN IP blocks 200 6750400
159en End-use netblock End-use netblock 100 6750400
160me Dialup netblock Dialup netblock 101 DIAL-RES
161de Dynamic DSL block Dynamic DSL block 102 DSL-RES
162ce Dynamic cable block Dynamic cable block 103 CBL-RES
163we Dynamic WiFi block Dynamic WiFi block 104 WL-RES
164rm Routing Routed netblock 500 6750400
165pc Reserve for dynamic-route DSL netblocks Dynamic-route netblocks 201 6750400
166pr Dynamic-route DSL netblock Dynamic-route DSL 221
167wr WAN block WAN block 220 6750400
168\.
169
170--
171-- Trigger and matching function to update modifystamp on allocations, poolips
172--
173CREATE FUNCTION up_modtime () RETURNS OPAQUE AS '
174 BEGIN
175 NEW.modifystamp := ''now'';
176 RETURN NEW;
177 END;
178' LANGUAGE 'plpgsql';
179
180CREATE TRIGGER up_modtime BEFORE UPDATE ON allocations
181 FOR EACH ROW EXECUTE PROCEDURE up_modtime();
182
183CREATE TRIGGER up_modtime BEFORE UPDATE ON poolips
184 FOR EACH ROW EXECUTE PROCEDURE up_modtime();
185
186--
187-- User data table - required for proper ACLs
188--
189
190CREATE TABLE "users" (
191 "username" varchar(16) NOT NULL PRIMARY KEY,
192 "password" varchar(16) DEFAULT '',
193 "acl" varchar(16) DEFAULT 'b'
194);
195
196CREATE TABLE "dns" (
197 "ip" inet NOT NULL PRIMARY KEY,
198 "hostname" character varying(128),
199 "auto" character(1) DEFAULT 'y'
200);
Note: See TracBrowser for help on using the repository browser.