Unite four domain tables into a single domainlist table.

Signed-off-by: DL6ER <dl6er@dl6er.de>
pull/3015/head
DL6ER 5 years ago
parent 9248c92b5c
commit 185319d560
No known key found for this signature in database
GPG Key ID: 00135ACBD90B28DD

@ -41,4 +41,11 @@ upgrade_gravityDB(){
sqlite3 "${database}" < "/etc/.pihole/advanced/Scripts/database_migration/gravity/2_to_3.sql"
version=3
fi
if [[ "$version" == "3" ]]; then
# This migration script unifies the formally separated domain
# lists into a single table with a UNIQUE domain constraint
echo -e " ${INFO} Upgrading gravity database from version 3 to 4"
sqlite3 "${database}" < "${scriptPath}/3_to_4.sql"
version=6
fi
}

@ -0,0 +1,96 @@
.timeout 30000
PRAGMA FOREIGN_KEYS=OFF;
BEGIN TRANSACTION;
CREATE TABLE domainlist
(
id INTEGER PRIMARY KEY AUTOINCREMENT,
type INTEGER NOT NULL DEFAULT 0,
domain TEXT UNIQUE NOT NULL,
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)),
comment TEXT
);
ALTER TABLE whitelist ADD COLUMN type INTEGER;
UPDATE whitelist SET type = 0;
INSERT INTO domainlist (type,domain,enabled,date_added,date_modified,comment)
SELECT type,domain,enabled,date_added,date_modified,comment FROM whitelist;
ALTER TABLE blacklist ADD COLUMN type INTEGER;
UPDATE blacklist SET type = 1;
INSERT INTO domainlist (type,domain,enabled,date_added,date_modified,comment)
SELECT type,domain,enabled,date_added,date_modified,comment FROM blacklist;
ALTER TABLE regex_whitelist ADD COLUMN type INTEGER;
UPDATE regex_whitelist SET type = 2;
INSERT INTO domainlist (type,domain,enabled,date_added,date_modified,comment)
SELECT type,domain,enabled,date_added,date_modified,comment FROM regex_whitelist;
ALTER TABLE regex_blacklist ADD COLUMN type INTEGER;
UPDATE regex_blacklist SET type = 3;
INSERT INTO domainlist (type,domain,enabled,date_added,date_modified,comment)
SELECT type,domain,enabled,date_added,date_modified,comment FROM regex_blacklist;
DROP TABLE whitelist_by_group;
DROP TABLE blacklist_by_group;
DROP TABLE regex_whitelist_by_group;
DROP TABLE regex_blacklist_by_group;
CREATE TABLE domainlist_by_group
(
domainlist_id INTEGER NOT NULL REFERENCES domainlist (id),
group_id INTEGER NOT NULL REFERENCES "group" (id),
PRIMARY KEY (domainlist_id, group_id)
);
DROP TRIGGER tr_whitelist_update;
DROP TRIGGER tr_blacklist_update;
DROP TRIGGER tr_regex_whitelist_update;
DROP TRIGGER tr_regex_blacklist_update;
CREATE TRIGGER tr_domainlist_update AFTER UPDATE ON domainlist
BEGIN
UPDATE domainlist SET date_modified = (cast(strftime('%s', 'now') as int)) WHERE domain = NEW.domain;
END;
DROP VIEW vw_whitelist;
CREATE VIEW vw_whitelist AS SELECT domain, domainlist.id AS id, domainlist_by_group.group_id AS group_id
FROM domainlist
LEFT JOIN domainlist_by_group ON domainlist_by_group.domainlist_id = domainlist.id
LEFT JOIN "group" ON "group".id = domainlist_by_group.group_id
WHERE domainlist.enabled = 1 AND (domainlist_by_group.group_id IS NULL OR "group".enabled = 1)
AND domainlist.type = 0
ORDER BY domainlist.id;
DROP VIEW vw_blacklist;
CREATE VIEW vw_blacklist AS SELECT domain, domainlist.id AS id, domainlist_by_group.group_id AS group_id
FROM domainlist
LEFT JOIN domainlist_by_group ON domainlist_by_group.domainlist_id = domainlist.id
LEFT JOIN "group" ON "group".id = domainlist_by_group.group_id
WHERE domainlist.enabled = 1 AND (domainlist_by_group.group_id IS NULL OR "group".enabled = 1)
AND domainlist.type = 1
ORDER BY domainlist.id;
DROP VIEW vw_regex_whitelist;
CREATE VIEW vw_regex_whitelist AS SELECT domain, domainlist.id AS id, domainlist_by_group.group_id AS group_id
FROM domainlist
LEFT JOIN domainlist_by_group ON domainlist_by_group.domainlist_id = domainlist.id
LEFT JOIN "group" ON "group".id = domainlist_by_group.group_id
WHERE domainlist.enabled = 1 AND (domainlist_by_group.group_id IS NULL OR "group".enabled = 1)
AND domainlist.type = 2
ORDER BY domainlist.id;
DROP VIEW vw_regex_blacklist;
CREATE VIEW vw_regex_blacklist AS SELECT domain, domainlist.id AS id, domainlist_by_group.group_id AS group_id
FROM domainlist
LEFT JOIN domainlist_by_group ON domainlist_by_group.domainlist_id = domainlist.id
LEFT JOIN "group" ON "group".id = domainlist_by_group.group_id
WHERE domainlist.enabled = 1 AND (domainlist_by_group.group_id IS NULL OR "group".enabled = 1)
AND domainlist.type = 3
ORDER BY domainlist.id;
UPDATE info SET value = 6 WHERE property = 'version';
COMMIT;

