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

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

/trunk

Updated SQL tabledefs with timestamps for master block, routed

block, allocation, and static IP "creation" times; also
allocation and static IP modification times.

Updated db2rwhois.pl with timestamp support and a little code cleanup.

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