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

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

/trunk

Further refine new install and 2.7-3.0 upgrade SQL to support multiple
copies of the same reverse zone in different VRFs that use different
DNS views. See #41.

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