aboutsummaryrefslogtreecommitdiff
path: root/internal/dbstore/sql
diff options
context:
space:
mode:
authorPaul Duncan <pabs@pablotron.org>2022-02-04 18:39:23 -0500
committerPaul Duncan <pabs@pablotron.org>2022-02-04 18:39:23 -0500
commitdd04d8fa0d12afcbfe54b8ad273f55ad0750e553 (patch)
tree5b38f694b2aa75df8fbeae171161230497d758eb /internal/dbstore/sql
parentd1f55e2626513dd8a77a6c6ad204f4ec843f2ad0 (diff)
downloadcvez-dd04d8fa0d12afcbfe54b8ad273f55ad0750e553.tar.bz2
cvez-dd04d8fa0d12afcbfe54b8ad273f55ad0750e553.zip
mv internal/dbstore/testdata/sql internal/dbstore/sql
Diffstat (limited to 'internal/dbstore/sql')
-rw-r--r--internal/dbstore/sql/fill-fts.sql10
-rw-r--r--internal/dbstore/sql/init.sql73
-rw-r--r--internal/dbstore/sql/insert-cpe.sql1
-rw-r--r--internal/dbstore/sql/insert-ref.sql1
-rw-r--r--internal/dbstore/sql/insert-title.sql1
5 files changed, 86 insertions, 0 deletions
diff --git a/internal/dbstore/sql/fill-fts.sql b/internal/dbstore/sql/fill-fts.sql
new file mode 100644
index 0000000..5329ca7
--- /dev/null
+++ b/internal/dbstore/sql/fill-fts.sql
@@ -0,0 +1,10 @@
+-- populate fts table
+INSERT INTO cpe_fts(rowid, title)
+ SELECT a.cpe_id,
+ COALESCE(b.val, '')
+
+ FROM cpes a
+ LEFT JOIN cpe_titles b
+ ON (b.cpe_id = a.cpe_id)
+
+ WHERE b.lang = 'en-US';
diff --git a/internal/dbstore/sql/init.sql b/internal/dbstore/sql/init.sql
new file mode 100644
index 0000000..a08b2f8
--- /dev/null
+++ b/internal/dbstore/sql/init.sql
@@ -0,0 +1,73 @@
+-- enable foreign keys
+PRAGMA foreign_keys = true;
+
+-- create cpes table
+CREATE TABLE cpes (
+ cpe_id INTEGER PRIMARY KEY,
+
+ -- cpe uri
+ cpe_uri TEXT UNIQUE NOT NULL,
+
+ -- cpe 2.3 formatting string
+ cpe23 TEXT UNIQUE NOT NULL
+);
+
+-- create titles table
+CREATE TABLE cpe_titles (
+ -- external CPE id
+ cpe_id INT NOT NULL
+ REFERENCES cpes(cpe_id),
+
+ -- language code
+ lang TEXT NOT NULL,
+
+ -- text value
+ val TEXT NOT NULL,
+
+ UNIQUE (cpe_id, lang)
+);
+
+-- create titles fts table
+CREATE VIRTUAL TABLE cpe_titles_fts USING fts5(title, tokenize = 'porter');
+
+-- create titles insert trigger
+CREATE TRIGGER tr_cpe_titles_insert AFTER INSERT ON cpe_titles
+ FOR EACH ROW WHEN (NEW.lang = 'en-US') BEGIN
+ INSERT INTO cpe_titles_fts(rowid, title) VALUES (NEW.cpe_id, NEW.val);
+ END;
+
+-- create titles delete trigger
+CREATE TRIGGER tr_cpe_titles_delete BEFORE DELETE ON cpe_titles
+ FOR EACH ROW WHEN (OLD.lang = 'en-US') BEGIN
+ DELETE FROM cpe_titles_fts WHERE rowid = OLD.cpe_id;
+ END;
+
+-- create refs table
+CREATE TABLE cpe_refs (
+ -- external CPE id
+ cpe_id INT NOT NULL
+ REFERENCES cpes(cpe_id),
+
+ -- url
+ href TEXT NOT NULL,
+
+ -- text description
+ val TEXT NOT NULL
+);
+
+-- create refs fts
+CREATE VIRTUAL TABLE cpe_refs_fts USING fts5(cpe_id UNINDEXED, href, val);
+
+-- create refs insert trigger
+CREATE TRIGGER tr_cpe_refs_insert AFTER INSERT ON cpe_refs
+ FOR EACH ROW BEGIN
+ INSERT INTO cpe_refs_fts(cpe_id, href, val) VALUES (NEW.cpe_id, NEW.href, NEW.val);
+ END;
+
+-- create refs delete trigger
+CREATE TRIGGER tr_cpe_refs_delete BEFORE DELETE ON cpe_refs
+ FOR EACH ROW BEGIN
+ DELETE FROM cpe_refs_fts WHERE rowid = OLD.cpe_id;
+ END;
+
+PRAGMA user_version = 314159;
diff --git a/internal/dbstore/sql/insert-cpe.sql b/internal/dbstore/sql/insert-cpe.sql
new file mode 100644
index 0000000..dca1c2b
--- /dev/null
+++ b/internal/dbstore/sql/insert-cpe.sql
@@ -0,0 +1 @@
+INSERT INTO cpes(cpe_uri, cpe23) VALUES (?, ?);
diff --git a/internal/dbstore/sql/insert-ref.sql b/internal/dbstore/sql/insert-ref.sql
new file mode 100644
index 0000000..a39ab1c
--- /dev/null
+++ b/internal/dbstore/sql/insert-ref.sql
@@ -0,0 +1 @@
+INSERT INTO cpe_refs(cpe_id, href, val) VALUES (?, ?, ?);
diff --git a/internal/dbstore/sql/insert-title.sql b/internal/dbstore/sql/insert-title.sql
new file mode 100644
index 0000000..5045d95
--- /dev/null
+++ b/internal/dbstore/sql/insert-title.sql
@@ -0,0 +1 @@
+INSERT INTO cpe_titles(cpe_id, lang, val) VALUES (?, ?, ?);