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 | -- Master and routed blocks now live in the allocations table.
|
---|
9 |
|
---|
10 | ALTER TABLE allocations ADD COLUMN vrf text NOT NULL DEFAULT '';
|
---|
11 | ALTER TABLE allocations ADD COLUMN rdns text NOT NULL DEFAULT '';
|
---|
12 | ALTER TABLE allocations ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
|
---|
13 | ALTER TABLE allocations ADD COLUMN master_id integer NOT NULL DEFAULT 0;
|
---|
14 | ALTER TABLE allocations DROP CONSTRAINT allocations_pkey;
|
---|
15 | ALTER TABLE allocations ADD COLUMN id serial PRIMARY KEY;
|
---|
16 |
|
---|
17 | ALTER TABLE freeblocks ADD COLUMN vrf text NOT NULL DEFAULT '';
|
---|
18 | ALTER TABLE freeblocks ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
|
---|
19 | ALTER TABLE freeblocks ADD COLUMN master_id integer NOT NULL DEFAULT 0;
|
---|
20 | ALTER TABLE freeblocks DROP CONSTRAINT freeblocks_pkey;
|
---|
21 | ALTER TABLE freeblocks ADD CONSTRAINT freeblocks_pkey PRIMARY KEY ("cidr","parent_id");
|
---|
22 | ALTER TABLE freeblocks ADD COLUMN id serial;
|
---|
23 |
|
---|
24 | ALTER TABLE poolips ADD COLUMN vrf text NOT NULL DEFAULT '';
|
---|
25 | ALTER TABLE poolips ADD COLUMN rdns text NOT NULL DEFAULT '';
|
---|
26 | ALTER TABLE poolips ADD COLUMN parent_id integer NOT NULL DEFAULT 0;
|
---|
27 | ALTER TABLE poolips ADD COLUMN master_id integer NOT NULL DEFAULT 0;
|
---|
28 | ALTER TABLE poolips DROP CONSTRAINT poolips_pkey;
|
---|
29 | ALTER TABLE poolips ADD COLUMN id serial;
|
---|
30 | ALTER TABLE poolips ADD CONSTRAINT poolips_pkey PRIMARY KEY ("ip", "parent_id");
|
---|
31 |
|
---|
32 | -- probably need some more indexes
|
---|
33 |
|
---|
34 | -- Need some additional fields to support search output. Might arguably
|
---|
35 | -- move pool IPs into the allocations table; we'll see.
|
---|
36 | DROP VIEW searchme;
|
---|
37 | CREATE VIEW "searchme" AS
|
---|
38 | SELECT allocations.cidr, allocations.custid, allocations."type", allocations.city,
|
---|
39 | allocations.description, allocations.notes, allocations.circuitid, allocations.id,
|
---|
40 | allocations.parent_id, 'n' AS available
|
---|
41 | FROM allocations
|
---|
42 | UNION
|
---|
43 | SELECT poolips.ip, poolips.custid, poolips.type, poolips.city,
|
---|
44 | poolips.description, poolips.notes, poolips.circuitid, poolips.id,
|
---|
45 | poolips.parent_id, poolips.available
|
---|
46 | FROM poolips;
|
---|
47 |
|
---|
48 | -- Relabel a few types to match the new structure
|
---|
49 | UPDATE alloctypes SET listname='Routing aggregation', dispname='Routing aggregation' WHERE type='rm';
|
---|
50 |
|
---|
51 | -- Not critical but the previous definitions were too restrictive (eg, can't
|
---|
52 | -- handle MD5, or SHA password hashes). Plans for ACLs also require larger fields.
|
---|
53 | ALTER TABLE users ALTER COLUMN username TYPE varchar(256);
|
---|
54 | ALTER TABLE users ALTER COLUMN password TYPE varchar(256);
|
---|
55 | ALTER TABLE users ALTER COLUMN acl TYPE varchar(256);
|
---|