1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
|
-- enable foreign keys
PRAGMA foreign_keys = true;
-- set database version
PRAGMA user_version = 314159;
-- create cpes table
CREATE TABLE cpes (
-- cpe unique ID
cpe_id INTEGER PRIMARY KEY,
-- cpe uri
cpe_uri TEXT UNIQUE NOT NULL CHECK (
LENGTH(cpe_uri) > 5 AND
cpe_uri LIKE 'cpe:/%'
),
-- cpe 2.3 formatting string
cpe23 TEXT UNIQUE NOT NULL CHECK (
LENGTH(cpe23) > 28 AND
cpe23 LIKE 'cpe:2.3:%:%:%:%:%:%:%:%:%:%:%'
)
);
-- create all fts table (cross join across all
-- titles and references, populated by triggers)
CREATE VIRTUAL TABLE cpe_fts_all USING fts5(
-- parent CPE id
cpe_id UNINDEXED,
-- title
title,
-- reference URL
href,
-- reference name
val,
-- use porter stemming
tokenize = 'porter'
);
-- create titles table
CREATE TABLE cpe_titles (
-- title primary key
cpe_title_id INTEGER PRIMARY KEY,
-- external CPE id
cpe_id INT NOT NULL
REFERENCES cpes(cpe_id),
-- language code
lang TEXT NOT NULL
CHECK (LENGTH(lang) >= 2),
-- text value
val TEXT NOT NULL
CHECK (LENGTH(val) > 0),
-- prevent duplicate titles of the same name
UNIQUE (cpe_id, lang)
);
-- create titles fts table
CREATE VIRTUAL TABLE cpe_fts_titles USING fts5(
-- parent CPE id
cpe_id UNINDEXED,
-- title
title,
-- use porter stemming
tokenize = 'porter'
);
-- create titles all fts insert trigger
CREATE TRIGGER tr_cpe_titles_insert_fts_all AFTER INSERT ON cpe_titles
FOR EACH ROW WHEN (NEW.lang = 'en-US') BEGIN
INSERT INTO cpe_fts_all(cpe_id, title, href, val)
SELECT NEW.cpe_id,
NEW.val,
b.href,
b.val
FROM cpes a
JOIN cpe_refs b
ON (b.cpe_id = a.cpe_id)
WHERE a.cpe_id = NEW.cpe_id;
END;
-- create titles delete all fts trigger
CREATE TRIGGER tr_cpe_titles_delete_fts_all BEFORE DELETE ON cpe_titles
FOR EACH ROW WHEN (OLD.lang = 'en-US') BEGIN
DELETE FROM cpe_fts_all
WHERE cpe_id = OLD.cpe_id
AND title = OLD.val;
END;
-- create titles all fts insert trigger
CREATE TRIGGER tr_cpe_titles_insert_fts_titles AFTER INSERT ON cpe_titles
FOR EACH ROW WHEN (NEW.lang = 'en-US') BEGIN
INSERT INTO cpe_fts_titles(cpe_id, title) VALUES (NEW.cpe_id, NEW.val);
END;
-- create titles delete titles fts trigger
CREATE TRIGGER tr_cpe_titles_delete_fts_titles BEFORE DELETE ON cpe_titles
FOR EACH ROW WHEN (OLD.lang = 'en-US') BEGIN
DELETE FROM cpe_fts_titles
WHERE cpe_id = OLD.cpe_id
AND title = OLD.val;
END;
-- create refs table
CREATE TABLE cpe_refs (
-- reference unique id
cpe_ref_id INTEGER PRIMARY KEY,
-- external CPE id
cpe_id INT NOT NULL
REFERENCES cpes(cpe_id),
-- url
href TEXT NOT NULL CHECK (
LENGTH(href) > 0 AND
(href LIKE 'http://%' OR href LIKE 'https://%')
),
-- text description
val TEXT NOT NULL
CHECK (LENGTH(val) > 0)
);
-- create refs fts table
CREATE VIRTUAL TABLE cpe_fts_refs USING fts5(
-- parent CPE id
cpe_id UNINDEXED,
-- reference URL
href,
-- reference name
val,
-- use porter stemming
tokenize = 'porter'
);
-- create refs insert trigger for all fts
CREATE TRIGGER tr_cpe_refs_insert_fts_all AFTER INSERT ON cpe_refs
FOR EACH ROW BEGIN
INSERT INTO cpe_fts_all(cpe_id, title, href, val)
SELECT NEW.cpe_id,
b.val,
NEW.href,
NEW.val
FROM cpes a
JOIN cpe_titles b
ON (b.cpe_id = a.cpe_id)
WHERE a.cpe_id = NEW.cpe_id
AND b.lang = 'en-US';
END;
-- create refs delete trigger for all fts
CREATE TRIGGER tr_cpe_refs_delete_fts_all BEFORE DELETE ON cpe_refs
FOR EACH ROW BEGIN
DELETE FROM cpe_fts_all
WHERE cpe_id = OLD.cpe_id
AND href = OLD.lang
AND val = OLD.val;
END;
-- create refs insert trigger for refs fts
CREATE TRIGGER tr_cpe_refs_insert_fts_refs AFTER INSERT ON cpe_refs
FOR EACH ROW BEGIN
INSERT INTO cpe_fts_refs(cpe_id, href, val) VALUES (NEW.cpe_id, NEW.href, NEW.val);
END;
-- create refs delete trigger for refs fts
CREATE TRIGGER tr_cpe_refs_delete_fts_refs BEFORE DELETE ON cpe_refs
FOR EACH ROW BEGIN
DELETE FROM cpe_fts_refs
WHERE cpe_id = OLD.cpe_id
AND href = OLD.lang
AND val = OLD.val;
END;
--
-- cpe matches table
--
CREATE TABLE cpe_matches (
-- cpe match unique ID
cpe_match_id INTEGER PRIMARY KEY,
-- modern CPE 2.3 formatted string
cpe23 TEXT UNIQUE NOT NULL CHECK (
LENGTH(cpe23) > 28 AND
cpe23 LIKE 'cpe:2.3:%:%:%:%:%:%:%:%:%:%:%'
),
-- old CPE 2.2 URI
cpe22_uri TEXT NOT NULL
);
-- cpe match vulnerabilities
CREATE TABLE cpe_match_vulnerables (
cpe_match_id INTEGER PRIMARY KEY,
-- true if this match is vulnerable, and false
-- otherwise
is_vulnerable BOOLEAN NOT NULL,
-- add foreign key constraint
FOREIGN KEY (cpe_match_id)
REFERENCES cpe_matches(cpe_match_id)
);
--
-- cpe match version minimums (e.g. version starts)
--
CREATE TABLE cpe_match_version_mins (
cpe_match_id INTEGER PRIMARY KEY,
-- valid values
--
-- * true: boundary includes this version (e.g. it was specified by
-- versionStartIncluding)
-- * false: boundary excludes this version (e.g., it was specified by
-- versionStartExcluding)
is_inclusive BOOLEAN NOT NULL,
-- minimum version
min_version TEXT NOT NULL
CHECK (LENGTH(min_version) > 0),
-- add foreign key constraint
FOREIGN KEY (cpe_match_id)
REFERENCES cpe_matches(cpe_match_id)
);
--
-- cpe match version maximums (e.g. version ends)
--
CREATE TABLE cpe_match_version_maxs (
-- cpe match unique id
cpe_match_id INTEGER PRIMARY KEY,
-- valid values
--
-- * true: boundary includes this version (e.g. it was specified by
-- versionEndIncluding)
-- * false: boundary excludes this version (e.g., it was specified by
-- versionEndExcluding)
is_inclusive BOOLEAN NOT NULL,
-- maximum version
max_version TEXT NOT NULL
CHECK (LENGTH(max_version) > 0),
-- add foreign key constraint
FOREIGN KEY (cpe_match_id)
REFERENCES cpe_matches(cpe_match_id)
);
-- map of matching
CREATE TABLE cpe_match_cpes (
-- CPE match ID
cpe_match_id INTEGER NOT NULL
REFERENCES cpe_matches(cpe_match_id),
-- CPE ID
cpe_id INTEGER NOT NULL
REFERENCES cpes(cpe_id),
-- nullable cpe22 URI
-- normally we would want this in a separate table, but
-- we don't care that much about this value
cpe22_uri TEXT NOT NULL,
PRIMARY KEY (cpe_match_id, cpe_id)
);
--
-- Descriptions of CVEs and CVE problem types.
--
CREATE TABLE descriptions (
-- description unique ID
desc_id INTEGER PRIMARY KEY,
-- description language
lang TEXT NOT NULL
CHECK (LENGTH(lang) >= 2),
-- description text
value TEXT NOT NULL CHECK (
LENGTH(value) > 0
)
);
--
-- CVE feeds.
--
CREATE TABLE feeds (
-- feed unique ID
feed_id INTEGER PRIMARY KEY,
-- time that feed was added
created_at TIMESTAMP WITH TIME ZONE NOT NULL
DEFAULT CURRENT_TIMESTAMP,
-- data timestamp
data_time TIMESTAMP WITH TIME ZONE NOT NULL
);
--
-- CVE feed items.
--
CREATE TABLE feed_items (
item_id INTEGER PRIMARY KEY,
-- feed that this CVE belongs to
feed_id INTEGER NOT NULL
REFERENCES feeds(feed_id),
-- published timestamp
published_at TIMESTAMP WITH TIME ZONE NOT NULL,
-- last modified timestamp
modified_at TIMESTAMP WITH TIME ZONE NOT NULL
);
-- create index
CREATE INDEX in_feed_items_feed_id ON feed_items(feed_id);
--
-- CVE assigners
--
CREATE TABLE assigners (
-- assigner unique ID
assigner_id INTEGER PRIMARY KEY,
-- assigner value
assigner TEXT UNIQUE NOT NULL CHECK (
LENGTH(assigner) > 0
)
);
--
-- CVEs
--
-- NOTE: this combines the concept of an "item" and a "cve" from the
-- source feed. maybe we should split them up again?
--
CREATE TABLE cves (
-- CVE unique ID
cve_id INTEGER PRIMARY KEY,
-- feed item that this CVE belongs to
item_id INTEGER NOT NULL
REFERENCES feed_items(item_id),
-- year of NVD CVE ID, (e.g. the "XXXX" in "CVE-XXXX-YYYY")
cve_year SMALLINT NOT NULL CHECK (
cve_year BETWEEN 1999 AND 2126
),
-- number of NVD CVE ID, (e.g. the "YYYY" in "CVE-XXXX-YYYY")
cve_num INT NOT NULL CHECK (
-- there is no upper bound, but let's pick
-- something sane
cve_num BETWEEN 1 AND 33554432
),
-- assigner ID
assigner_id INTEGER NOT NULL
REFERENCES assigners(assigner_id)
);
-- create index
CREATE INDEX in_cves_item_id ON cves(item_id);
--
-- NVD CVE IDs (e.g. "CVE-YYYY-NNNN").
--
CREATE VIEW cve_nvd_ids AS
SELECT cve_id,
printf('CVE-%04d-%04d', cve_year, cve_num) AS nvd_id
FROM cves;
--
-- CVE descriptions
--
CREATE TABLE cve_descriptions (
-- CVE unique ID
cve_id INTEGER NOT NULL
REFERENCES cves(cve_id),
-- description unique ID
desc_id INTEGER NOT NULL
REFERENCES descriptions(desc_id),
PRIMARY KEY (cve_id, desc_id)
);
-- create index
CREATE INDEX in_cve_descriptions_cve_id ON cve_descriptions(cve_id);
--
-- CVE problem types
--
CREATE TABLE cve_problems (
-- problem type unique ID
pt_id INTEGER PRIMARY KEY,
-- CVE that this problem type belongs to
cve_id INTEGER NOT NULL
REFERENCES cves(cve_id)
);
-- create index
CREATE INDEX in_cve_problems_cve_id ON cve_problems(cve_id);
--
-- CVE problem type descriptions
--
CREATE TABLE cve_problem_descriptions (
-- problem type that this description belongs to
pt_id INTEGER NOT NULL
REFERENCES cve_problems(pt_id),
-- description unique ID
desc_id INTEGER NOT NULL
REFERENCES descriptions(desc_id),
PRIMARY KEY (pt_id, desc_id)
);
--
-- CVE references
--
CREATE TABLE cve_refs (
-- cve reference unique ID
cve_ref_id INTEGER PRIMARY KEY,
-- CVE unique ID
cve_id INTEGER NOT NULL
REFERENCES cves(cve_id),
-- reference URL
url TEXT NOT NULL CHECK (
-- FIXME: not sure about length here
LENGTH(url) BETWEEN 7 AND 1024
),
-- reference name
name TEXT NOT NULL CHECK (
-- FIXME: not sure about length here
LENGTH(name) BETWEEN 1 AND 1024
),
-- reference name
source TEXT NOT NULL
);
-- create index
CREATE INDEX in_cve_refs_cve_id ON cve_refs(cve_id);
--
-- cve reference tags
--
CREATE TABLE cve_ref_tags (
cve_ref_id INTEGER NOT NULL
REFERENCES cve_refs(cve_ref_id),
-- tag
tag TEXT NOT NULL CHECK (
-- FIXME: not sure about maximum length
LENGTH(tag) BETWEEN 1 AND 128
),
-- prevent duplicate tags
UNIQUE (cve_ref_id, tag)
);
-- create index
CREATE INDEX in_cve_ref_tags_cve_ref_id ON cve_ref_tags(cve_ref_id);
--
-- CVSS severities.
--
CREATE TABLE severities (
-- severity unique ID
severity_id INTEGER PRIMARY KEY,
-- severity name
name TEXT UNIQUE NOT NULL CHECK (
-- limit to know severities
name IN ('NONE', 'LOW', 'MEDIUM', 'HIGH', 'CRITICAL')
),
-- severity sort order, from low to high
sort SMALLINT UNIQUE NOT NULL
);
-- add severities
INSERT INTO severities(severity_id, name, sort) VALUES
(1, 'NONE', 1),
(2, 'LOW', 2),
(3, 'MEDIUM', 3),
(4, 'HIGH', 4),
(5, 'CRITICAL', 5);
--
-- item cvss v2 impacts
--
CREATE TABLE item_cvss_v2_impacts (
-- feed item that this impact belongs to
item_id INTEGER NOT NULL
REFERENCES feed_items(item_id),
-- cvss v2 version
-- FIXME: don't need this, check during import
-- v2_version TEXT NOT NULL CHECK (
-- LENGTH(v2_version) > 0
-- ),
-- cvss v2 vector
v2_vector TEXT NOT NULL CHECK (
-- TODO: enforce this
LENGTH(v2_vector) > 0
),
-- cvss v2 base score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v2_base_score TINYINT NOT NULL CHECK (
v2_base_score BETWEEN 0 AND 100
),
-- cvss v2 severity
v2_severity_id INTEGER NOT NULL
REFERENCES severities(severity_id),
-- cvss v2 impact score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v2_impact_score TINYINT NOT NULL CHECK (
v2_impact_score BETWEEN 0 AND 100
),
-- cvss v2 exploitability score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v2_expl_score TINYINT NOT NULL CHECK (
v2_expl_score BETWEEN 0 AND 100
),
-- cvss v2 insufficient info
v2_insufficient_info BOOLEAN NOT NULL,
-- cvss v2 insufficient info
v2_obtain_all_priv BOOLEAN NOT NULL,
-- cvss v2 obtain user privileges
v2_obtain_user_priv BOOLEAN NOT NULL,
-- cvss v2 obtain other privileges
v2_obtain_other_priv BOOLEAN NOT NULL,
-- cvss v2 user interaction required?
v2_ui_req BOOLEAN NOT NULL
);
-- create indices
CREATE INDEX in_item_cvss_v2_impacts_item_id ON item_cvss_v2_impacts(item_id);
CREATE INDEX in_item_cvss_v2_impacts_v2_severity_id ON item_cvss_v2_impacts(v2_severity_id);
--
-- item cvss v3 impacts
--
CREATE TABLE item_cvss_v3_impacts (
-- feed item that this impact belongs to
item_id INTEGER NOT NULL
REFERENCES feed_items(item_id),
-- FIXME: don't need this, check during import
-- v3_version TEXT NOT NULL CHECK (
-- LENGTH(v3_version) > 0
-- ),
-- cvss v3 vector
v3_vector TEXT NOT NULL CHECK (
-- TODO: enforce this
LENGTH(v3_vector) > 0 AND
v3_vector LIKE 'CVSS:3._/%'
),
-- cvss v3 base score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v3_base_score TINYINT NOT NULL CHECK (
v3_base_score BETWEEN 0 AND 100
),
-- cvss v3 base severity
v3_severity_id INTEGER NOT NULL
REFERENCES severities(severity_id),
-- cvss v3 exploitability score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v3_expl_score TINYINT NOT NULL CHECK (
v3_expl_score BETWEEN 0 AND 100
),
-- cvss v3 impact score
-- (NOTE: multiplied by 10 and stored as a tinyint)
v3_impact_score TINYINT NOT NULL CHECK (
v3_impact_score BETWEEN 0 AND 100
)
);
-- create indices
CREATE INDEX in_item_cvss_v3_impacts_item_id ON item_cvss_v3_impacts(item_id);
CREATE INDEX in_item_cvss_v3_impacts_v3_severity_id ON item_cvss_v3_impacts(v3_severity_id);
--
-- create cve all fts table
--
-- join across all of the following:
-- * NVD CVE ID
-- * assigner
-- * cve description(s)
-- * cve problem type description(s)
-- * cve reference(s) (url, name, source, and tags)
-- * cvss v2 severity name
-- * cvss v3 severity name
--
-- this virtual table is populated and cleared by triggers on the
-- corresponding cve tables (see triggers below).
--
CREATE VIRTUAL TABLE cve_fts_all USING fts5(
-- parent CVE id
cve_id UNINDEXED,
-- NVD CVE ID (e.g. CVE-XXXX-YYYY)
nvd_id,
-- CVE assigner
assigner,
-- CVE descriptions
cve_descs,
-- problem type descriptions
pt_descs,
-- reference URL
ref_url,
-- reference name
ref_name,
-- reference source
ref_source,
-- reference tags
ref_tags,
-- use porter stemming
tokenize = 'porter'
);
--
-- Dummy table to trigger cve_fts refreshes.
--
CREATE TABLE cve_fts_refresh (
created_at TIMESTAMP WITH TIME ZONE NOT NULL
DEFAULT CURRENT_TIMESTAMP
);
-- create before insert trigger on cve_fts_refresh
CREATE TRIGGER tr_cve_fts_refresh_before_insert
BEFORE INSERT ON cve_fts_refresh
FOR EACH ROW BEGIN
DELETE FROM cve_fts_all;
END;
--
-- create insert trigger on cve_fts_refresh
--
-- Notes:
-- * test sizes:
-- - no index: ~31M
-- - per-table triggers: ~320M
-- - full refresh trigger: ~120M
-- - refresh trigger, group_concat(), IDs/severities removed: 86M
--
-- TODO:
-- - [x] use group_concat() to concatenate tags
-- - [x] remove all IDs except cve_id
-- - [x] remove severities
--
CREATE TRIGGER tr_cve_fts_refresh_after_insert
AFTER INSERT ON cve_fts_refresh
FOR EACH ROW BEGIN
INSERT INTO cve_fts_all(
cve_id,
nvd_id,
assigner,
cve_descs,
pt_descs,
ref_url,
ref_name,
ref_source,
ref_tags
)
SELECT a.cve_id, -- cve_id
b.nvd_id, -- nvd_id
c.assigner, -- assigner
COALESCE(d.descriptions, ''), -- cve_descs
COALESCE(e.descriptions, ''), -- pt_descs
COALESCE(f.url, ''), -- ref_url
COALESCE(f.name, ''), -- ref_name
COALESCE(f.source, ''), -- ref_source
COALESCE(g.tags, '') -- ref_tags
FROM cves a
JOIN cve_nvd_ids b
ON (b.cve_id = a.cve_id)
JOIN assigners c
ON (c.assigner_id = a.assigner_id)
LEFT JOIN (
-- concatenate english cve descriptions
SELECT a.cve_id,
group_concat(b.value) AS descriptions
FROM cve_descriptions a
JOIN descriptions b
ON (b.desc_id = a.desc_id)
WHERE b.lang LIKE 'en%'
GROUP BY a.cve_id
) d ON (d.cve_id = a.cve_id)
LEFT JOIN (
-- concatenate english problem type descriptions
SELECT a.cve_id,
group_concat(c.value) AS descriptions
FROM cve_problems a
JOIN cve_problem_descriptions b
ON (b.pt_id = a.pt_id)
JOIN descriptions c
ON (c.desc_id = b.desc_id)
WHERE c.lang LIKE 'en%'
GROUP BY a.cve_id
) e ON (e.cve_id = a.cve_id)
LEFT JOIN cve_refs f
ON (f.cve_id = a.cve_id)
LEFT JOIN (
-- concatenate reference tags
SELECT cve_ref_id,
group_concat(tag) AS tags
FROM cve_ref_tags
GROUP BY cve_ref_id
) g ON (g.cve_ref_id = f.cve_ref_id);
END;
--
-- CISA Known Exploited Vulnerabilities (KEV) catalogs.
--
CREATE TABLE cisa_catalogs (
-- catalog unique ID
cat_id INTEGER PRIMARY KEY,
-- catalog title
title TEXT NOT NULL CHECK (
-- FIXME: not sure about max length here
LENGTH(title) BETWEEN 1 AND 256
),
-- catalog version
version TEXT NOT NULL CHECK (
LENGTH(version) = 10 AND
version LIKE '____.__.__'
),
-- catalog release date
released_at TIMESTAMP WITH TIME ZONE NOT NULL
);
--
-- CISA catalog vendors and projects.
--
CREATE TABLE cisa_vendors (
-- vendor/project unique ID
vendor_id INTEGER PRIMARY KEY,
-- vendor/project name
name TEXT UNIQUE NOT NULL CHECK (
-- current range: [2, 18]
LENGTH(name) BETWEEN 1 AND 256
)
);
--
-- CISA catalog products.
--
CREATE TABLE cisa_products (
-- product unique ID
product_id INTEGER PRIMARY KEY,
-- product name
name TEXT UNIQUE NOT NULL CHECK (
-- current range: [0, 179]
LENGTH(name) BETWEEN 0 AND 512
)
);
--
-- CISA KEV catalog vulnerabilities
--
-- current vulnerability list field size ranges:
-- name,min,max
-- cveID,13,16
-- dateAdded,10,10
-- dueDate,10,10
-- product,0,179
-- requiredAction,38,79
-- shortDescription,0,1389
-- vendorProject,2,18
-- vulnerabilityName,11,138
CREATE TABLE cisa_vulns (
-- vulnerability unique ID
vuln_id INTEGER PRIMARY KEY,
-- catalog ID
cat_id INTEGER NOT NULL
REFERENCES cisa_catalogs(cat_id),
-- year of NVD CVE ID, (e.g. the "XXXX" in "CVE-XXXX-YYYY")
cve_year SMALLINT NOT NULL CHECK (
cve_year BETWEEN 1999 AND 2126
),
-- number of NVD CVE ID, (e.g. the "YYYY" in "CVE-XXXX-YYYY")
cve_num INT NOT NULL CHECK (
-- there is no upper bound, but let's pick
-- something sane
cve_num BETWEEN 1 AND 33554432
),
-- vendor/project ID
vendor_id INTEGER NOT NULL
REFERENCES cisa_vendors(vendor_id),
-- product ID
product_id INTEGER NOT NULL
REFERENCES cisa_products(product_id),
-- vulnerability name
name TEXT NOT NULL CHECK (
-- current range: [11, 138]
LENGTH(name) BETWEEN 1 AND 1024
),
-- date that vulnerability was added to catalog
added_at DATE NOT NULL,
-- short description of vulnerability
description TEXT NOT NULL CHECK (
-- current range: [0, 1389]
LENGTH(description) BETWEEN 0 AND 2048
),
-- required action
action TEXT NOT NULL CHECK (
-- current range: [38, 79]
LENGTH(action) BETWEEN 1 AND 2048
),
-- date that required action is due
due_at DATE NOT NULL
);
--
-- CISA vulnerability CVE IDs (e.g. "CVE-YYYY-NNNN").
--
CREATE VIEW cisa_vuln_cve_ids AS
SELECT vuln_id,
printf('CVE-%04d-%04d', cve_year, cve_num) AS nvd_id
FROM cisa_vulns;
--
-- create CISA vulnerabilities FTS table
--
-- this virtual table is populated and cleared by triggers on the
-- corresponding cve tables (see triggers below).
--
CREATE VIRTUAL TABLE cisa_vulns_fts USING fts5(
-- parent vulnerability id
vuln_id UNINDEXED,
-- NVD CVE ID (e.g. CVE-XXXX-YYYY)
cve_id,
-- vulnerability vendor/project
vendor,
-- vulnerability product
product,
-- vulnerability name
name,
-- vulnerability description
description,
-- use porter stemming
tokenize = 'porter'
);
--
-- Dummy table to trigger cve_fts refreshes.
--
CREATE TABLE cisa_vulns_fts_refresh (
created_at TIMESTAMP WITH TIME ZONE NOT NULL
DEFAULT CURRENT_TIMESTAMP
);
-- create before insert trigger on cve_fts_refresh
CREATE TRIGGER tr_cisa_vulns_fts_refresh_before_insert
BEFORE INSERT ON cisa_vulns_fts_refresh
FOR EACH ROW BEGIN
DELETE FROM cisa_vulns_fts;
END;
--
-- create insert trigger on cisa_vulns_fts_refresh
--
CREATE TRIGGER tr_cisa_vulns_fts_refresh_after_insert
AFTER INSERT ON cisa_vulns_fts_refresh
FOR EACH ROW BEGIN
INSERT INTO cisa_vulns_fts(
vuln_id,
cve_id,
vendor,
product,
name,
description
)
SELECT a.vuln_id, -- vuln ID
b.nvd_id, -- NVD cve id
c.name, -- vendor name
d.name, -- product name
a.name, -- vuln name
a.description -- vuln description
FROM cisa_vulns a
JOIN cisa_vuln_cve_ids b
ON (b.vuln_id = a.vuln_id)
JOIN cisa_vendors c
ON (c.vendor_id = a.vendor_id)
JOIN cisa_products d
ON (d.product_id = a.product_id);
END;
|