From: Mark Schouten Date: Fri, 14 Nov 2014 11:42:56 +0000 (+0100) Subject: Enable foreign keys for Sqlite3 X-Git-Tag: dnsdist-1.0.0-alpha1~59^2~4^2~4 X-Git-Url: https://granicus.if.org/sourcecode?a=commitdiff_plain;h=948280123c3bf87b1d6a06c7cb563f0801062fdf;p=pdns Enable foreign keys for Sqlite3 --- diff --git a/modules/gsqlite3backend/enable_foreign_keys.sql b/modules/gsqlite3backend/enable_foreign_keys.sql new file mode 100644 index 000000000..f543f1ad0 --- /dev/null +++ b/modules/gsqlite3backend/enable_foreign_keys.sql @@ -0,0 +1,139 @@ +-- Disable foreign keys, if any +PRAGMA foreign_keys = 0; + +-- Replace records-table +BEGIN TRANSACTION; + CREATE TEMPORARY TABLE records_backup ( + id INTEGER PRIMARY KEY, + domain_id INTEGER DEFAULT NULL, + name VARCHAR(255) DEFAULT NULL, + type VARCHAR(10) DEFAULT NULL, + content VARCHAR(65535) DEFAULT NULL, + ttl INTEGER DEFAULT NULL, + prio INTEGER DEFAULT NULL, + change_date INTEGER DEFAULT NULL, + disabled BOOLEAN DEFAULT 0, + ordername VARCHAR(255), + auth BOOL DEFAULT 1 + ); + + INSERT INTO records_backup SELECT id,domain_id,name,type,content,ttl,prio,change_date,disabled,ordername,auth FROM records; + DROP TABLE records; + + CREATE TABLE records ( + id INTEGER PRIMARY KEY, + domain_id INTEGER DEFAULT NULL, + name VARCHAR(255) DEFAULT NULL, + type VARCHAR(10) DEFAULT NULL, + content VARCHAR(65535) DEFAULT NULL, + ttl INTEGER DEFAULT NULL, + prio INTEGER DEFAULT NULL, + change_date INTEGER DEFAULT NULL, + disabled BOOLEAN DEFAULT 0, + ordername VARCHAR(255), + auth BOOL DEFAULT 1, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE + ); + + CREATE INDEX rec_name_index ON records(name); + CREATE INDEX nametype_index ON records(name,type); + CREATE INDEX domain_id ON records(domain_id); + CREATE INDEX orderindex ON records(ordername); + + INSERT INTO records SELECT id,domain_id,name,type,content,ttl,prio,change_date,disabled,ordername,auth FROM records_backup; + DROP TABLE records_backup; +COMMIT; + +-- Replace comments-table +BEGIN TRANSACTION; + CREATE TEMPORARY TABLE comments_backup ( + id INTEGER PRIMARY KEY, + domain_id INTEGER NOT NULL, + name VARCHAR(255) NOT NULL, + type VARCHAR(10) NOT NULL, + modified_at INT NOT NULL, + account VARCHAR(40) DEFAULT NULL, + comment VARCHAR(65535) NOT NULL + ); + + INSERT INTO comments_backup SELECT id,domain_id,name,type,modified_at,account,comment FROM comments; + DROP TABLE comments; + + CREATE TABLE comments ( + id INTEGER PRIMARY KEY, + domain_id INTEGER NOT NULL, + name VARCHAR(255) NOT NULL, + type VARCHAR(10) NOT NULL, + modified_at INT NOT NULL, + account VARCHAR(40) DEFAULT NULL, + comment VARCHAR(65535) NOT NULL, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE + ); + + CREATE INDEX comments_domain_id_index ON comments (domain_id); + CREATE INDEX comments_nametype_index ON comments (name, type); + CREATE INDEX comments_order_idx ON comments (domain_id, modified_at); + + INSERT INTO comments SELECT id,domain_id,name,type,modified_at,account,comment FROM comments_backup; + DROP TABLE comments_backup; +COMMIT; + +-- Replace domainmetadata-table +BEGIN TRANSACTION; + CREATE TEMPORARY TABLE domainmetadata_backup ( + id INTEGER PRIMARY KEY, + domain_id INT NOT NULL, + kind VARCHAR(32) COLLATE NOCASE, + content TEXT + ); + + INSERT INTO domainmetadata_backup SELECT id,domain_id,kind,content FROM domainmetadata; + DROP TABLE domainmetadata; + + CREATE TABLE domainmetadata ( + id INTEGER PRIMARY KEY, + domain_id INT NOT NULL, + kind VARCHAR(32) COLLATE NOCASE, + content TEXT, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE + ); + + CREATE INDEX domainmetaidindex ON domainmetadata(domain_id); + + INSERT INTO domainmetadata SELECT id,domain_id,kind,content FROM domainmetadata_backup; + DROP TABLE domainmetadata_backup; +COMMIT; + +-- Replace cryptokeys-table +BEGIN TRANSACTION; + CREATE TEMPORARY TABLE cryptokeys_backup ( + id INTEGER PRIMARY KEY, + domain_id INT NOT NULL, + flags INT NOT NULL, + active BOOL, + content TEXT + ); + + INSERT INTO cryptokeys_backup SELECT id,domain_id,flags,active,content FROM cryptokeys; + DROP TABLE cryptokeys; + + CREATE TABLE cryptokeys ( + id INTEGER PRIMARY KEY, + domain_id INT NOT NULL, + flags INT NOT NULL, + active BOOL, + content TEXT, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE + ); + + CREATE INDEX domainidindex ON cryptokeys(domain_id); + INSERT INTO cryptokeys_backup SELECT id,domain_id,flags,active,content FROM cryptokeys; + DROP TABLE cryptokeys_backup; +COMMIT; + +-- Check the current database for FOREIGN_KEYS after enabling it again +PRAGMA foreign_keys = 1; + +-- This command checks the status of the constraints. Output is in the form of: +-- [table]|[id]|[referred table]|[id])(which is probably 0, since the constraint fails)] +PRAGMA foreign_key_check; diff --git a/modules/gsqlite3backend/gsqlite3backend.cc b/modules/gsqlite3backend/gsqlite3backend.cc index 88faa45f0..aa41b2911 100644 --- a/modules/gsqlite3backend/gsqlite3backend.cc +++ b/modules/gsqlite3backend/gsqlite3backend.cc @@ -32,6 +32,8 @@ gSQLite3Backend::gSQLite3Backend( const std::string & mode, const std::string & SSQLite3::result_t res; ptr->doQuery("PRAGMA synchronous="+getArg("pragma-synchronous"), res); } + SSQLite3::result_t res; + ptr->doQuery("PRAGMA foreign_keys = 1", res); } catch( SSqlException & e ) { diff --git a/modules/gsqlite3backend/schema.sqlite3.sql b/modules/gsqlite3backend/schema.sqlite3.sql index 7cdd2b878..4748a8ddd 100644 --- a/modules/gsqlite3backend/schema.sqlite3.sql +++ b/modules/gsqlite3backend/schema.sqlite3.sql @@ -1,3 +1,5 @@ +PRAGMA foreign_keys = 1; + CREATE TABLE domains ( id INTEGER PRIMARY KEY, name VARCHAR(255) NOT NULL COLLATE NOCASE, @@ -22,7 +24,8 @@ CREATE TABLE records ( change_date INTEGER DEFAULT NULL, disabled BOOLEAN DEFAULT 0, ordername VARCHAR(255), - auth BOOL DEFAULT 1 + auth BOOL DEFAULT 1, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE INDEX rec_name_index ON records(name); @@ -47,7 +50,8 @@ CREATE TABLE comments ( type VARCHAR(10) NOT NULL, modified_at INT NOT NULL, account VARCHAR(40) DEFAULT NULL, - comment VARCHAR(65535) NOT NULL + comment VARCHAR(65535) NOT NULL, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE INDEX comments_domain_id_index ON comments (domain_id); @@ -59,7 +63,8 @@ CREATE TABLE domainmetadata ( id INTEGER PRIMARY KEY, domain_id INT NOT NULL, kind VARCHAR(32) COLLATE NOCASE, - content TEXT + content TEXT, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE INDEX domainmetaidindex ON domainmetadata(domain_id); @@ -70,7 +75,8 @@ CREATE TABLE cryptokeys ( domain_id INT NOT NULL, flags INT NOT NULL, active BOOL, - content TEXT + content TEXT, + FOREIGN KEY(domain_id) REFERENCES domains(id) ON DELETE CASCADE ON UPDATE CASCADE ); CREATE INDEX domainidindex ON cryptokeys(domain_id); diff --git a/regression-tests.nobackend/gsqlite3-fk-insert/command b/regression-tests.nobackend/gsqlite3-fk-insert/command new file mode 100755 index 000000000..963cea02a --- /dev/null +++ b/regression-tests.nobackend/gsqlite3-fk-insert/command @@ -0,0 +1,6 @@ +#!/usr/bin/env bash + + +echo "PRAGMA foreign_keys = 1; INSERT INTO comments (domain_id, name, type, modified_at, account, comment) VALUES (9999, 'test', 'test', 0, 'test', 'Test 123');" | sqlite3 ../regression-tests/pdns.sqlite3 2>&1 + +exit 0 diff --git a/regression-tests.nobackend/gsqlite3-fk-insert/description b/regression-tests.nobackend/gsqlite3-fk-insert/description new file mode 100644 index 000000000..4824925c5 --- /dev/null +++ b/regression-tests.nobackend/gsqlite3-fk-insert/description @@ -0,0 +1 @@ +Check if we can insert a comment for a non-existing zone. We shouldn't be able to do that diff --git a/regression-tests.nobackend/gsqlite3-fk-insert/expected_result b/regression-tests.nobackend/gsqlite3-fk-insert/expected_result new file mode 100644 index 000000000..57af8962f --- /dev/null +++ b/regression-tests.nobackend/gsqlite3-fk-insert/expected_result @@ -0,0 +1 @@ +Error: near line 1: FOREIGN KEY constraint failed diff --git a/regression-tests.nobackend/gsqlite3-fk-remove/command b/regression-tests.nobackend/gsqlite3-fk-remove/command new file mode 100755 index 000000000..ae10a1660 --- /dev/null +++ b/regression-tests.nobackend/gsqlite3-fk-remove/command @@ -0,0 +1,8 @@ +#!/usr/bin/env bash + +echo "PRAGMA foreign_keys = 1; INSERT INTO domains (id, name, type) VALUES (9999, 'test', 'Master');" | sqlite3 ../regression-tests/pdns.sqlite3 2>&1 +echo "PRAGMA foreign_keys = 1; INSERT INTO comments (domain_id, name, type, modified_at, account, comment) VALUES (9999, 'test', 'test', 0, 'test', 'Test 123');" | sqlite3 ../regression-tests/pdns.sqlite3 2>&1 +echo "PRAGMA foreign_keys = 1; DELETE FROM domains WHERE id = 9999;" | sqlite3 ../regression-tests/pdns.sqlite3 2>&1 +echo "PRAGMA foreign_keys = 1; SELECT * FROM comments WHERE domain_id = 9999;" | sqlite3 ../regression-tests/pdns.sqlite3 2>&1 + +exit 0 diff --git a/regression-tests.nobackend/gsqlite3-fk-remove/description b/regression-tests.nobackend/gsqlite3-fk-remove/description new file mode 100644 index 000000000..250ed16b9 --- /dev/null +++ b/regression-tests.nobackend/gsqlite3-fk-remove/description @@ -0,0 +1,2 @@ +If we create a zone, add a comment and remove the zone, the comment should be +gone too. diff --git a/regression-tests.nobackend/gsqlite3-fk-remove/expected_result b/regression-tests.nobackend/gsqlite3-fk-remove/expected_result new file mode 100644 index 000000000..e69de29bb