[181] | 1 | CREATE DATABASE ipdb;
|
---|
[4] | 2 |
|
---|
[176] | 3 | \connect ipdb ipdb
|
---|
[4] | 4 |
|
---|
| 5 | CREATE 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),
|
---|
[324] | 12 | "country" character(2),
|
---|
[4] | 13 | "pocode" character varying(7),
|
---|
| 14 | "phone" character varying(15),
|
---|
[324] | 15 | "tech_handle" character varying(50),
|
---|
| 16 | "abuse_handle" character varying(50),
|
---|
| 17 | "admin_handle" character varying(50),
|
---|
[4] | 18 | "def_rdns" character varying(40),
|
---|
[324] | 19 | "special" text,
|
---|
[4] | 20 | Constraint "customers_pkey" Primary Key ("custid")
|
---|
| 21 | );
|
---|
| 22 |
|
---|
[34] | 23 | REVOKE ALL on "customers" from PUBLIC;
|
---|
| 24 | GRANT ALL on "customers" to "ipdb";
|
---|
| 25 |
|
---|
[4] | 26 | CREATE TABLE "masterblocks" (
|
---|
[219] | 27 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
|
---|
[324] | 28 | "ctime" timestamp DEFAULT now(),
|
---|
| 29 | "mtime" timestamp DEFAULT now()
|
---|
[4] | 30 | );
|
---|
| 31 |
|
---|
[34] | 32 | REVOKE ALL on "masterblocks" from PUBLIC;
|
---|
| 33 | GRANT ALL on "masterblocks" to "ipdb";
|
---|
| 34 |
|
---|
[4] | 35 | CREATE TABLE "routed" (
|
---|
[176] | 36 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
|
---|
[4] | 37 | "maskbits" integer DEFAULT 128,
|
---|
[219] | 38 | "city" character varying(30) DEFAULT '',
|
---|
| 39 | "ctime" timestamp DEFAULT now()
|
---|
[4] | 40 | );
|
---|
| 41 |
|
---|
[34] | 42 | REVOKE ALL on "routed" from PUBLIC;
|
---|
| 43 | GRANT ALL on "routed" to "ipdb";
|
---|
[316] | 44 | GRANT SELECT on "routed" to "ipdb";
|
---|
[34] | 45 |
|
---|
[4] | 46 | CREATE TABLE "temp" (
|
---|
| 47 | "ofs" integer
|
---|
| 48 | );
|
---|
| 49 |
|
---|
[34] | 50 | REVOKE ALL on "temp" from PUBLIC;
|
---|
| 51 | GRANT ALL on "temp" to "ipdb";
|
---|
| 52 |
|
---|
[57] | 53 | CREATE TABLE "freeblocks" (
|
---|
[180] | 54 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
|
---|
[57] | 55 | "maskbits" integer DEFAULT 128,
|
---|
| 56 | "city" character varying(30) DEFAULT '',
|
---|
[176] | 57 | "routed" character(1) DEFAULT 'n'
|
---|
[34] | 58 | );
|
---|
| 59 |
|
---|
[57] | 60 | REVOKE ALL on "freeblocks" from PUBLIC;
|
---|
| 61 | GRANT ALL on "freeblocks" to "ipdb";
|
---|
[34] | 62 |
|
---|
[74] | 63 | CREATE TABLE "poolips" (
|
---|
| 64 | "pool" cidr DEFAULT '255.255.255.255/32' NOT NULL,
|
---|
[176] | 65 | "ip" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
|
---|
[74] | 66 | "custid" character varying(16) DEFAULT '' NOT NULL,
|
---|
[175] | 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,
|
---|
[284] | 73 | "privdata" text DEFAULT '' NOT NULL,
|
---|
[316] | 74 | "newcustid" character varying(16) DEFAULT '',
|
---|
[218] | 75 | "createstamp" timestamp DEFAULT now(),
|
---|
| 76 | "modifystamp" timestamp DEFAULT now(),
|
---|
[176] | 77 | CHECK (((available = 'y'::bpchar) OR (available = 'n'::bpchar)))
|
---|
[74] | 78 | );
|
---|
| 79 |
|
---|
| 80 | REVOKE ALL on "poolips" from PUBLIC;
|
---|
| 81 | GRANT ALL on "poolips" to "ipdb";
|
---|
| 82 |
|
---|
| 83 | CREATE TABLE "allocations" (
|
---|
[176] | 84 | "cidr" cidr DEFAULT '255.255.255.255/32' NOT NULL PRIMARY KEY,
|
---|
[74] | 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 '',
|
---|
[218] | 92 | "createstamp" timestamp DEFAULT now(),
|
---|
| 93 | "modifystamp" timestamp DEFAULT now(),
|
---|
[284] | 94 | "privdata" text DEFAULT '' NOT NULL,
|
---|
[316] | 95 | "newcustid" character varying(16) DEFAULT '',
|
---|
| 96 | swip character(1) DEFAULT 'n'
|
---|
[74] | 97 | );
|
---|
| 98 |
|
---|
| 99 | REVOKE ALL on "allocations" from PUBLIC;
|
---|
| 100 | GRANT ALL on "allocations" to "ipdb";
|
---|
| 101 |
|
---|
[285] | 102 | CREATE 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;
|
---|
[92] | 103 |
|
---|
[176] | 104 | REVOKE ALL on "searchme" from PUBLIC;
|
---|
| 105 | GRANT ALL on "searchme" to "ipdb";
|
---|
| 106 |
|
---|
[92] | 107 | CREATE TABLE "alloctypes" (
|
---|
[176] | 108 | "type" character(2) DEFAULT '' NOT NULL PRIMARY KEY,
|
---|
[92] | 109 | "listname" character varying(40) DEFAULT '',
|
---|
| 110 | "dispname" character varying(40) DEFAULT '',
|
---|
| 111 | "listorder" integer DEFAULT 0,
|
---|
[324] | 112 | "def_custid" character varying(16) DEFAULT '',
|
---|
| 113 | "arin_netname" character varying(20) DEFAILT 'ISP'
|
---|
[92] | 114 | );
|
---|
| 115 |
|
---|
[321] | 116 | --
|
---|
| 117 | -- Name: alloctypes; Type: TABLE DATA; Schema: public; Owner: ipdb
|
---|
| 118 | --
|
---|
| 119 |
|
---|
[324] | 120 | COPY "alloctypes" FROM stdin;
|
---|
| 121 | cn Customer netblock Customer netblock 0 ISPCUST
|
---|
| 122 | si Static IP - Server pool Server pool IP 20 6750400 ISP
|
---|
| 123 | ci Static IP - Cable Static cable IP 21 ISP
|
---|
| 124 | di Static IP - DSL Static DSL IP 22 ISP
|
---|
| 125 | mi Static IP - Dialup Static dialup IP 23 ISP
|
---|
| 126 | wi Static IP - Wireless Static wireless IP 24 ISP
|
---|
| 127 | sd Static Pool - Servers Server pool 40 6750400 ISP
|
---|
| 128 | cd Static Pool - Cable Cable pool 41 CBL-BUS ISP-STATIC-CABLE
|
---|
| 129 | dp Static Pool - DSL DSL pool 42 DSL-BUS ISP-STATIC-DSL
|
---|
| 130 | mp Static Pool - Dialup Static dialup pool 43 DIAL-BUS ISP-STATIC-DIAL
|
---|
| 131 | wp Static Pool - Wireless Static wireless pool 44 WL-BUS ISP-STATIC-WIFI
|
---|
| 132 | en End-use netblock End-use netblock 100 6750400 ISP
|
---|
| 133 | me Dialup netblock Dialup netblock 101 DIAL-RES ISP-DIAL
|
---|
| 134 | de Dynamic DSL block Dynamic DSL block 102 DSL-RES ISP-DSL
|
---|
| 135 | ce Dynamic cable block Dynamic cable block 103 CBL-RES ISP-CABLE
|
---|
| 136 | we Dynamic WiFi block Dynamic WiFi block 104 WL-RES ISP-WIFI
|
---|
| 137 | ve Dynamic VoIP block Dynamic VoIP block 105 DYN-VOIP ISP
|
---|
| 138 | li Static IP - LAN/POP Static LAN/POP IP 190 6750400 ISP
|
---|
| 139 | ld Static Pool - LAN/POP LAN pool 191 6750400 ISP
|
---|
| 140 | wc Reserve for CORE/WAN blocks CORE/WAN blocks 200 6750400 ISP
|
---|
| 141 | pc Reserve for dynamic-route DSL netblocks Dynamic-route netblocks 201 6750400 ISP-STATIC-DSL
|
---|
| 142 | ac Reserve for ATM ATM blocks 202 6750400 ISP
|
---|
| 143 | wr CORE/WAN block CORE/WAN block 220 6750400 ISP
|
---|
| 144 | pr Dynamic-route DSL netblock Dynamic-route DSL 221 ISP
|
---|
| 145 | ar ATM block ATM block 222 ISP
|
---|
| 146 | rm Routing Routed netblock 500 6750400 ISP
|
---|
| 147 | in Internal netblock Internal netblock 990 6750400 ISP
|
---|
| 148 | mm Master block Master block 999 6750400 ISP
|
---|
[182] | 149 | \.
|
---|
[218] | 150 |
|
---|
[316] | 151 | REVOKE ALL on "alloctypes" from PUBLIC;
|
---|
| 152 | GRANT ALL on "alloctypes" to "ipdb";
|
---|
| 153 |
|
---|
| 154 | CREATE TABLE "cities" (
|
---|
| 155 | "id" serial NOT NULL PRIMARY KEY,
|
---|
| 156 | "city" character varying(30) DEFAULT '' NOT NULL,
|
---|
| 157 | "routing" character(1) DEFAULT 'n' NOT NULL
|
---|
| 158 | );
|
---|
| 159 |
|
---|
| 160 | REVOKE ALL on "cities" from PUBLIC;
|
---|
| 161 | GRANT ALL on "cities" to "ipdb";
|
---|
| 162 |
|
---|
[218] | 163 | --
|
---|
| 164 | -- Trigger and matching function to update modifystamp on allocations, poolips
|
---|
| 165 | --
|
---|
| 166 | CREATE FUNCTION up_modtime () RETURNS OPAQUE AS '
|
---|
| 167 | BEGIN
|
---|
| 168 | NEW.modifystamp := ''now'';
|
---|
| 169 | RETURN NEW;
|
---|
| 170 | END;
|
---|
| 171 | ' LANGUAGE 'plpgsql';
|
---|
| 172 |
|
---|
| 173 | CREATE TRIGGER up_modtime BEFORE UPDATE ON allocations
|
---|
| 174 | FOR EACH ROW EXECUTE PROCEDURE up_modtime();
|
---|
| 175 |
|
---|
| 176 | CREATE TRIGGER up_modtime BEFORE UPDATE ON poolips
|
---|
| 177 | FOR EACH ROW EXECUTE PROCEDURE up_modtime();
|
---|
[233] | 178 |
|
---|
| 179 | --
|
---|
| 180 | -- User data table - required for proper ACLs
|
---|
| 181 | --
|
---|
| 182 |
|
---|
| 183 | CREATE TABLE "users" (
|
---|
[237] | 184 | "username" varchar(16) NOT NULL PRIMARY KEY,
|
---|
[233] | 185 | "password" varchar(16) DEFAULT '',
|
---|
| 186 | "acl" varchar(16) DEFAULT 'b'
|
---|
| 187 | );
|
---|
[257] | 188 |
|
---|
| 189 | CREATE TABLE "dns" (
|
---|
| 190 | "ip" inet NOT NULL PRIMARY KEY,
|
---|
| 191 | "hostname" character varying(128),
|
---|
| 192 | "auto" character(1) DEFAULT 'y'
|
---|
| 193 | );
|
---|