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

Commit

Permalink
Merge 9c3feb5 into 46c05c1
Browse files Browse the repository at this point in the history
  • Loading branch information
DJensen94 committed Nov 8, 2021
2 parents 46c05c1 + 9c3feb5 commit 781f7e9
Showing 1 changed file with 103 additions and 43 deletions.
146 changes: 103 additions & 43 deletions src/pe_reports/data/data_schema.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,3 @@
--
-- PostgreSQL database dump
--

Expand All @@ -15,19 +14,56 @@ CREATE TABLE IF NOT EXISTS public.organizations
(
organizations_uid uuid default uuid_generate_v1() NOT NULL,
name text NOT NULL,
root_domains text[],
cyhy_db_name text,
UNIQUE(name),
PRIMARY KEY (organizations_uid)
);

-- Organization's Domains Table
CREATE TABLE IF NOT EXISTS public.domains
-- Organization's Root Domains Table
CREATE TABLE IF NOT EXISTS public.root_domains
(
domain_uid uuid default uuid_generate_v1() NOT NULL,
root_domain_uid uuid default uuid_generate_v1() NOT NULL,
organizations_uid uuid NOT NULL,
organization_name text NOT NULL,
root_domain text NOT NULL,
ip_address text,
PRIMARY KEY (domain_uid)
UNIQUE(root_domain, organizations_uid),
PRIMARY KEY (root_domain_uid)
);

-- Organization's Sub Domains Table
CREATE TABLE IF NOT EXISTS public.sub_domains
(
sub_domain_uid uuid default uuid_generate_v1() NOT NULL,
sub_domain text NOT NULL,
root_domain_uid uuid NOT NULL,
root_domain text NOT NULL,
UNIQUE(sub_domain, root_domain_uid),
PRIMARY KEY (sub_domain_uid)
);

-- Organization's Sub Domains web_assets Link Table
CREATE TABLE IF NOT EXISTS Sub_domains_Web_assets
(
sub_domain_uid uuid NOT NULL,
asset_uid uuid NOT NULL,
PRIMARY KEY (sub_domain_uid, asset_uid)
);

-- Organization's IPs Table
CREATE TABLE IF NOT EXISTS public.web_assets
(
asset_uid uuid default uuid_generate_v1() NOT NULL,
asset_type text Not NULL,
asset text NOT NULL,
ip_type text,
verified boolean,
organizations_uid uuid NOT NULL,
asset_origin text,
report_on boolean DEFAULT TRUE,
last_scanned timestamp,
UNIQUE(asset),
PRIMARY KEY (asset_uid)
);

-- Organization's Aliases Table
Expand All @@ -36,6 +72,7 @@ CREATE TABLE IF NOT EXISTS public.alias
alias_uid uuid default uuid_generate_v1() NOT NULL,
organizations_uid uuid NOT NULL,
alias text NOT NULL,
UNIQUE (alias),
PRIMARY KEY (alias_uid)
);

Expand All @@ -51,20 +88,23 @@ CREATE TABLE IF NOT EXISTS public.executives

-- Reporting Tables ----
-- Domain Masquerading Table
CREATE TABLE IF NOT EXISTS public."DNSTwist"
CREATE TABLE IF NOT EXISTS public."dnstwist_domain_masq"
(
dnstwist_uid uuid default uuid_generate_v1() NOT NULL,
"discoveredBy" uuid NOT NULL,
"domain-name" text,
"dns-a" text,
"dns-aaaa" text,
"dns-mx" text,
"dns-ns" text,
fuzzer text,
"date-observed" text,
"ssdeep-score" text,
suspected_domain_uid uuid default uuid_generate_v1() NOT NULL,
organizations_uid uuid NOT NULL,
PRIMARY KEY (dnstwist_uid)
"domain_permutation" text,
"ipv4" text,
"ipv6" text,
"mail_server" text,
"name_server" text,
fuzzer text,
"date_observed" date,
"ssdeep_score" text,
"malicious" boolean,
"blocklist_attack_count" integer,
"blocklist_report_count" integer,
UNIQUE ("domain_permutation"),
PRIMARY KEY (suspected_domain_uid)
);

-- Dark Web Alerts Table
Expand All @@ -73,7 +113,7 @@ CREATE TABLE IF NOT EXISTS public.alerts
alerts_uid uuid default uuid_generate_v1() NOT NULL,
alert_name text,
content text,
date text,
date date,
sixgill_id text,
read text,
severity text,
Expand All @@ -82,6 +122,9 @@ CREATE TABLE IF NOT EXISTS public.alerts
threats text,
title text,
user_id text,
category text,
lang text,
UNIQUE (sixgill_id),
organizations_uid uuid NOT NULL,
PRIMARY KEY (alerts_uid)
);
Expand All @@ -94,18 +137,20 @@ CREATE TABLE IF NOT EXISTS public.mentions
collection_date text,
content text,
creator text,
date text,
date date,
sixgill_mention_id text,
post_id text,
lang 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,
tags text,
UNIQUE (sixgill_mention_id),
organizations_uid uuid NOT NULL,
PRIMARY KEY (mentions_uid)
);
Expand Down Expand Up @@ -134,7 +179,6 @@ CREATE TABLE IF NOT EXISTS public.shodan_insecure_protocols_unverified_vulns
UNIQUE (organizations_uid, ip, port, protocol, timestamp),
PRIMARY KEY (insecure_product_uid)
);

