mirror of
https://github.com/pi-hole/pi-hole.git
synced 2024-12-24 13:50:17 +00:00
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:
parent
27e4208631
commit
87c115fc86
2 changed files with 70 additions and 53 deletions
|
@ -2,15 +2,10 @@ PRAGMA FOREIGN_KEYS=ON;
|
||||||
|
|
||||||
CREATE TABLE domain_groups
|
CREATE TABLE domain_groups
|
||||||
(
|
(
|
||||||
"id" INTEGER PRIMARY KEY AUTOINCREMENT,
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||||
"enabled" BOOLEAN NOT NULL DEFAULT 1,
|
enabled BOOLEAN NOT NULL DEFAULT 1,
|
||||||
"description" TEXT
|
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
|
CREATE TABLE whitelist
|
||||||
(
|
(
|
||||||
|
@ -19,10 +14,16 @@ CREATE TABLE whitelist
|
||||||
enabled BOOLEAN NOT NULL DEFAULT 1,
|
enabled BOOLEAN NOT NULL DEFAULT 1,
|
||||||
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
||||||
date_modified 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
|
||||||
comment TEXT,
|
|
||||||
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
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
|
CREATE TABLE blacklist
|
||||||
(
|
(
|
||||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||||
|
@ -30,10 +31,16 @@ CREATE TABLE blacklist
|
||||||
enabled BOOLEAN NOT NULL DEFAULT 1,
|
enabled BOOLEAN NOT NULL DEFAULT 1,
|
||||||
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
||||||
date_modified 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
|
||||||
comment TEXT,
|
|
||||||
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
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
|
CREATE TABLE regex
|
||||||
(
|
(
|
||||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||||
|
@ -41,22 +48,22 @@ CREATE TABLE regex
|
||||||
enabled BOOLEAN NOT NULL DEFAULT 1,
|
enabled BOOLEAN NOT NULL DEFAULT 1,
|
||||||
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
||||||
date_modified 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
|
||||||
comment TEXT,
|
|
||||||
FOREIGN KEY (group_id) REFERENCES domain_groups(id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
CREATE TABLE adlist_groups
|
CREATE TABLE regex_by_group
|
||||||
(
|
(
|
||||||
"id" INTEGER PRIMARY KEY AUTOINCREMENT,
|
regex_id INTEGER NOT NULL REFERENCES regex (id),
|
||||||
"enabled" BOOLEAN NOT NULL DEFAULT 1,
|
group_id INTEGER NOT NULL REFERENCES domain_groups (id),
|
||||||
"description" TEXT
|
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
|
CREATE TABLE adlists
|
||||||
(
|
(
|
||||||
|
@ -65,10 +72,16 @@ CREATE TABLE adlists
|
||||||
enabled BOOLEAN NOT NULL DEFAULT 1,
|
enabled BOOLEAN NOT NULL DEFAULT 1,
|
||||||
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
date_added INTEGER NOT NULL DEFAULT (cast(strftime('%s', 'now') as int)),
|
||||||
date_modified 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
|
||||||
comment TEXT,
|
|
||||||
FOREIGN KEY (group_id) REFERENCES adlist_groups(id)
|
|
||||||
);
|
);
|
||||||
|
|
||||||
|
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
|
CREATE TABLE gravity
|
||||||
(
|
(
|
||||||
domain TEXT PRIMARY KEY
|
domain TEXT PRIMARY KEY
|
||||||
|
@ -81,48 +94,52 @@ CREATE TABLE info
|
||||||
|
|
||||||
INSERT INTO info VALUES("version","1");
|
INSERT INTO info VALUES("version","1");
|
||||||
|
|
||||||
CREATE VIEW vw_gravity AS SELECT a.domain
|
CREATE VIEW vw_gravity AS SELECT domain
|
||||||
FROM gravity a
|
FROM gravity
|
||||||
WHERE a.domain NOT IN (SELECT domain from vw_whitelist);
|
WHERE domain NOT IN (SELECT domain from vw_whitelist);
|
||||||
|
|
||||||
CREATE VIEW vw_whitelist AS SELECT a.domain
|
CREATE VIEW vw_whitelist AS SELECT domain
|
||||||
FROM whitelist a
|
FROM whitelist
|
||||||
INNER JOIN domain_groups b ON b.id = a.group_id
|
LEFT JOIN whitelist_by_group ON whitelist_by_group.whitelist_id = whitelist.id
|
||||||
WHERE a.enabled = 1 AND b.enabled = 1
|
LEFT JOIN domain_groups ON domain_groups.id = whitelist_by_group.group_id
|
||||||
ORDER BY a.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
|
CREATE TRIGGER tr_whitelist_update AFTER UPDATE ON whitelist
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE whitelist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
UPDATE whitelist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CREATE VIEW vw_blacklist AS SELECT a.domain
|
CREATE VIEW vw_blacklist AS SELECT domain
|
||||||
FROM blacklist a
|
FROM blacklist
|
||||||
INNER JOIN domain_groups b ON b.id = a.group_id
|
LEFT JOIN blacklist_by_group ON blacklist_by_group.blacklist_id = blacklist.id
|
||||||
WHERE a.enabled = 1 AND a.domain NOT IN vw_whitelist AND b.enabled = 1
|
LEFT JOIN domain_groups ON domain_groups.id = blacklist_by_group.group_id
|
||||||
ORDER BY a.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
|
CREATE TRIGGER tr_blacklist_update AFTER UPDATE ON blacklist
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE blacklist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
UPDATE blacklist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CREATE VIEW vw_regex AS SELECT a.domain
|
CREATE VIEW vw_regex AS SELECT domain
|
||||||
FROM regex a
|
FROM regex
|
||||||
INNER JOIN domain_groups b ON b.id = a.group_id
|
LEFT JOIN regex_by_group ON regex_by_group.regex_id = regex.id
|
||||||
WHERE a.enabled = 1 AND b.enabled = 1
|
LEFT JOIN domain_groups ON domain_groups.id = regex_by_group.group_id
|
||||||
ORDER BY a.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
|
CREATE TRIGGER tr_regex_update AFTER UPDATE ON regex
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE regex SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
UPDATE regex SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CREATE VIEW vw_adlists AS SELECT a.address
|
CREATE VIEW vw_adlists AS SELECT address
|
||||||
FROM adlists a
|
FROM adlists
|
||||||
INNER JOIN adlist_groups b ON b.id = a.group_id
|
LEFT JOIN adlists_by_group ON adlists_by_group.adlists_id = adlists.id
|
||||||
WHERE a.enabled = 1 AND b.enabled = 1
|
LEFT JOIN adlists_groups ON adlists_groups.id = adlists_by_group.group_id
|
||||||
ORDER BY a.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
|
CREATE TRIGGER tr_adlists_update AFTER UPDATE ON adlists
|
||||||
BEGIN
|
BEGIN
|
||||||
|
|
|
@ -120,7 +120,7 @@ database_table_from_file() {
|
||||||
do
|
do
|
||||||
# Only add non-empty lines
|
# Only add non-empty lines
|
||||||
if [[ ! -z "${domain}" ]]; then
|
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
|
rowid+=1
|
||||||
fi
|
fi
|
||||||
done
|
done
|
||||||
|
|
Loading…
Reference in a new issue