Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

SQL baseline cleanup #1614

Merged
merged 31 commits into from
Nov 15, 2017
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
31 commits
Select commit Hold shift + click to select a range
4102acf
whitespace cleanup
lunkwill42 Nov 14, 2017
1b7694a
insert new top-level categories in the correct place
lunkwill42 Nov 14, 2017
863cc2c
properly effectuate rename from subcat -> netboxgroup
lunkwill42 Nov 14, 2017
be1748a
removal of deviceid unique constraint on module table
lunkwill42 Nov 14, 2017
8c20a6a
properly change schema of swportblocked
lunkwill42 Nov 14, 2017
2d6f886
insert all subsystems in the same location of the script
lunkwill42 Nov 14, 2017
10c4cf0
insert all event- and alert types in the same location of script
lunkwill42 Nov 14, 2017
972143a
don't alter tables after the fact, make it right the first time!
lunkwill42 Nov 14, 2017
735789f
there is no data to fix when installing the baseline!
lunkwill42 Nov 14, 2017
999df73
insert 'unknown' vendor in the correct place.
lunkwill42 Nov 14, 2017
0b9b12b
"IF NOT EXISTS" is unnecessary in the baseline
lunkwill42 Nov 14, 2017
4e144d1
move inserts of even more event- and alerttypes
lunkwill42 Nov 14, 2017
9d10439
no need to drop a constraint from baseline, just never create it!
lunkwill42 Nov 14, 2017
8516b5e
whitespace cleanup
lunkwill42 Nov 14, 2017
c69b966
there is no data to fix when installing the baseline!
lunkwill42 Nov 14, 2017
3b606d4
navprofiles: don't alter tables after the fact, make it right the fir…
lunkwill42 Nov 14, 2017
3bb11d0
add account.preferences from the start, this is the baseline!
lunkwill42 Nov 14, 2017
a9e1c13
set list limit from the start, this is the baseline!
lunkwill42 Nov 14, 2017
2aa179b
consolidate AccountGroupPrivilege changes since last baseline
lunkwill42 Nov 14, 2017
9e080df
move insertion of alertsender to correct place
lunkwill42 Nov 14, 2017
f260fb1
consolidate updated matchfields since last baseline
lunkwill42 Nov 14, 2017
e717514
move insertions to correct location
lunkwill42 Nov 14, 2017
5b25c73
navprofiles: don't alter tables after the fact, make it right the fir…
lunkwill42 Nov 14, 2017
80f6302
add (possibly) clarifying comment
lunkwill42 Nov 14, 2017
4ee7ae6
there is no need to clean up data that isn't there!
lunkwill42 Nov 14, 2017
ab428b2
consolidate dashboard/widget changes since last baseline
lunkwill42 Nov 14, 2017
60c9afe
insert macwatch subsystem in the expected location
lunkwill42 Nov 15, 2017
392a1da
group things logically and add descriptive comments for each section
lunkwill42 Nov 15, 2017
7f36d99
no need for explicit transactions in changescripts
lunkwill42 Nov 15, 2017
bdebdd4
clean up relations that have been placed in the wrong db schema on so…
lunkwill42 Nov 15, 2017
de60751
remove obsolete but sometimes lingering objects from PostgreSQL database
lunkwill42 Nov 15, 2017
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
22 changes: 5 additions & 17 deletions sql/baseline/arnold.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,6 +22,8 @@ orgid VARCHAR,
determined CHAR(1), -- set to y if this is mac/port combo is blocked with the -d option.
fromvlan INT, -- original vlan on port before change (only on vlanchange)
tovlan INT, -- vlan on port after change (only on vlanchange)
textual_interface VARCHAR DEFAULT '', -- for storing textual representation of the interface when detaining

UNIQUE (mac,swportid)
);

Expand All @@ -41,7 +43,9 @@ username VARCHAR NOT NULL
CREATE TABLE quarantine_vlans (
quarantineid SERIAL PRIMARY KEY,
vlan INT,
description VARCHAR
description VARCHAR,

CONSTRAINT quarantine_vlan_unique UNIQUE (vlan)
);

-- A block, of lack of better name, is a run where we do automatic blocking
Expand All @@ -63,19 +67,3 @@ activeonvlans VARCHAR, -- a string with comma-separated vlan-numbers
detainmenttype VARCHAR CHECK (detainmenttype='disable' OR detainmenttype='quarantine'), -- type of detainment to try
quarantineid INT REFERENCES quarantine_vlans ON UPDATE CASCADE ON DELETE CASCADE
);

-- Create field for storing textual representation of the interface when detaining

ALTER table arnold.identity ADD textual_interface VARCHAR DEFAULT '';


-- Fix uniqueness on quarantine vlans

DELETE FROM quarantine_vlans WHERE quarantineid in (
SELECT q2.quarantineid
FROM quarantine_vlans q1
JOIN quarantine_vlans q2
ON (q1.vlan = q2.vlan AND q1.quarantineid < q2.quarantineid)
ORDER BY q1.quarantineid);

