Skip to content

Commit

Permalink
Add in-memory tables for all alert families. Add aggregated views for…
Browse files Browse the repository at this point in the history
… all families.
  • Loading branch information
cardigliano committed Nov 12, 2024
1 parent 2e54589 commit 173e0aa
Show file tree
Hide file tree
Showing 3 changed files with 908 additions and 83 deletions.
331 changes: 329 additions & 2 deletions httpdocs/misc/alert_store_schema.sql
Original file line number Diff line number Diff line change
@@ -1,10 +1,16 @@
-- -----------------------------------------------------
-- -----------------------------------------------------
-- Persistent DataBase
-- -----------------------------------------------------
-- -----------------------------------------------------

-- -----------------------------------------------------
-- Table `active_monitoring_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `active_monitoring_alerts` (
`rowid` INTEGER PRIMARY KEY AUTOINCREMENT,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0, -- e.g., historical [0], acknowledged [1], engaged (TBD)
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0, -- e.g., historical [0], acknowledged [1], engaged [2]
`resolved_ip` TEXT NULL,
`resolved_name` TEXT NULL,
`interface_id` INTEGER NULL,
Expand Down Expand Up @@ -432,12 +438,279 @@ CREATE TABLE IF NOT EXISTS `asset_management` (

@

-- -----------------------------------------------------
-- -----------------------------------------------------
-- In-Memory DataBase
-- -----------------------------------------------------
-- -----------------------------------------------------

ATTACH DATABASE ':memory:' AS mem_db;

-- -----------------------------------------------------
-- Table `active_monitoring_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `active_monitoring_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0, -- e.g., historical [0], acknowledged [1], engaged (TBD)
`resolved_ip` TEXT NULL,
`resolved_name` TEXT NULL,
`interface_id` INTEGER NULL,
`measurement` TEXT NULL,
`measure_threshold` INTEGER NULL DEFAULT 0,
`measure_value` REAL NULL DEFAULT 0,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL, -- A label that can be set by the user
`user_label_tstamp` DATETIME NULL DEFAULT 0, -- Timestamp of the last user_label change
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `flow_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `flow_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`json` TEXT NULL,
`ip_version` INTEGER NOT NULL DEFAULT 0 CHECK(`ip_version` = 4 OR `ip_version` = 6),
`cli_ip` TEXT NOT NULL,
`srv_ip` TEXT NOT NULL,
`cli_port` INTEGER NOT NULL DEFAULT 0 CHECK(`cli_port` BETWEEN 0 AND 65535),
`srv_port` INTEGER NOT NULL DEFAULT 0 CHECK(`srv_port` BETWEEN 0 AND 65535),
`vlan_id` INTEGER NOT NULL DEFAULT 0 CHECK(`vlan_id` >= 0),
`is_cli_attacker` INTEGER NOT NULL DEFAULT 0 CHECK(`is_cli_attacker` IN (0,1)),
`is_cli_victim` INTEGER NOT NULL DEFAULT 0 CHECK(`is_cli_victim` IN (0,1)),
`is_srv_attacker` INTEGER NOT NULL DEFAULT 0 CHECK(`is_srv_attacker` IN (0,1)),
`is_srv_victim` INTEGER NOT NULL DEFAULT 0 CHECK(`is_srv_victim` IN (0,1)),
`proto` INTEGER NOT NULL DEFAULT 0 CHECK(`proto` >= 0),
`l7_proto` INTEGER NOT NULL DEFAULT 0 CHECK(`l7_proto` >= 0),
`l7_master_proto` INTEGER NOT NULL DEFAULT 0 CHECK(`l7_master_proto` >= 0),
`l7_cat` INTEGER NOT NULL DEFAULT 0 CHECK(`l7_cat` >= 0),
`cli_name` TEXT NULL,
`srv_name` TEXT NULL,
`cli_country` TEXT NULL,
`srv_country` TEXT NULL,
`cli_blacklisted` INTEGER NOT NULL DEFAULT 0 CHECK(`cli_blacklisted` IN (0,1)),
`srv_blacklisted` INTEGER NOT NULL DEFAULT 0 CHECK(`srv_blacklisted` IN (0,1)),
`cli2srv_bytes` INTEGER NOT NULL DEFAULT 0 CHECK(`cli2srv_bytes` >= 0),
`srv2cli_bytes` INTEGER NOT NULL DEFAULT 0 CHECK(`srv2cli_bytes` >= 0),
`cli2srv_pkts` INTEGER NOT NULL DEFAULT 0 CHECK(`cli2srv_pkts` >= 0),
`srv2cli_pkts` INTEGER NOT NULL DEFAULT 0 CHECK(`srv2cli_pkts` >= 0),
`first_seen` DATETIME NOT NULL DEFAULT 0,
`community_id` TEXT NULL,
`alerts_map` BLOB DEFAULT 0, -- An HEX bitmap of all flow statuses
`flow_risk_bitmap` INTEGER NOT NULL DEFAULT 0,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `host_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `host_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`ip_version` INTEGER NOT NULL DEFAULT 0 CHECK(`ip_version` = 4 OR `ip_version` = 6),
`ip` TEXT NOT NULL,
`vlan_id` INTEGER NULL DEFAULT 0 CHECK(`vlan_id` >= 0),
`name` TEXT NULL,
`is_attacker` INTEGER NULL CHECK(`is_attacker` IN (0,1)),
`is_victim` INTEGER NULL CHECK(`is_victim` IN (0,1)),
`is_client` INTEGER NULL CHECK(`is_client` IN (0,1)),
`is_server` INTEGER NULL CHECK(`is_server` IN (0,1)),
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `mac_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `mac_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`address` TEXT NULL DEFAULT 0,
`device_type` INTEGER NULL CHECK(`device_type` >= 0),
`name` TEXT NULL,
`is_attacker` INTEGER NULL CHECK(`is_attacker` IN (0,1)),
`is_victim` INTEGER NULL CHECK(`is_victim` IN (0,1)),
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `snmp_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `snmp_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`ip` TEXT NOT NULL,
`port` INTEGER NULL,
`name` TEXT NULL,
`port_name` TEXT NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `network_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `network_alerts` (
`rowid` INTEGER PRIMARY KEY ,
`local_network_id` INTEGER NOT NULL CHECK(`local_network_id` >= 0),
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`name` TEXT NULL,
`alias` TEXT NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `interface_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `interface_alerts` (
`rowid` INTEGER PRIMARY KEY,
`ifid` INTEGER NOT NULL CHECK(`ifid` >= -1),
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`subtype` TEXT NULL,
`name` TEXT NULL,
`alias` TEXT NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `user_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `user_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`user` TEXT NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);

@

-- -----------------------------------------------------
-- Table `system_alerts`
-- -----------------------------------------------------
CREATE TABLE IF NOT EXISTS `system_alerts` (
`rowid` INTEGER PRIMARY KEY,
`alert_id` INTEGER NOT NULL CHECK(`alert_id` >= 0),
`alert_status` INTEGER NOT NULL CHECK(`alert_status` >= 0) DEFAULT 0,
`interface_id` INTEGER NULL,
`name` TEXT NULL,
`tstamp` DATETIME NOT NULL,
`tstamp_end` DATETIME NULL DEFAULT 0,
`severity` INTEGER NOT NULL CHECK(`severity` >= 0),
`score` INTEGER NOT NULL DEFAULT 0 CHECK(`score` >= 0),
`granularity` INTEGER NOT NULL DEFAULT 0 CHECK(`granularity` >= 0),
`counter` INTEGER NOT NULL DEFAULT 0 CHECK(`counter` >= 0),
`description` TEXT NULL,
`json` TEXT NULL,
`user_label` TEXT NULL,
`user_label_tstamp` DATETIME NULL DEFAULT 0,
`require_attention` INTEGER NULL DEFAULT 0
);





@

CREATE TABLE mem_db.engaged_host_alerts (
Expand Down Expand Up @@ -470,9 +743,63 @@ alert_category INTEGER NULL,
require_attention INTEGER NULL DEFAULT 0
);

@
-- -----------------------------------------------------
-- -----------------------------------------------------
-- Views
-- -----------------------------------------------------
-- -----------------------------------------------------

@
CREATE TEMP VIEW active_monitoring_alerts_view AS
SELECT * FROM active_monitoring_alerts
UNION ALL
SELECT * FROM mem_db.engaged_active_monitoring_alerts

@

CREATE TEMP VIEW mac_alerts_view AS
SELECT * FROM mac_alerts
UNION ALL
SELECT * FROM mem_db.engaged_mac_alerts

@

CREATE TEMP VIEW snmp_alerts_view AS
SELECT * FROM snmp_alerts
UNION ALL
SELECT * FROM mem_db.engaged_snmp_alerts

@

CREATE TEMP VIEW network_alerts_view AS
SELECT * FROM network_alerts
UNION ALL
SELECT * FROM mem_db.engaged_network_alerts

@

CREATE TEMP VIEW interface_alerts_view AS
SELECT * FROM interface_alerts
UNION ALL
SELECT * FROM mem_db.engaged_interface_alerts

@

CREATE TEMP VIEW user_alerts_view AS
SELECT * FROM user_alerts
UNION ALL
SELECT * FROM mem_db.engaged_user_alerts

@

CREATE TEMP VIEW system_alerts_view AS
SELECT * FROM system_alerts
UNION ALL
SELECT * FROM mem_db.engaged_system_alerts

@

-- View with engaged and historical alerts
-- Note: columns are listed manually as order may change due to alter table
CREATE TEMP VIEW host_alerts_view AS
SELECT
Expand Down
Loading

0 comments on commit 173e0aa

Please sign in to comment.