Change implementation to use linking tables (domain_groups, adlists_groups). This allows adding domains to multiple lists conveniently.

Signed-off-by: DL6ER <dl6er@dl6er.de>
This commit is contained in:
DL6ER 2019-06-30 18:58:47 +02:00
parent 27e4208631
commit 87c115fc86
No known key found for this signature in database
GPG key ID: 00135ACBD90B28DD
2 changed files with 70 additions and 53 deletions

View file

@ -2,15 +2,10 @@ PRAGMA FOREIGN_KEYS=ON;
CREATE TABLE domain_groups
(
"id" INTEGER PRIMARY KEY AUTOINCREMENT,
"enabled" BOOLEAN NOT NULL DEFAULT 1,
"description" TEXT
id INTEGER PRIMARY KEY AUTOINCREMENT,
enabled BOOLEAN NOT NULL DEFAULT 1,
description TEXT
);
INSERT INTO domain_groups ("id","description") VALUES (0,'Standard group');
CREATE TRIGGER domain_groups_standard_group AFTER DELETE ON domain_groups WHEN OLD.id = 0
BEGIN
INSERT INTO domain_groups ("id","description") VALUES (0,'Standard group');
END;
CREATE TABLE whitelist
(
@ -19,10 +14,16 @@ CREATE TABLE whitelist
enabled BOOLEAN NOT NULL DEFAULT 1,
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
date_modified INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
group_id INTEGER NOT NULL DEFAULT 0,
comment TEXT,
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
comment TEXT
);
CREATE TABLE whitelist_by_group
(
whitelist_id INTEGER NOT NULL REFERENCES whitelist (id),
group_id INTEGER NOT NULL REFERENCES domain_groups (id),
PRIMARY KEY (whitelist_id, group_id)
);
CREATE TABLE blacklist
(
id INTEGER PRIMARY KEY AUTOINCREMENT,
@ -30,10 +31,16 @@ CREATE TABLE blacklist
enabled BOOLEAN NOT NULL DEFAULT 1,
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
date_modified INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
group_id INTEGER NOT NULL DEFAULT 0,
comment TEXT,
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
comment TEXT
);
CREATE TABLE blacklist_by_group
(
blacklist_id INTEGER NOT NULL REFERENCES blacklist (id),
group_id INTEGER NOT NULL REFERENCES domain_groups (id),
PRIMARY KEY (blacklist_id, group_id)
);
CREATE TABLE regex
(
id INTEGER PRIMARY KEY AUTOINCREMENT,
@ -41,22 +48,22 @@ CREATE TABLE regex
enabled BOOLEAN NOT NULL DEFAULT 1,
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
date_modified INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
group_id INTEGER NOT NULL DEFAULT 0,
comment TEXT,
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
comment TEXT
);
CREATE TABLE adlist_groups
CREATE TABLE regex_by_group
(
"id" INTEGER PRIMARY KEY AUTOINCREMENT,
"enabled" BOOLEAN NOT NULL DEFAULT 1,
"description" TEXT
regex_id INTEGER NOT NULL REFERENCES regex (id),
group_id INTEGER NOT NULL REFERENCES domain_groups (id),
PRIMARY KEY (regex_id, group_id)
);
CREATE TABLE adlists_groups
(
id INTEGER PRIMARY KEY AUTOINCREMENT,
enabled BOOLEAN NOT NULL DEFAULT 1,
description TEXT
);
INSERT INTO adlist_groups ("id","description") VALUES (0,'Standard group');
CREATE TRIGGER adlist_groups_standard_group AFTER DELETE ON adlist_groups WHEN OLD.id = 0
BEGIN
INSERT INTO adlist_groups ("id","description") VALUES (0,'Standard group');
END;
CREATE TABLE adlists
(
@ -65,10 +72,16 @@ CREATE TABLE adlists
enabled BOOLEAN NOT NULL DEFAULT 1,
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
date_modified INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
group_id INTEGER NOT NULL DEFAULT 0,
comment TEXT,
FOREIGN KEY (group_id) REFERENCES adlist_groups(id)
comment TEXT
);
CREATE TABLE adlists_by_group
(
adlists_id INTEGER NOT NULL REFERENCES adlists (id),
group_id INTEGER NOT NULL REFERENCES adlists_groups (id),
PRIMARY KEY (adlists_id, group_id)
);
CREATE TABLE gravity
(
domain TEXT PRIMARY KEY
@ -81,48 +94,52 @@ CREATE TABLE info
INSERT INTO info VALUES("version","1");
CREATE VIEW vw_gravity AS SELECT a.domain
FROM gravity a
WHERE a.domain NOT IN (SELECT domain from vw_whitelist);
CREATE VIEW vw_gravity AS SELECT domain
FROM gravity
WHERE domain NOT IN (SELECT domain from vw_whitelist);
CREATE VIEW vw_whitelist AS SELECT a.domain
FROM whitelist a
INNER JOIN domain_groups b ON b.id = a.group_id
WHERE a.enabled = 1 AND b.enabled = 1
ORDER BY a.id;
CREATE VIEW vw_whitelist AS SELECT domain
FROM whitelist
LEFT JOIN whitelist_by_group ON whitelist_by_group.whitelist_id = whitelist.id
LEFT JOIN domain_groups ON domain_groups.id = whitelist_by_group.group_id
WHERE whitelist.enabled = 1 AND domain_groups.enabled IS NULL OR domain_groups.enabled == 1
ORDER BY whitelist.id;
CREATE TRIGGER tr_whitelist_update AFTER UPDATE ON whitelist
BEGIN
UPDATE whitelist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
END;
CREATE VIEW vw_blacklist AS SELECT a.domain
FROM blacklist a
INNER JOIN domain_groups b ON b.id = a.group_id
WHERE a.enabled = 1 AND a.domain NOT IN vw_whitelist AND b.enabled = 1
ORDER BY a.id;
CREATE VIEW vw_blacklist AS SELECT domain
FROM blacklist
LEFT JOIN blacklist_by_group ON blacklist_by_group.blacklist_id = blacklist.id
LEFT JOIN domain_groups ON domain_groups.id = blacklist_by_group.group_id
WHERE blacklist.enabled = 1 AND domain_groups.enabled IS NULL OR domain_groups.enabled == 1
ORDER BY blacklist.id;
CREATE TRIGGER tr_blacklist_update AFTER UPDATE ON blacklist
BEGIN
UPDATE blacklist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
END;
CREATE VIEW vw_regex AS SELECT a.domain
FROM regex a
INNER JOIN domain_groups b ON b.id = a.group_id
WHERE a.enabled = 1 AND b.enabled = 1
ORDER BY a.id;
CREATE VIEW vw_regex AS SELECT domain
FROM regex
LEFT JOIN regex_by_group ON regex_by_group.regex_id = regex.id
LEFT JOIN domain_groups ON domain_groups.id = regex_by_group.group_id
WHERE regex.enabled = 1 AND domain_groups.enabled IS NULL OR domain_groups.enabled == 1
ORDER BY regex.id;
CREATE TRIGGER tr_regex_update AFTER UPDATE ON regex
BEGIN
UPDATE regex SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
END;
CREATE VIEW vw_adlists AS SELECT a.address
FROM adlists a
INNER JOIN adlist_groups b ON b.id = a.group_id
WHERE a.enabled = 1 AND b.enabled = 1
ORDER BY a.id;
CREATE VIEW vw_adlists AS SELECT address
FROM adlists
LEFT JOIN adlists_by_group ON adlists_by_group.adlists_id = adlists.id
LEFT JOIN adlists_groups ON adlists_groups.id = adlists_by_group.group_id
WHERE adlists.enabled = 1 AND adlists_groups.enabled IS NULL OR adlists_groups.enabled == 1
ORDER BY adlists.id;
CREATE TRIGGER tr_adlists_update AFTER UPDATE ON adlists
BEGIN

View file

@ -120,7 +120,7 @@ database_table_from_file() {
do
# Only add non-empty lines
if [[ ! -z "${domain}" ]]; then
echo "${rowid},\"${domain}\",1,${timestamp},${timestamp},0,\"Migrated from ${source}\"" >> "${tmpFile}"
echo "${rowid},\"${domain}\",1,${timestamp},${timestamp},\"Migrated from ${source}\"" >> "${tmpFile}"
rowid+=1
fi
done