ALTER TABLE quarantine_vlans ADD CONSTRAINT quarantine_vlan_unique UNIQUE (vlan);
397 changes: 114 additions & 283 deletions sql/baseline/manage.sql

Large diffs are not rendered by default.

74 changes: 40 additions & 34 deletions sql/baseline/manage2.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,8 +23,20 @@ CREATE TABLE manage.macwatch (
CONSTRAINT macwatch_unique_mac UNIQUE (mac)
);

-- Create table for images

-- Registry of macwatch matches
-- (since watch rules may have wildcards and/or mac prefixes)
CREATE TABLE macwatch_match (
id SERIAL PRIMARY KEY,
macwatch INT NOT NULL REFERENCES macwatch(id) ON DELETE CASCADE ON UPDATE CASCADE,
cam INT NOT NULL REFERENCES cam(camid) ON DELETE CASCADE ON UPDATE CASCADE,
posted TIMESTAMP DEFAULT NOW()
);


------------------------------------------------------------------------------
-- Create table for room images
------------------------------------------------------------------------------
CREATE TABLE image (
imageid SERIAL PRIMARY KEY,
roomid VARCHAR REFERENCES room(roomid) NOT NULL,
Expand All @@ -36,22 +48,9 @@ CREATE TABLE image (
priority INT
);


INSERT INTO subsystem (
SELECT 'macwatch' AS name
WHERE NOT EXISTS (
SELECT name FROM subsystem WHERE name='macwatch'));

-- Added because macwatch may use mac-address prefixes
CREATE TABLE macwatch_match(
id SERIAL PRIMARY KEY,
macwatch INT NOT NULL REFERENCES macwatch(id) ON DELETE CASCADE ON UPDATE CASCADE,
cam INT NOT NULL REFERENCES cam(camid) ON DELETE CASCADE ON UPDATE CASCADE,
posted TIMESTAMP DEFAULT NOW()
);

------------------------------------------------------------------------------
-- Create basic token storage for api tokens

------------------------------------------------------------------------------
CREATE TABLE apitoken (
id SERIAL PRIMARY KEY,
token VARCHAR not null,
Expand All @@ -61,10 +60,14 @@ CREATE TABLE apitoken (
created TIMESTAMP DEFAULT now(),
last_used TIMESTAMP,
comment TEXT,
revoked BOOLEAN default FALSE
revoked BOOLEAN default FALSE,
endpoints hstore
);


------------------------------------------------------------------------------
-- Threshold rules and related functions
------------------------------------------------------------------------------
CREATE TABLE manage.thresholdrule (
id SERIAL PRIMARY KEY,
target VARCHAR NOT NULL,
Expand All @@ -82,22 +85,6 @@ CREATE TABLE manage.thresholdrule (

);

CREATE TABLE manage.alerthist_ack (
alert_id INTEGER PRIMARY KEY NOT NULL,
account_id INTEGER NOT NULL,
comment VARCHAR DEFAULT NULL,
date TIMESTAMPTZ DEFAULT NOW(),

CONSTRAINT alerthistory_ack_alert FOREIGN KEY (alert_id)
REFERENCES manage.alerthist (alerthistid)
ON UPDATE CASCADE ON DELETE CASCADE,

CONSTRAINT alerthistory_ack_user FOREIGN KEY (account_id)
REFERENCES profiles.account (id)
ON UPDATE CASCADE ON DELETE CASCADE

);

-- automatically close thresholdState when threshold rules are removed
CREATE OR REPLACE FUNCTION close_thresholdstate_on_thresholdrule_delete()
RETURNS TRIGGER AS $$
Expand All @@ -120,4 +107,23 @@ CREATE TRIGGER trig_close_thresholdstate_on_thresholdrule_delete
AFTER UPDATE OR DELETE ON manage.thresholdrule
FOR EACH ROW
EXECUTE PROCEDURE close_thresholdstate_on_thresholdrule_delete();
ALTER TABLE apitoken ADD COLUMN endpoints hstore;


------------------------------------------------------------------------------
-- Alerthist acknowledgements
------------------------------------------------------------------------------
CREATE TABLE manage.alerthist_ack (
alert_id INTEGER PRIMARY KEY NOT NULL,
account_id INTEGER NOT NULL,
comment VARCHAR DEFAULT NULL,
date TIMESTAMPTZ DEFAULT NOW(),

CONSTRAINT alerthistory_ack_alert FOREIGN KEY (alert_id)
REFERENCES manage.alerthist (alerthistid)
ON UPDATE CASCADE ON DELETE CASCADE,

CONSTRAINT alerthistory_ack_user FOREIGN KEY (account_id)
REFERENCES profiles.account (id)
ON UPDATE CASCADE ON DELETE CASCADE

);
Loading