source: trunk/cgi-bin/ipdb-2.7-3.0.sql@ 858

Last change on this file since 858 was 854, checked in by Kris Deugau, 9 years ago

/trunk

Commit lurking extension to dnsavail table creation to allow nonstandard
long "location" entries

File size: 4.2 KB
Line 
1-- Baseline SQL to add necessary fields for IPDB 2.7 -> IPDB 3.0
2-- Note some data changes must be made via script.
3
4-- WARNING: This SQL is backwards-compatible, but once db-update.pl
5-- has run, IPDB v2.7 and older will NOT be able to properly manipulate
6-- the data!
7
8-- Flag table for deciding if we can usefully do rDNS RPC calls.
9CREATE TABLE dnsavail (
10 "zone" cidr PRIMARY KEY,
11 "location" varchar(4) DEFAULT '',
12 parent_alloc integer NOT NULL
13);
14
15-- Store backup fields in a separate table
16CREATE TABLE backuplist (
17 backup_id serial NOT NULL,
18 bkbrand text,
19 bkmodel text,
20 bktype text,
21 bkport integer,
22 bksrc text,
23 bkuser text,
24 bkvpass text,
25 bkepass text,
26 bkip inet
27);
28
29-- VRFs are now the apex entity
30CREATE TABLE vrfs (
31 vrf varchar(32) DEFAULT '' NOT NULL,
32 comment text DEFAULT '' NOT NULL,
33 location varchar(4) DEFAULT '' NOT NULL
34);
35
36ALTER TABLE ONLY vrfs
37 ADD CONSTRAINT vrfs_pkey PRIMARY KEY (vrf);
38
39-- need a default VRF to stuff everything into to start with
40INSERT INTO vrfs (vrf,comment) VALUES ('DEFAULT','Initial default VRF');
41
42-- Master and routed blocks now live in the allocations table.
43
44ALTER TABLE allocations ADD COLUMN vrf text NOT NULL DEFAULT '';
45ALTER TABLE allocations ADD COLUMN vlan text NOT NULL DEFAULT '';
46ALTER TABLE allocations ADD COLUMN rdns text NOT NULL DEFAULT '';
47ALTER TABLE allocations ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
48ALTER TABLE allocations ADD COLUMN master_id integer NOT NULL DEFAULT 0;
49ALTER TABLE allocations ADD COLUMN backup_id integer NOT NULL DEFAULT 0;
50ALTER TABLE allocations DROP CONSTRAINT allocations_pkey;
51ALTER TABLE allocations ADD COLUMN id serial PRIMARY KEY;
52-- not certain this is right
53CREATE UNIQUE INDEX allocations_skey ON allocations (cidr,vrf,type);
54
55ALTER TABLE freeblocks ADD COLUMN vrf text NOT NULL DEFAULT '';
56ALTER TABLE freeblocks ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
57ALTER TABLE freeblocks ADD COLUMN master_id integer NOT NULL DEFAULT 0;
58ALTER TABLE freeblocks ADD COLUMN reserve_for integer NOT NULL DEFAULT 0;
59ALTER TABLE freeblocks DROP CONSTRAINT freeblocks_pkey;
60ALTER TABLE freeblocks ADD CONSTRAINT freeblocks_pkey PRIMARY KEY ("cidr","parent_id");
61ALTER TABLE freeblocks ADD COLUMN id serial;
62
63ALTER TABLE poolips ADD COLUMN vrf text NOT NULL DEFAULT '';
64ALTER TABLE poolips ADD COLUMN vlan text NOT NULL DEFAULT '';
65ALTER TABLE poolips ADD COLUMN rdns text NOT NULL DEFAULT '';
66ALTER TABLE poolips ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
67ALTER TABLE poolips ADD COLUMN master_id integer NOT NULL DEFAULT 0;
68ALTER TABLE poolips ADD COLUMN backup_id integer NOT NULL DEFAULT 0;
69ALTER TABLE poolips DROP CONSTRAINT poolips_pkey;
70ALTER TABLE poolips ADD COLUMN id serial;
71ALTER TABLE poolips ADD CONSTRAINT poolips_pkey PRIMARY KEY ("ip", "parent_id");
72
73-- probably need some more indexes
74
75-- Need some additional fields to support search output. Might arguably
76-- move pool IPs into the allocations table; we'll see.
77DROP VIEW searchme;
78-- do these here, because we can't do them while the view is defined
79ALTER TABLE allocations ALTER COLUMN description TYPE varchar(128);
80ALTER TABLE poolips ALTER COLUMN description TYPE varchar(128);
81CREATE VIEW "searchme" AS
82 SELECT allocations.cidr, allocations.custid, allocations."type", allocations.city,
83 allocations.description, allocations.notes, allocations.circuitid, allocations.vrf,
84 allocations.vlan, allocations.id, allocations.parent_id, allocations.master_id, 'n' AS available
85 FROM allocations
86 UNION
87 SELECT poolips.ip, poolips.custid, poolips.type, poolips.city,
88 poolips.description, poolips.notes, poolips.circuitid, poolips.vrf,
89 poolips.vlan, poolips.id, poolips.parent_id, poolips.master_id, poolips.available
90 FROM poolips;
91
92-- Relabel a few types to match the new structure
93UPDATE alloctypes SET listname='Routing aggregation', dispname='Routing aggregation' WHERE type='rm';
94
95-- Not critical but the previous definitions were too restrictive (eg, can't
96-- handle MD5, or SHA password hashes). Plans for ACLs also require larger fields.
97ALTER TABLE users ALTER COLUMN username TYPE varchar(256);
98ALTER TABLE users ALTER COLUMN password TYPE varchar(256);
99ALTER TABLE users ALTER COLUMN acl TYPE varchar(256);
Note: See TracBrowser for help on using the repository browser.