Skip to content
This repository has been archived by the owner on Feb 14, 2024. It is now read-only.

Commit

Permalink
Merge pull request #43 from cisagov/ss-wip-dark-sql
Browse files Browse the repository at this point in the history
Add dark web schema to sql
  • Loading branch information
schmelz21 committed Sep 9, 2021
2 parents 4d2075c + 3730321 commit 572e3ec
Showing 1 changed file with 138 additions and 40 deletions.
178 changes: 138 additions & 40 deletions src/pe_reports/data/data_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,8 +6,8 @@
-- Includes Domain Masquerading, Credentals Exposed, Inffered Vulns, and Dark Web data

BEGIN;

-- Organizations table
-- Organization Assets --
-- Organization's Table
CREATE TABLE IF NOT EXISTS public.organizations
(
organization_id text NOT NULL,
Expand All @@ -16,7 +16,7 @@ CREATE TABLE IF NOT EXISTS public.organizations
PRIMARY KEY (organization_id)
);

-- Domains table
-- Organization's Domains Table
CREATE TABLE IF NOT EXISTS public.domains
(
domain_id text NOT NULL,
Expand All @@ -26,6 +26,26 @@ CREATE TABLE IF NOT EXISTS public.domains
PRIMARY KEY (domain_id)
);

-- Organization's Aliases Table
CREATE TABLE public.alias
(
alias_id text NOT NULL,
organization_id text NOT NULL,
alias text NOT NULL,
PRIMARY KEY (alias_id)
);

-- Organization's Evecutives Table
CREATE TABLE public.executives
(
executives_id text NOT NULL,
organization_id text NOT NULL,
executives text NOT NULL,
PRIMARY KEY (executives_id)
);


-- Reporting Tables ----
-- Domain Masquerading Table
CREATE TABLE IF NOT EXISTS public."DNSTwist"
(
Expand All @@ -43,25 +63,50 @@ CREATE TABLE IF NOT EXISTS public."DNSTwist"
PRIMARY KEY (id)
);

-- One to many relation between Organization and Domains
ALTER TABLE public.domains
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;

-- One to many relation between Organization and DNSTwist results
ALTER TABLE public."DNSTwist"
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;
-- Dark Web Alerts Table
CREATE TABLE public.alerts
(
id text NOT NULL,
alert_name text,
content text,
date text,
sixgill_id text,
read text,
severity text,
site text,
threat_level text,
threats text,
title text,
user_id text,
organization_id text NOT NULL,
PRIMARY KEY (id)
);

-- One to many relation between Domains and DNSTwist results
ALTER TABLE public."DNSTwist"
ADD FOREIGN KEY ("discoveredBy")
REFERENCES public.domains ("domain_id")
NOT VALID;
-- Dark Web Mentions Table
CREATE TABLE public.mentions
(
id text NOT NULL,
category text,
collection_date text,
content text,
creator text,
date text,
post_id text,
rep_grade text,
site text,
site_grade text,
title text,
type text,
url text,
tags text,
comments_count text,
sub_category text,
query text,
organization_id text NOT NULL,
PRIMARY KEY (id)
);

-- HIBP breaches table
-- HIBP breaches Table
CREATE TABLE IF NOT EXISTS public.hibp_breaches
(
breach_name text NOT NULL,
Expand All @@ -79,7 +124,7 @@ CREATE TABLE IF NOT EXISTS public.hibp_breaches
PRIMARY KEY (breach_name)
);

-- HIBP exposed credentials table
-- HIBP Exposed Credentials Table
CREATE TABLE IF NOT EXISTS public.hibp_exposed_credentials
(
credential_id serial,
Expand All @@ -91,25 +136,7 @@ CREATE TABLE IF NOT EXISTS public.hibp_exposed_credentials
PRIMARY KEY (credential_id)
);

ALTER TABLE public.hibp_exposed_credentials
ADD FOREIGN KEY (breach_name)
REFERENCES public.hibp_breaches (breach_name)
NOT VALID;

-- HIBP complete breach view
Create View vw_breach_complete
AS
SELECT creds.credential_id,creds.email, creds.breach_name, creds.root_domain, creds.sub_domain,
b.description, b.breach_date, b.added_date, b.modified_date, b.data_classes,
b.password_included, b.is_verified, b.is_fabricated, b.is_sensitive, b.is_retired, b.is_spam_list

FROM hibp_exposed_credentials as creds

JOIN hibp_breaches as b
ON creds.breach_name = b.breach_name;


-- Cyber Six Gill exposed credentials table
-- Cyber Six Gill Exposed Credentials Table
CREATE TABLE IF NOT EXISTS public.cybersix_exposed_credentials
(
credential_id serial,
Expand All @@ -128,5 +155,76 @@ CREATE TABLE IF NOT EXISTS public.cybersix_exposed_credentials
PRIMARY KEY (credential_id)
);

-- Top CVEs
CREATE TABLE public.top_cves
(
id text NOT NULL,
type text,
cve text,
description text,
PRIMARY KEY (id)
);


-- Table Relatinships --
-- One to many relation between Organization and Domains
ALTER TABLE public.domains
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;

-- One to many relation between Organization and DNSTwist results
ALTER TABLE public."DNSTwist"
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;

-- One to many relation between Domains and DNSTwist results
ALTER TABLE public."DNSTwist"
ADD FOREIGN KEY ("discoveredBy")
REFERENCES public.domains ("domain_id")
NOT VALID;

-- One to many relation between Organization and Domains
ALTER TABLE public.hibp_exposed_credentials
ADD FOREIGN KEY (breach_name)
REFERENCES public.hibp_breaches (breach_name)
NOT VALID;

-- One to many relation between Organization and Aliases
ALTER TABLE public.alias
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;

-- One to many relation between Organization and Executives
ALTER TABLE public.executives
ADD FOREIGN KEY (organization_id)
REFERENCES public.organizations (organization_id)
NOT VALID;

-- One to many relation between Organization and SixGill Alert API
ALTER TABLE public.organizations
ADD FOREIGN KEY (organization_id)
REFERENCES public.alerts (organization_id)
NOT VALID;

-- One to Many Relationship for Mentions
-- Represented in complex SixGill "query": API.


-- Views --
-- HIBP complete breach view
Create View vw_breach_complete
AS
SELECT creds.credential_id,creds.email, creds.breach_name, creds.root_domain, creds.sub_domain,
b.description, b.breach_date, b.added_date, b.modified_date, b.data_classes,
b.password_included, b.is_verified, b.is_fabricated, b.is_sensitive, b.is_retired, b.is_spam_list

FROM hibp_exposed_credentials as creds

JOIN hibp_breaches as b
ON creds.breach_name = b.breach_name;


END;

0 comments on commit 572e3ec

Please sign in to comment.