--Shodan Veriried Vulnerabilities table
CREATE TABLE IF NOT EXISTS public.shodan_verified_vulns
(
Expand Down Expand Up @@ -168,7 +212,6 @@ CREATE TABLE IF NOT EXISTS public.shodan_verified_vulns
UNIQUE (organizations_uid, ip, port, protocol, timestamp),
PRIMARY KEY (verified_vuln_uid)
);

--Shodan Assets and IPs table
CREATE TABLE IF NOT EXISTS public.shodan_assets
(
Expand All @@ -194,7 +237,6 @@ CREATE TABLE IF NOT EXISTS public.shodan_assets
CREATE TABLE IF NOT EXISTS public.hibp_breaches
(
hibp_breaches_uid uuid default uuid_generate_v1() NOT NULL,
breach_id uuid NOT NULL,
breach_name text NOT NULL,
description text,
exposed_cred_count bigint,
Expand All @@ -208,6 +250,7 @@ CREATE TABLE IF NOT EXISTS public.hibp_breaches
is_sensitive boolean,
is_retired boolean,
is_spam_list boolean,
UNIQUE (breach_name),
PRIMARY KEY (hibp_breaches_uid)
);

Expand All @@ -220,7 +263,8 @@ CREATE TABLE IF NOT EXISTS public.hibp_exposed_credentials
root_domain text,
sub_domain text,
breach_name text,
breach_id uuid NOT NULL,
modified_date timestamp without time zone,
breach_id uuid NOT NULL,
UNIQUE (email, breach_name),
PRIMARY KEY (hibp_exposed_credentials_uid)
);
Expand All @@ -233,7 +277,7 @@ CREATE TABLE IF NOT EXISTS public.cybersix_exposed_credentials
breach_date date,
breach_id integer,
breach_name text NOT NULL,
create_time timestamp without time zone[],
create_time timestamp without time zone,
description text,
domain text,
email text NOT NULL,
Expand All @@ -242,37 +286,55 @@ CREATE TABLE IF NOT EXISTS public.cybersix_exposed_credentials
login_id text,
name text,
phone text,
UNIQUE (email, breach_id),
PRIMARY KEY (csg_exposed_credentials_uid)
);

-- Top CVEs
CREATE TABLE IF NOT EXISTS public.top_cves
(
top_cves_uid uuid default uuid_generate_v1() NOT NULL,
type text,
cve text,
description text,
top_cves_uid uuid default uuid_generate_v1() NOT NULL,
cve_id text,
dynamic_rating text,
nvd_base_score text,
date date,
summary text,
UNIQUE (cve_id, date),
PRIMARY KEY (top_cves_uid)
);


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

-- One to many relation between Organization and DNSTwist results
ALTER TABLE public."DNSTwist"
-- One to many relation between root domains and sub Domains
ALTER TABLE public.sub_domains
ADD FOREIGN KEY (root_domain_uid)
REFERENCES public.root_domains (root_domain_uid)
NOT VALID;

-- many to many relation between sub domains and IPs
ALTER TABLE public.Sub_domains_Web_assets
ADD FOREIGN KEY (sub_domain_uid)
REFERENCES public.sub_domains (sub_domain_uid)
NOT VALID,
ADD FOREIGN KEY (asset_uid)
REFERENCES public.web_assets (asset_uid)
NOT VALID;

-- One to many relation between orgs and web_assets
ALTER TABLE public.web_assets
ADD FOREIGN KEY (organizations_uid)
REFERENCES public.organizations (organizations_uid)
NOT VALID;

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

-- One to many relation between Organization and Shodan Assets
Expand Down Expand Up @@ -329,11 +391,9 @@ ALTER TABLE public.alerts
REFERENCES public.organizations (organizations_uid)
NOT VALID;


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


-- Views --
-- HIBP complete breach view
Create View vw_breach_complete
Expand All @@ -345,6 +405,6 @@ SELECT creds.hibp_exposed_credentials_uid,creds.email, creds.breach_name, creds.
FROM hibp_exposed_credentials as creds

JOIN hibp_breaches as b
ON creds.breach_id = b.breach_id;
ON creds.breach_id = b.hibp_breaches_uid;

END;

0 comments on commit 781f7e9

Please sign in to comment.