@ -27,6 +27,17 @@ listname=""
colfile="/opt/pihole/COL_TABLE"
source ${colfile}
getTypeID() {
if [[ "$1" == "whitelist" ]]; then
echo "0"
elif [[ "$1" == "blacklist" ]]; then
echo "1"
elif [[ "$1" == "regex_whitelist" ]]; then
echo "2"
elif [[ "$1" == "regex_blacklist" ]]; then
echo "3"
fi
}
helpFunc() {
if [[ "${listType}" == "whitelist" ]]; then
@ -129,13 +140,14 @@ ProcessDomainList() {
}
AddDomain() {
local domain list num
local domain list num typeID
# Use printf to escape domain. %q prints the argument in a form that can be reused as shell input
domain="$1"
list="$2"
typeID="$(getTypeID "${list}")"
# Is the domain in the list we want to add it to?
num="$(sqlite3 "${gravityDBfile}" "SELECT COUNT(*) FROM ${list} WHERE domain = '${domain}';")"
num="$(sqlite3 "${gravityDBfile}" "SELECT COUNT(*) FROM domainlist WHERE domain = '${domain}' AND type = ${typeID};")"
if [[ "${num}" -ne 0 ]]; then
if [[ "${verbose}" == true ]]; then
@ -151,17 +163,18 @@ AddDomain() {
reload=true
# Insert only the domain here. The enabled and date_added fields will be filled
# with their default values (enabled = true, date_added = current timestamp)
sqlite3 "${gravityDBfile}" "INSERT INTO ${list} (domain) VALUES ('${domain}');"
sqlite3 "${gravityDBfile}" "INSERT INTO domainlist (domain,type) VALUES ('${domain}',${typeID});"
}
RemoveDomain() {
local domain list num
local domain list num typeID
# Use printf to escape domain. %q prints the argument in a form that can be reused as shell input
domain="$1"
list="$2"
typeID="$(getTypeID "${list}")"
# Is the domain in the list we want to remove it from?
num="$(sqlite3 "${gravityDBfile}" "SELECT COUNT(*) FROM ${list} WHERE domain = '${domain}';")"
num="$(sqlite3 "${gravityDBfile}" "SELECT COUNT(*) FROM domainlist WHERE domain = '${domain}' AND type = ${typeID};")"
if [[ "${num}" -eq 0 ]]; then
if [[ "${verbose}" == true ]]; then
@ -176,14 +189,15 @@ RemoveDomain() {
fi
reload=true
# Remove it from the current list
sqlite3 "${gravityDBfile}" "DELETE FROM ${list} WHERE domain = '${domain}';"
sqlite3 "${gravityDBfile}" "DELETE FROM domainlist WHERE domain = '${domain}' AND type = ${typeID};"
}
Displaylist() {
local list listname count num_pipes domain enabled status nicedate
local list listname count num_pipes domain enabled status nicedate typeID
listname="${listType}"
data="$(sqlite3 "${gravityDBfile}" "SELECT domain,enabled,date_modified FROM ${listType};" 2> /dev/null)"
typeID="$(getTypeID "${listType}")"
data="$(sqlite3 "${gravityDBfile}" "SELECT domain,enabled,date_modified FROM domainlist WHERE type = ${typeID};" 2> /dev/null)"
if [[ -z $data ]]; then
echo -e "Not showing empty list"
@ -221,7 +235,9 @@ Displaylist() {
}
NukeList() {
sqlite3 "${gravityDBfile}" "DELETE FROM ${listType};"
local typeID
typeID=$(getTypeID "${list}")
sqlite3 "${gravityDBfile}" "DELETE FROM domainlist WHERE type = ${typeID};"
}
for var in "$@"; do

Loading…
Cancel
Save