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

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

/trunk

Bugfix in tabledef for users table (required for ACLs)

  • user is apparently a reserved word for Postgres
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 "newcustid" integer,
74 "createstamp" timestamp DEFAULT now(),
75 "modifystamp" timestamp DEFAULT now(),
76 CHECK (((available = 'y'::bpchar) OR (available = 'n'::bpchar)))
77);
78
79REVOKE ALL on "poolips" from PUBLIC;
80GRANT ALL on "poolips" to "kdeugau";
81GRANT ALL on "poolips" to "ipdb";
82
83CREATE TABLE "allocations" (
84 "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
85 "custid" character varying(16) DEFAULT '',
86 "type" character(2) DEFAULT '',
87 "city" character varying(30) DEFAULT '',
88 "description" character varying(64) DEFAULT '',
89 "notes" text DEFAULT '',
90 "maskbits" integer DEFAULT 128,
91 "circuitid" character varying(128) DEFAULT '',
92 "createstamp" timestamp DEFAULT now(),
93 "modifystamp" timestamp DEFAULT now(),
94 "newcustid" integer
95);
96
97REVOKE ALL on "allocations" from PUBLIC;
98GRANT ALL on "allocations" to "kdeugau";
99GRANT ALL on "allocations" to "ipdb";
100
101CREATE 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;
102
103REVOKE ALL on "searchme" from PUBLIC;
104GRANT ALL on "searchme" to "kdeugau";
105GRANT ALL on "searchme" to "ipdb";
106
107CREATE TABLE "alloctypes" (
108 "type" character(2) DEFAULT '' NOT NULL PRIMARY KEY,
109 "listname" character varying(40) DEFAULT '',
110 "dispname" character varying(40) DEFAULT '',
111 "listorder" integer DEFAULT 0,
112 "def_custid" character varying(16) DEFAULT ''
113);
114
115REVOKE ALL on "alloctypes" from PUBLIC;
116GRANT ALL on "alloctypes" to "kdeugau";
117GRANT ALL on "alloctypes" to "ipdb";
118
119CREATE TABLE "cities" (
120 "city" character varying(30) DEFAULT '' NOT NULL PRIMARY KEY,
121 "routing" character(1) DEFAULT 'n' NOT NULL
122);
123
124REVOKE ALL on "cities" from PUBLIC;
125GRANT ALL on "cities" to "kdeugau";
126GRANT ALL on "cities" to "ipdb";
127
128--
129-- Selected TOC Entries:
130--
131\connect - ipdb
132
133--
134-- TOC Entry ID 2 (OID 92809)
135--
136-- Name: alloctypes Type: TABLE Owner: ipdb
137--
138
139CREATE TABLE "alloctypes" (
140 "type" character(2) DEFAULT '' NOT NULL,
141 "listname" character varying(40) DEFAULT '',
142 "dispname" character varying(40) DEFAULT '',
143 "listorder" integer DEFAULT 0,
144 "def_custid" character varying(16) DEFAULT '',
145 Constraint "alloctypes_pkey" Primary Key ("type")
146);
147
148--
149-- TOC Entry ID 3 (OID 92809)
150--
151-- Name: alloctypes Type: ACL Owner:
152--
153
154REVOKE ALL on "alloctypes" from PUBLIC;
155GRANT ALL on "alloctypes" to "kdeugau";
156GRANT ALL on "alloctypes" to "ipdb";
157
158--
159-- Data for TOC Entry ID 4 (OID 92809)
160--
161-- Name: alloctypes Type: TABLE DATA Owner: ipdb
162--
163
164
165COPY "alloctypes" FROM stdin;
166cd Static Pool - Cable Cable pool 41 CBL-BUS
167dp Static Pool - DSL DSL pool 42 DSL-BUS
168mp Static Pool - Dialup Static dialup pool 43 DIAL-BUS
169wp Static Pool - Wireless Static wireless pool 44 WL-BUS
170mm Master block Master block 999 6750400
171in Internal netblock Internal netblock 990 6750400
172sd Static Pool - Servers Server pool 40 6750400
173cn Customer netblock Customer netblock 0
174ci Static IP - Cable Static cable IP 21
175di Static IP - DSL Static DSL IP 22
176mi Static IP - Dialup Static dialup IP 23
177wi Static IP - Wireless Static wireless IP 24
178si Static IP - Server pool Server pool IP 20 6750400
179wc Reserve for WAN blocks WAN IP blocks 200 6750400
180wr Internal WAN block Internal WAN block 201 6750400
181pc Reserve for dynamic-route DSL netblocks Dynamic-route netblocks 202 6750400
182en End-use netblock End-use netblock 100 6750400
183me Dialup netblock Dialup netblock 101 DIAL-RES
184de Dynamic DSL block Dynamic DSL block 102 DSL-RES
185ce Dynamic cable block Dynamic cable block 103 CBL-RES
186we Dynamic WiFi block Dynamic WiFi block 104 WL-RES
187rm Routing Routed netblock 500 6750400
188pr Dynamic-route DSL netblock Dynamic-route DSL 203
189\.
190
191--
192-- Trigger and matching function to update modifystamp on allocations, poolips
193--
194CREATE FUNCTION up_modtime () RETURNS OPAQUE AS '
195 BEGIN
196 NEW.modifystamp := ''now'';
197 RETURN NEW;
198 END;
199' LANGUAGE 'plpgsql';
200
201CREATE TRIGGER up_modtime BEFORE UPDATE ON allocations
202 FOR EACH ROW EXECUTE PROCEDURE up_modtime();
203
204CREATE TRIGGER up_modtime BEFORE UPDATE ON poolips
205 FOR EACH ROW EXECUTE PROCEDURE up_modtime();
206
207--
208-- User data table - required for proper ACLs
209--
210
211CREATE TABLE "users" (
212 "username" varchar(16) NOT NULL PRIMARY KEY,
213 "password" varchar(16) DEFAULT '',
214 "acl" varchar(16) DEFAULT 'b'
215);
Note: See TracBrowser for help on using the repository browser.