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

Commit

Permalink
Merge 0b88d9e into 78ccbfd
Browse files Browse the repository at this point in the history
  • Loading branch information
aloftus23 committed Sep 26, 2022
2 parents 78ccbfd + 0b88d9e commit 655ef57
Show file tree
Hide file tree
Showing 5 changed files with 742 additions and 296 deletions.
288 changes: 270 additions & 18 deletions src/pe_reports/data/data_schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -480,11 +480,11 @@ CREATE TABLE public.shodan_insecure_protocols_unverified_vulns (
);

--
-- Name: shodan_verified_vulns; Type: TABLE; Schema: public; Owner: pe
-- Name: shodan_vulns; Type: TABLE; Schema: public; Owner: pe
--

CREATE TABLE public.shodan_verified_vulns (
verified_vuln_uid uuid DEFAULT public.uuid_generate_v1() NOT NULL,
CREATE TABLE public.shodan_vulns (
shodan_vuln_uid uuid DEFAULT public.uuid_generate_v1() NOT NULL,
organizations_uid uuid NOT NULL,
organization text,
ip text,
Expand All @@ -511,7 +511,13 @@ CREATE TABLE public.shodan_verified_vulns (
hostnames text[],
isn text,
asn integer,
data_source_uid uuid NOT NULL
data_source_uid uuid NOT NULL,
type text,
name text,
potential_vulns text[],
mitigation text,
server text,
is_verified boolean
);

--
Expand Down Expand Up @@ -835,19 +841,19 @@ ALTER TABLE ONLY public.shodan_insecure_protocols_unverified_vulns


--
-- Name: shodan_verified_vulns shodan_verified_vulns_organizations_uid_ip_port_protocol_ti_key; Type: CONSTRAINT; Schema: public; Owner: pe
-- Name: shodan_vulns shodan_vulns_organizations_uid_ip_port_protocol_ti_key; Type: CONSTRAINT; Schema: public; Owner: pe
--

ALTER TABLE ONLY public.shodan_verified_vulns
ADD CONSTRAINT shodan_verified_vulns_organizations_uid_ip_port_protocol_ti_key UNIQUE (organizations_uid, ip, port, protocol, "timestamp");
ALTER TABLE ONLY public.shodan_vulns
ADD CONSTRAINT shodan_vulns_organizations_uid_ip_port_protocol_ti_key UNIQUE (organizations_uid, ip, port, protocol, "timestamp");


--
-- Name: shodan_verified_vulns shodan_verified_vulns_pkey; Type: CONSTRAINT; Schema: public; Owner: pe
-- Name: shodan_vulns shodan_vulns_pkey; Type: CONSTRAINT; Schema: public; Owner: pe
--

ALTER TABLE ONLY public.shodan_verified_vulns
ADD CONSTRAINT shodan_verified_vulns_pkey PRIMARY KEY (verified_vuln_uid);
ALTER TABLE ONLY public.shodan_vulns
ADD CONSTRAINT shodan_vulns_pkey PRIMARY KEY (shodan_vuln_uid);


--
Expand Down Expand Up @@ -1113,19 +1119,19 @@ ALTER TABLE ONLY public.shodan_insecure_protocols_unverified_vulns


--
-- Name: shodan_verified_vulns shodan_verified_vulns_data_source_uid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: pe
-- Name: shodan_vulns shodan_vulns_data_source_uid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: pe
--

ALTER TABLE ONLY public.shodan_verified_vulns
ADD CONSTRAINT shodan_verified_vulns_data_source_uid_fkey FOREIGN KEY (data_source_uid) REFERENCES public.data_source(data_source_uid) NOT VALID;
ALTER TABLE ONLY public.shodan_vulns
ADD CONSTRAINT shodan_vulns_data_source_uid_fkey FOREIGN KEY (data_source_uid) REFERENCES public.data_source(data_source_uid) NOT VALID;


--
-- Name: shodan_verified_vulns shodan_verified_vulns_organizations_uid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: pe
-- Name: shodan_vulns shodan_vulns_organizations_uid_fkey; Type: FK CONSTRAINT; Schema: public; Owner: pe
--

ALTER TABLE ONLY public.shodan_verified_vulns
ADD CONSTRAINT shodan_verified_vulns_organizations_uid_fkey FOREIGN KEY (organizations_uid) REFERENCES public.organizations(organizations_uid) NOT VALID;
ALTER TABLE ONLY public.shodan_vulns
ADD CONSTRAINT shodan_vulns_organizations_uid_fkey FOREIGN KEY (organizations_uid) REFERENCES public.organizations(organizations_uid) NOT VALID;


--
Expand Down Expand Up @@ -1185,10 +1191,10 @@ ALTER TABLE ONLY public.web_assets


--
-- Name: new_vw_breach_complete; Type: VIEW; Schema: public; Owner: pe
-- Name: new_breachcomp; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW public.new_vw_breach_complete AS
CREATE VIEW public.vw_breachcomp AS
SELECT creds.credential_exposures_uid,
creds.email,
creds.breach_name,
Expand All @@ -1215,6 +1221,252 @@ CREATE VIEW public.new_vw_breach_complete AS
FROM (public.credential_exposures creds
JOIN public.credential_breaches b ON ((creds.credential_breaches_uid = b.credential_breaches_uid)));

--
-- Name: vw_breachcomp_credsbydate; Type: VIEW; Schema: public; Owner: pe
--
CREATE VIEW vw_breachcomp_credsbydate AS
SELECT
organizations_uid,
DATE(modified_date) mod_date,
SUM(CASE password_included WHEN false THEN 1 ELSE 0 END) AS no_password,
SUM(CASE password_included WHEN True THEN 1 ELSE 0 END) AS password_included
FROM vw_breachcomp
GROUP BY organizations_uid,
mod_date
ORDER BY mod_date DESC

--
-- Name: vw_breachcomp_breachdetails; Type: VIEW; Schema: public; Owner: pe
--
CREATE VIEW vw_breachcomp_breachdetails as
SELECT
vb.organizations_uid,
vb.breach_name,
DATE(vb.modified_date) mod_date,
vb.description,
vb.breach_date,
vb.password_included,
COUNT(vb.email) number_of_creds
FROM
vw_breachcomp vb
GROUP BY
vb.organizations_uid,
vb.breach_name,
mod_date,
vb.description,
vb.breach_date,
vb.password_included
ORDER BY mod_date DESC

--
-- Name: vw_shodanvulns_suspected; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_shodanvulns_suspected AS
SELECT
sv.organizations_uid,
sv.organization,
sv.ip,
sv.port,
sv.protocol,
sv.type,
sv."name",
sv.potential_vulns,
sv.mitigation,
sv."timestamp",
sv.product,
sv."server",
sv.tags,
sv.domains,
sv.hostnames,
sv.isn,
sv.asn,
ds."name" as "data_source"
FROM shodan_vulns sv
JOIN data_source ds
ON ds.data_source_uid = sv.data_source_uid
WHERE is_verified = false

--
-- Name: vw_shodanvulns_verified; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_shodanvulns_verified AS
SELECT
sv.organizations_uid,
sv.organization,
sv.ip,
sv.port,
sv.protocol,
sv."timestamp",
sv.cve,
sv.severity,
sv.cvss,
sv.summary,
sv.product,
sv.attack_vector,
sv.av_description ,
sv.attack_complexity,
sv.ac_description,
sv.confidentiality_impact,
sv.ci_description,
sv.integrity_impact,
sv.ii_description,
sv.availability_impact,
sv.ai_description,
sv.tags,
sv.domains,
sv.hostnames,
sv.isn,
sv.asn,
ds."name" as "data_source"
FROM shodan_vulns sv
JOIN data_source as ds
ON ds.data_source_uid = sv.data_source_uid
WHERE is_verified = true

--
-- Name: vw_darkweb_mentionsbydate; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_mentionsbydate AS
SELECT
organizations_uid,
DATE(m."date"),
count(*) as "Count"
FROM mentions m
GROUP BY organizations_uid,
m."date"
ORDER BY m."date" desc;

--
-- Name: vw_darkweb_socmedia_mostactposts; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_socmedia_mostactposts AS
select m.organizations_uid,
m."date",
m.title "Title",
case
when m.comments_count = 'NaN'
then 1
when m.comments_count = '0.0'
then 1
else m.comments_count::numeric::integer
end "Comments Count"
from mentions m
where m.site not like 'forum%' and m.site not like 'market%'
ORDER BY "Comments Count" desc;

--
-- Name: vw_darkweb_mostactposts; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_mostactposts AS
select m.organizations_uid,
m."date",
m.title "Title",
case
when m.comments_count = 'NaN'
then 1
when m.comments_count = '0.0'
then 1
when m.comments_count is null
then 1
else m.comments_count::numeric::integer
end "Comments Count"
from mentions m
where m.site like 'forum%' or m.site like 'market%'
ORDER BY "Comments Count" desc;

--
-- Name: vw_darkweb_assetalerts; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_assetalerts AS
select a.organizations_uid,
max(a."date") as "date",
a.site as "Site",
a.title as "Title",
count(*) as "Events"
from alerts a
where a.alert_name not like '%executive%'
and a.site notnull and a.site != 'NaN'
GROUP BY a.site,
a.title, a.organizations_uid
ORDER BY "Events" desc;

--
-- Name: vw_darkweb_execalerts; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_execalerts AS
select a.organizations_uid,
max(a."date") as "date",
a.site as "Site",
a.title as "Title",
count(*) as "Events"
from alerts a
where a.alert_name like '%executive%'
and a.site notnull and a.site != 'NaN'
GROUP BY a.site,
a.title, a.organizations_uid
ORDER BY "Events" desc;

--
-- Name: vw_darkweb_threatactors; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_threatactors AS
select m.organizations_uid,
m."date",
m.creator as "Creator",
round(m.rep_grade::numeric ,3) as "Grade"
from mentions m
ORDER BY "Grade" desc;

--
-- Name: vw_darkweb_potentialthreats; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_potentialthreats AS
select a.organizations_uid,
a."date" as "date",
a.site as "Site",
btrim(a.threats,'{}') as "Threats"
from alerts a
where a.site notnull and a.site != 'NaN' and a.site != '';

--
-- Name: vw_darkweb_sites; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_sites AS
select m.organizations_uid,
m."date",
m.site as "Site"
from mentions m;

--
-- Name: vw_darkweb_inviteonlymarkets; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_inviteonlymarkets AS
select a.organizations_uid,
a."date" as "date",
a.site as "Site"
from alerts a
where a.site like 'market%'
and a.site notnull and a.site != 'NaN' and a.site != '';

--
-- Name: vw_darkweb_topcves; Type: VIEW; Schema: public; Owner: pe
--

CREATE VIEW vw_darkweb_topcves AS
select *
from top_cves tc
ORDER BY tc."date" DESC LIMIT 10;

--
-- Name: SCHEMA public; Type: ACL; Schema: -; Owner: postgres
Expand Down

0 comments on commit 655ef57

Please sign in to comment.