Change schema to enforce foreing keys

The foreign keys have 'ON DELETE CASCADE' to simplify the removal
of networks etc. (controller code)

Some unique constraints are replaced with a multi column primary
key.

To update an existing database:
 * install updated binaries
 * stop service
 * sqlite3 controller.db .dump | \
    egrep '((^PRAGMA)|(^BEGIN)|(^INSERT)|(^COMMIT))' | \
    grep -v 'schemaVersion' > data.sql
 * mv controller.db controller.db.backup
 * start service
 * stop service
 * sqlite3 controller.db < data.sql
 * start service
This commit is contained in:
Kees Bos 2015-06-11 11:35:25 +02:00
parent 00aa115898
commit de697a1c45
2 changed files with 115 additions and 119 deletions

View File

@ -3,53 +3,6 @@ CREATE TABLE Config (
v varchar(1024) NOT NULL
);
CREATE TABLE IpAssignment (
networkId char(16) NOT NULL,
nodeId char(10) NOT NULL,
ip blob(16) NOT NULL,
ipNetmaskBits integer NOT NULL DEFAULT(0),
ipVersion integer NOT NULL DEFAULT(4)
);
CREATE INDEX IpAssignment_networkId_ip ON IpAssignment (networkId, ip);
CREATE INDEX IpAssignment_networkId_nodeId ON IpAssignment (networkId, nodeId);
CREATE INDEX IpAssignment_networkId ON IpAssignment (networkId);
CREATE TABLE IpAssignmentPool (
networkId char(16) NOT NULL,
ipNetwork blob(16) NOT NULL,
ipNetmaskBits integer NOT NULL,
ipVersion integer NOT NULL DEFAULT(4)
);
CREATE INDEX IpAssignmentPool_networkId ON IpAssignmentPool (networkId);
CREATE TABLE Member (
networkId char(16) NOT NULL,
nodeId char(10) NOT NULL,
authorized integer NOT NULL DEFAULT(0),
activeBridge integer NOT NULL DEFAULT(0)
);
CREATE INDEX Member_networkId ON Member (networkId);
CREATE INDEX Member_networkId_activeBridge ON Member(networkId, activeBridge);
CREATE UNIQUE INDEX Member_networkId_nodeId ON Member (networkId, nodeId);
CREATE TABLE MulticastRate (
networkId char(16) NOT NULL,
mgMac char(12) NOT NULL,
mgAdi integer NOT NULL DEFAULT(0),
preload integer NOT NULL,
maxBalance integer NOT NULL,
accrual integer NOT NULL
);
CREATE INDEX MulticastRate_networkId ON MulticastRate (networkId);
CREATE TABLE Network (
id char(16) PRIMARY KEY NOT NULL,
name varchar(128) NOT NULL,
@ -63,16 +16,6 @@ CREATE TABLE Network (
revision integer NOT NULL DEFAULT(1)
);
CREATE TABLE Relay (
networkId char(16) NOT NULL,
nodeId char(10) NOT NULL,
phyAddress varchar(64) NOT NULL
);
CREATE INDEX Relay_networkId ON Relay (networkId);
CREATE UNIQUE INDEX Relay_networkId_nodeId ON Relay (networkId, nodeId);
CREATE TABLE Node (
id char(10) PRIMARY KEY NOT NULL,
identity varchar(4096) NOT NULL,
@ -81,10 +24,65 @@ CREATE TABLE Node (
firstSeen integer NOT NULL DEFAULT(0)
);
CREATE TABLE IpAssignment (
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,
ip blob(16) NOT NULL,
ipNetmaskBits integer NOT NULL DEFAULT(0),
ipVersion integer NOT NULL DEFAULT(4)
);
CREATE INDEX IpAssignment_networkId_ip ON IpAssignment (networkId, ip);
CREATE INDEX IpAssignment_networkId_nodeId ON IpAssignment (networkId, nodeId);
CREATE INDEX IpAssignment_networkId ON IpAssignment (networkId);
CREATE TABLE IpAssignmentPool (
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
ipNetwork blob(16) NOT NULL,
ipNetmaskBits integer NOT NULL,
ipVersion integer NOT NULL DEFAULT(4)
);
CREATE INDEX IpAssignmentPool_networkId ON IpAssignmentPool (networkId);
CREATE TABLE Member (
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,
authorized integer NOT NULL DEFAULT(0),
activeBridge integer NOT NULL DEFAULT(0),
PRIMARY KEY (networkId, nodeId)
);
CREATE INDEX Member_networkId ON Member (networkId);
CREATE INDEX Member_networkId_activeBridge ON Member(networkId, activeBridge);
CREATE TABLE MulticastRate (
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
mgMac char(12) NOT NULL,
mgAdi integer NOT NULL DEFAULT(0),
preload integer NOT NULL,
maxBalance integer NOT NULL,
accrual integer NOT NULL
);
CREATE INDEX MulticastRate_networkId ON MulticastRate (networkId);
CREATE TABLE Relay (
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,
phyAddress varchar(64) NOT NULL,
PRIMARY KEY (networkId, nodeId)
);
CREATE INDEX Relay_networkId ON Relay (networkId);
CREATE TABLE Rule (
networkId char(16) NOT NULL,
networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,
ruleId integer NOT NULL,
nodeId char(10),
nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,
vlanId integer,
vlanPcp integer,
etherType integer,
@ -101,4 +99,4 @@ CREATE TABLE Rule (
"action" varchar(4096) NOT NULL DEFAULT('accept')
);
CREATE INDEX Rule_networkId ON Rule (networkId);
CREATE INDEX Rule_networkId ON Rule (networkId);

View File

@ -4,53 +4,6 @@
" v varchar(1024) NOT NULL\n"\
");\n"\
"\n"\
"CREATE TABLE IpAssignment (\n"\
" networkId char(16) NOT NULL,\n"\
" nodeId char(10) NOT NULL,\n"\
" ip blob(16) NOT NULL,\n"\
" ipNetmaskBits integer NOT NULL DEFAULT(0),\n"\
" ipVersion integer NOT NULL DEFAULT(4)\n"\
");\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId_ip ON IpAssignment (networkId, ip);\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId_nodeId ON IpAssignment (networkId, nodeId);\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId ON IpAssignment (networkId);\n"\
"\n"\
"CREATE TABLE IpAssignmentPool (\n"\
" networkId char(16) NOT NULL,\n"\
" ipNetwork blob(16) NOT NULL,\n"\
" ipNetmaskBits integer NOT NULL,\n"\
" ipVersion integer NOT NULL DEFAULT(4)\n"\
");\n"\
"\n"\
"CREATE INDEX IpAssignmentPool_networkId ON IpAssignmentPool (networkId);\n"\
"\n"\
"CREATE TABLE Member (\n"\
" networkId char(16) NOT NULL,\n"\
" nodeId char(10) NOT NULL,\n"\
" authorized integer NOT NULL DEFAULT(0),\n"\
" activeBridge integer NOT NULL DEFAULT(0)\n"\
");\n"\
"\n"\
"CREATE INDEX Member_networkId ON Member (networkId);\n"\
"\n"\
"CREATE INDEX Member_networkId_activeBridge ON Member(networkId, activeBridge);\n"\
"\n"\
"CREATE UNIQUE INDEX Member_networkId_nodeId ON Member (networkId, nodeId);\n"\
"\n"\
"CREATE TABLE MulticastRate (\n"\
" networkId char(16) NOT NULL,\n"\
" mgMac char(12) NOT NULL,\n"\
" mgAdi integer NOT NULL DEFAULT(0),\n"\
" preload integer NOT NULL,\n"\
" maxBalance integer NOT NULL,\n"\
" accrual integer NOT NULL\n"\
");\n"\
"\n"\
"CREATE INDEX MulticastRate_networkId ON MulticastRate (networkId);\n"\
"\n"\
"CREATE TABLE Network (\n"\
" id char(16) PRIMARY KEY NOT NULL,\n"\
" name varchar(128) NOT NULL,\n"\
@ -64,16 +17,6 @@
" revision integer NOT NULL DEFAULT(1)\n"\
");\n"\
"\n"\
"CREATE TABLE Relay (\n"\
" networkId char(16) NOT NULL,\n"\
" nodeId char(10) NOT NULL,\n"\
" phyAddress varchar(64) NOT NULL\n"\
");\n"\
"\n"\
"CREATE INDEX Relay_networkId ON Relay (networkId);\n"\
"\n"\
"CREATE UNIQUE INDEX Relay_networkId_nodeId ON Relay (networkId, nodeId);\n"\
"\n"\
"CREATE TABLE Node (\n"\
" id char(10) PRIMARY KEY NOT NULL,\n"\
" identity varchar(4096) NOT NULL,\n"\
@ -82,10 +25,65 @@
" firstSeen integer NOT NULL DEFAULT(0)\n"\
");\n"\
"\n"\
"CREATE TABLE IpAssignment (\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,\n"\
" ip blob(16) NOT NULL,\n"\
" ipNetmaskBits integer NOT NULL DEFAULT(0),\n"\
" ipVersion integer NOT NULL DEFAULT(4)\n"\
");\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId_ip ON IpAssignment (networkId, ip);\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId_nodeId ON IpAssignment (networkId, nodeId);\n"\
"\n"\
"CREATE INDEX IpAssignment_networkId ON IpAssignment (networkId);\n"\
"\n"\
"CREATE TABLE IpAssignmentPool (\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" ipNetwork blob(16) NOT NULL,\n"\
" ipNetmaskBits integer NOT NULL,\n"\
" ipVersion integer NOT NULL DEFAULT(4)\n"\
");\n"\
"\n"\
"CREATE INDEX IpAssignmentPool_networkId ON IpAssignmentPool (networkId);\n"\
"\n"\
"CREATE TABLE Member (\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,\n"\
" authorized integer NOT NULL DEFAULT(0),\n"\
" activeBridge integer NOT NULL DEFAULT(0),\n"\
" PRIMARY KEY (networkId, nodeId)\n"\
");\n"\
"\n"\
"CREATE INDEX Member_networkId ON Member (networkId);\n"\
"\n"\
"CREATE INDEX Member_networkId_activeBridge ON Member(networkId, activeBridge);\n"\
"\n"\
"CREATE TABLE MulticastRate (\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" mgMac char(12) NOT NULL,\n"\
" mgAdi integer NOT NULL DEFAULT(0),\n"\
" preload integer NOT NULL,\n"\
" maxBalance integer NOT NULL,\n"\
" accrual integer NOT NULL\n"\
");\n"\
"\n"\
"CREATE INDEX MulticastRate_networkId ON MulticastRate (networkId);\n"\
"\n"\
"CREATE TABLE Relay (\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,\n"\
" phyAddress varchar(64) NOT NULL,\n"\
" PRIMARY KEY (networkId, nodeId)\n"\
");\n"\
"\n"\
"CREATE INDEX Relay_networkId ON Relay (networkId);\n"\
"\n"\
"CREATE TABLE Rule (\n"\
" networkId char(16) NOT NULL,\n"\
" networkId char(16) NOT NULL REFERENCES Network(id) ON DELETE CASCADE,\n"\
" ruleId integer NOT NULL,\n"\
" nodeId char(10),\n"\
" nodeId char(10) NOT NULL REFERENCES Node(id) ON DELETE CASCADE,\n"\
" vlanId integer,\n"\
" vlanPcp integer,\n"\
" etherType integer,\n"\