├── .gitignore ├── Community Reports ├── AssetAuthenticationAccessLevel.sql ├── Authentication_Level_Achieved_with_Current_Credentials.sql ├── Old Jasper Reports (DO NOT USE) │ ├── JasperReports │ │ ├── SQL-JASPER │ │ │ ├── Modified-Default.sql │ │ │ └── RAW-DEFAULT.sql │ │ ├── vulnerability-32aging-32detail │ │ │ ├── META-INF │ │ │ │ ├── MANIFEST.MF │ │ │ │ ├── RAPID7-J.RSA │ │ │ │ └── RAPID7-J.SF │ │ │ ├── vulnerability-aging-detail-site.jasper │ │ │ ├── vulnerability-aging-detail-site.jrxml │ │ │ ├── vulnerability-aging-detail.jasper │ │ │ ├── vulnerability-aging-detail.jrxml │ │ │ └── vulnerability-aging-detail.properties │ │ ├── vulnerability-32aging-32summary │ │ │ ├── META-INF │ │ │ │ ├── MANIFEST.MF │ │ │ │ ├── RAPID7-J.RSA │ │ │ │ └── RAPID7-J.SF │ │ │ ├── vulnerability-aging-summary-groups.jasper │ │ │ ├── vulnerability-aging-summary-groups.jrxml │ │ │ ├── vulnerability-aging-summary-groups.pdf │ │ │ ├── vulnerability-aging-summary-sites.jasper │ │ │ ├── vulnerability-aging-summary-sites.jrxml │ │ │ ├── vulnerability-aging-summary-sites.pdf │ │ │ ├── vulnerability-aging-summary-tags.jasper │ │ │ ├── vulnerability-aging-summary-tags.jrxml │ │ │ ├── vulnerability-aging-summary.jasper │ │ │ ├── vulnerability-aging-summary.jrxml │ │ │ ├── vulnerability-aging-summary.pdf │ │ │ └── vulnerability-aging-summary.properties │ │ └── vulnerability-32count-32comparison │ │ │ ├── META-INF │ │ │ ├── MANIFEST.MF │ │ │ ├── RAPID7-J.RSA │ │ │ └── RAPID7-J.SF │ │ │ ├── nx_ent.jpg │ │ │ ├── vulnerability-count-comparison.jasper │ │ │ ├── vulnerability-count-comparison.jrxml │ │ │ └── vulnerability-count-comparison.properties │ ├── vulnerability-32aging-32detail.nrt │ ├── vulnerability-32aging-32summary.nrt │ ├── vulnerability-32count-32comparison.nrt │ ├── vulnerability-aging-detail-JASPER-DONOTUSE(modified to make your life easier).sql │ └── vulnerability-aging-detail-JASPER-DONOTUSE.sql ├── Patch Tuesday CVEs.sql ├── README.md ├── Sites with Credential Issues.sql ├── Sites_Site-Scopes.sql ├── Unauthenticated-Unmanaged_Assets.sql ├── baseline_remediation_export.sql ├── baseline_unremediated_solutions.sql ├── remediated baseline totals by site.sql ├── solution_export.sql ├── vuln_dashboard_by_site.sql ├── vuln_detail_category.sql └── vuln_detail_dlx_severity.sql ├── Data Warehouse ├── active_vulnerability_exceptions.sql └── nessus_import │ └── nessus_csv_compare_merge.sql ├── Dev-ScratchPad ├── Data Warehouse Reporting │ ├── 2020_DW │ │ ├── DW - Asset Report │ │ │ └── DW_Asset_Report.sql │ │ └── Vulnerability_Detail_DW.sql │ ├── DEV - Vulnerability Exceptions - WH │ │ ├── WH_Vulnerability_Exceptions_by_asset(limited to cvss score 0.1 to 2.9).sql │ │ ├── WH_Vulnerability_Exceptions_by_asset(not-limited).sql │ │ ├── WH_exception_report.sql │ │ ├── test.sql │ │ └── test2.sql │ ├── DEV Reports │ │ └── Detail Aging │ │ │ ├── DATA_WAREHOUSE_REPORT_Vulnerability_Aging_Detail_(includes r7 aging code).sql │ │ │ └── DATA_WAREHOUSE_REPORT_Vulnerability_Aging_Detail_(includes r7 aging code)v2.7.1_DEV.sql │ └── Working_Do_Not_Modify │ │ └── Vulnerability_By_Asset.sql └── Junk-Old │ └── 2019_or_older │ ├── 20190517 │ ├── dev1.sql │ ├── dev2.sql │ └── dev3.sql │ ├── 1568231171420.sql │ ├── Aging_Detail_RAW_REPORTING-DATA-MODEL.sql │ ├── Aging_Detail_RAW_v2.sql │ ├── Aging_Detail_RAW_v3.sql │ ├── Modified-vuln-age-detail.sql │ ├── Psuedo_Working_Aging_Detail_Report_v1.0.sql │ ├── Untitled-1.sql │ ├── Untitled-2.sql │ ├── Untitled-3.sql │ ├── Vuln-Aging.sql │ ├── Vuln_Aging_Detail_old_format.sql │ ├── Vulnerability_Aging_Detail_(includes r7 aging code)_DEV.sql │ ├── Vulnerability_Aging_Detail_UPPER-Hostname.sql │ ├── Vulnerability_Aging_Detail_comments.sql │ ├── Vulnerability_Aging_Detail_replace_blank_hostnames.sql │ ├── Vulnerability_By_Asset_DEV.sql │ ├── Vulnerability_By_Asset_Dev2.sql │ ├── Vulnerability_By_Asset_Dev3.sql │ ├── Vulnerability_By_Asset_Dev4.sql │ ├── alsdgjalg.sql │ ├── alsdgjalg2.sql │ ├── compate-temp.sql │ ├── dev-test-aging_5.sql │ ├── dev-test-agingreport-4.sql │ ├── dev10.sql │ ├── dev11.sql │ ├── dev12.sql │ ├── dev13.sql │ ├── dev14.sql │ ├── dev15.sql │ ├── dev16.1_test.sql │ ├── dev16.sql │ ├── dev2_1.sql │ ├── dev6.sql │ ├── dev7.sql │ ├── dev8.sql │ ├── dev9.sql │ ├── dev_nxpasgjaslrgjalkjga.sql │ └── devtestcopy1.sql ├── InsightVM - Console Reports └── Development │ └── Detail Aging - DEV │ └── Vulnerability_Aging_Detail_(includes r7 aging code).sql ├── LICENSE ├── Prebuilt Queries ├── New_and_Remediated_Vulnerabilities.sql ├── Report_on_a_Single_Vulnerability.sql ├── assets_grouped_count-of-vuln-by-severity.sql ├── assets_grouped_count-of-vuln-by-severity_v3.sql ├── assets_vulns.sql ├── baseline_scan_date.sql ├── current_scan_date.sql ├── hostname_IP_count-of-vuln.sql ├── new_vulns.sql ├── rapid7-vulnerability_aging_dashboard_query.sql ├── remediated_vulns.sql ├── vuln_exploit_count.sql └── vulnerability-trends │ ├── META-INF │ └── MANIFEST.MF │ ├── images │ ├── critical.png │ ├── exploit-vuln.png │ ├── malware-vuln.png │ ├── moderate.png │ ├── severe.png │ ├── total-assets.png │ └── total-vuln.png │ ├── vulnerability-trends.jasper │ ├── vulnerability-trends.jrxml │ ├── vulnerability-trends.properties │ ├── vulnerability-trends_ja_JP.properties │ ├── vulnerability-trends_ko_KR.properties │ ├── vulnerability-trends_zh_CN.properties │ └── vulnerability-trends_zh_HK.properties ├── README.md └── Reports ├── All Vulnerabilities per asset (Filter via console).sql ├── Executive_Report_v5.sql ├── Vulnerability Exceptions ├── Vulnerability_Exceptions_by_asset(limit-to-CVE).sql ├── Vulnerability_Exceptions_by_asset(limit-to-reason_id).sql └── Vulnerability_Exceptions_by_asset(not-limited).sql ├── Vulnerability_Aging_Detail_(includes r7 aging code).sql ├── Vulnerability_Aging_Detail_PRIMARY.sql └── Vulnerability_Detail_(limit to specific CVE) ├── Vulnerability_Detail_v2.7.1_CVE(msft-cve-2019-1214).sql ├── Vulnerability_Detail_v2.7.1_CVE(msft-cve-2019-1215).sql ├── Vulnerability_Detail_v2.9.1_CVE(BLUEKEEP-2).sql ├── Vulnerability_Detail_v2.9.1_CVE(DEJABLUE).sql ├── Vulnerability_Detail_v2.9.1_CVE(Microsoft CVE-2019-0887_Remote Desktop Services Remote Code Execution).sql └── Vulnerability_Detail_v2.9.1_CVE(SACK Panic).sql /Community Reports/AssetAuthenticationAccessLevel.sql: -------------------------------------------------------------------------------- 1 | SELECT ds.name "Site", da.ip_address as "IP Address", da.host_name as "Host Name", dacs.aggregated_credential_status_description "Access Level" 2 | 3 | FROM dim_asset da 4 | 5 | JOIN fact_asset fa using (asset_id) 6 | 7 | JOIN dim_site_asset dsa using (asset_id) 8 | 9 | JOIN dim_site ds using (site_id) 10 | 11 | JOIN dim_aggregated_credential_status dacs using (aggregated_credential_status_id) 12 | 13 | GROUP BY ds.name, da.ip_address, da.host_name, dacs.aggregated_credential_status_description 14 | 15 | ORDER BY da.ip_address DESC -------------------------------------------------------------------------------- /Community Reports/Authentication_Level_Achieved_with_Current_Credentials.sql: -------------------------------------------------------------------------------- 1 | SELECT dsite.name "Site", da.ip_address as "IP Address", da.host_name as "Host Name", ds.name as "Service", dp.description as "Protocol", dcs.credential_status_description "Access Level" 2 | 3 | FROM dim_asset da 4 | 5 | JOIN fact_asset_scan_service fass using (asset_id) 6 | 7 | JOIN fact_asset fa using (asset_id) 8 | 9 | JOIN dim_site_asset dsa using (asset_id) 10 | 11 | JOIN dim_site dsite using (site_id) 12 | 13 | JOIN dim_service ds using (service_id) 14 | 15 | JOIN dim_protocol dp using (protocol_id) 16 | 17 | JOIN dim_credential_status dcs using (credential_status_id) 18 | 19 | GROUP BY dsite.name, da.ip_address, da.host_name, ds.name, dp.description, dcs.credential_status_description 20 | 21 | ORDER BY da.ip_address DESC -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/SQL-JASPER/Modified-Default.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT fav.asset_id 4 | ,fav.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasv.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasv 7 | JOIN fact_asset_vulnerability_instance fav ON fasv.asset_id = fav.asset_id AND fasv.vulnerability_id = fav.vulnerability_id 8 | GROUP BY fav.asset_id, fav.vulnerability_id 9 | ), 10 | asset_metadata AS ( 11 | SELECT da.asset_id 12 | ,ds.name AS site_name 13 | ,da.ip_address AS ip_address 14 | ,da.host_name 15 | FROM dim_asset da 16 | JOIN dim_site_asset dsa ON dsa.asset_id = da.asset_id 17 | JOIN dim_site ds ON ds.site_id = dsa.site_id 18 | ) 19 | SELECT vfa.asset_id 20 | ,am.site_name 21 | ,am.ip_address 22 | ,am.host_name 23 | ,vfa.vulnerability_title 24 | ,vfa.severity 25 | ,vfa.vuln_count 26 | ,vfa.age 27 | , CASE 28 | WHEN vfa.age < 30 THEN '<30' 29 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 30 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '61-90' 31 | ELSE '90+' 32 | END as "Aging" 33 | FROM ( 34 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 35 | SELECT avd.asset_id, dv.title AS vulnerability_title 36 | ,dv.severity_score AS severity 37 | ,avd.vuln_count 38 | ,avd.age 39 | FROM ( 40 | SELECT fav.asset_id 41 | ,fav.vulnerability_id 42 | ,1 AS vuln_count 43 | ,ava.age 44 | FROM asset_vuln_age ava 45 | JOIN fact_asset_vulnerability_finding fav ON fav.asset_id = ava.asset_id AND fav.vulnerability_id = ava.vulnerability_id 46 | GROUP BY fav.asset_id, fav.vulnerability_id, ava.age 47 | ) avd 48 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 49 | ) vfa 50 | JOIN asset_metadata am ON am.asset_id = vfa.asset_id 51 | ORDER BY site_name, ip_address, vulnerability_title -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/SQL-JASPER/RAW-DEFAULT.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT fav.asset_id, fav.vulnerability_id, date_part('days', (CURRENT_DATE - MIN(fasv.date)) + INTERVAL '1 day') AS age 4 | FROM fact_asset_scan_vulnerability_instance fasv 5 | JOIN fact_asset_vulnerability_instance fav ON fasv.asset_id = fav.asset_id AND fasv.vulnerability_id = fav.vulnerability_id 6 | GROUP BY fav.asset_id, fav.vulnerability_id 7 | ), 8 | asset_metadata AS ( 9 | SELECT da.asset_id, ds.name AS site_name, da.ip_address AS ip_address, da.host_name 10 | FROM dim_asset da 11 | JOIN dim_site_asset dsa ON dsa.asset_id = da.asset_id 12 | JOIN dim_site ds ON ds.site_id = dsa.site_id 13 | ) 14 | SELECT vfa.asset_id, am.site_name, am.ip_address, am.host_name, vfa.vulnerability_title, vfa.severity, vfa.vuln_count, vfa.age 15 | FROM ( 16 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 17 | SELECT avd.asset_id, dv.title AS vulnerability_title, dv.severity_score AS severity, avd.vuln_count, avd.age 18 | FROM ( 19 | SELECT fav.asset_id, fav.vulnerability_id, 1 AS vuln_count, ava.age 20 | FROM asset_vuln_age ava 21 | JOIN fact_asset_vulnerability_finding fav ON fav.asset_id = ava.asset_id AND fav.vulnerability_id = ava.vulnerability_id 22 | GROUP BY fav.asset_id, fav.vulnerability_id, ava.age 23 | ) avd 24 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 25 | ) vfa 26 | JOIN asset_metadata am ON am.asset_id = vfa.asset_id 27 | ORDER BY site_name, ip_address, vulnerability_title -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/META-INF/MANIFEST.MF: -------------------------------------------------------------------------------- 1 | Manifest-Version: 1.0 2 | resource-bundle-file: vulnerability-aging-detail.properties 3 | report-engine-version: 1.0.0 4 | main-template-file: vulnerability-aging-detail.jrxml 5 | data-model-version: 1.1.0 6 | 7 | Name: vulnerability-aging-detail-site.jrxml 8 | SHA1-Digest: lv4n4z23OLtn8dQqadpX7cFXAk0= 9 | 10 | Name: vulnerability-aging-detail.jrxml 11 | SHA1-Digest: fhDvn659P1hTz9KQedfvrAB9Nsg= 12 | 13 | Name: vulnerability-aging-detail-site.jasper 14 | SHA1-Digest: O+PN7le7YZZs/bnpLzaGH+8bIIQ= 15 | 16 | Name: vulnerability-aging-detail.jasper 17 | SHA1-Digest: SLsVsHi5w4LUQJdcYqQX5gX4NFw= 18 | 19 | Name: vulnerability-aging-detail.properties 20 | SHA1-Digest: ubo0q0aowM8R7h+cKHRb7LZYTPM= 21 | 22 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/META-INF/RAPID7-J.RSA: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/META-INF/RAPID7-J.RSA -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/META-INF/RAPID7-J.SF: -------------------------------------------------------------------------------- 1 | Signature-Version: 1.0 2 | SHA1-Digest-Manifest-Main-Attributes: KLQGsxJ4YBO2Yb1OkIqMLzrKN3o= 3 | Created-By: 1.6.0_30 (Sun Microsystems Inc.) 4 | SHA1-Digest-Manifest: 6EoYtCP0zYLFTErMSbwdBp42XlE= 5 | 6 | Name: vulnerability-aging-detail-site.jrxml 7 | SHA1-Digest: ZrZmDsN21ubvQXSn4AKaiEozlZA= 8 | 9 | Name: vulnerability-aging-detail.jrxml 10 | SHA1-Digest: jpmpSDrvDOeamtd+qkpz+Nf6fNs= 11 | 12 | Name: vulnerability-aging-detail-site.jasper 13 | SHA1-Digest: QUR2YpXDCX5FemI6cQfJhvAFwzU= 14 | 15 | Name: vulnerability-aging-detail.jasper 16 | SHA1-Digest: PJaG10Y8mu08rcM0BQStmRdeeHQ= 17 | 18 | Name: vulnerability-aging-detail.properties 19 | SHA1-Digest: j94MvhjpHQqvKgWyBCW3KaOnICE= 20 | 21 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/vulnerability-aging-detail-site.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/vulnerability-aging-detail-site.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/vulnerability-aging-detail.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/vulnerability-aging-detail.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32detail/vulnerability-aging-detail.properties: -------------------------------------------------------------------------------- 1 | #page header 2 | title=Vulnerability Aging Report Detail by Site 3 | description=This report groups vulnerabilities by severity level and vulnerability age, which is the number of days since each vulnerability was discovered. The summarization of sites will only include the assets selected within the scope of the report that have a vulnerability instance detected. Use this information to prioritize remediation efforts and verify their success. 4 | 5 | # group headers 6 | site_name=Site: {0} 7 | ip_address=Asset: {0} 8 | 9 | #column headers 10 | moderate=Moderate 11 | severe=Severe 12 | critical=Critical 13 | 14 | # group footers 15 | asset_totals=Total Assets 16 | vuln_totals=Total Vulnerabilities 17 | grand_asset_totals=Grand Total Assets 18 | grand_vuln_totals=Grand Total Vulnerabilities 19 | 20 | #page footer 21 | page_num=Page {0} of 22 | report_date=Report Date 23 | 24 | #no data 25 | no_data=Based on your scan results or configuration settings, there is no data to display. -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/META-INF/MANIFEST.MF: -------------------------------------------------------------------------------- 1 | Manifest-Version: 1.0 2 | resource-bundle-file: vulnerability-aging-summary.properties 3 | report-engine-version: 1.0.0 4 | main-template-file: vulnerability-aging-summary.jrxml 5 | data-model-version: 1.2.0 6 | 7 | Name: vulnerability-aging-summary-tags.jrxml 8 | SHA1-Digest: U34ERSPPfomeRHH9xEQqv4dh+bE= 9 | 10 | Name: vulnerability-aging-summary-groups.jrxml 11 | SHA1-Digest: Q1NypiDhXZCDiQgztYLXsjuZslA= 12 | 13 | Name: vulnerability-aging-summary.jasper 14 | SHA1-Digest: a6UFq32rFwRj3eWdJ9B9HQ75+kg= 15 | 16 | Name: vulnerability-aging-summary-sites.jrxml 17 | SHA1-Digest: O7+yR0BpXCWeHQa3wgN23ALp+MU= 18 | 19 | Name: vulnerability-aging-summary-sites.pdf 20 | SHA1-Digest: /XbeAlWMsXOrOQc5g+VNfpVzdlg= 21 | 22 | Name: vulnerability-aging-summary-groups.pdf 23 | SHA1-Digest: 5RjrbFT2V97WH8iRe/tO6NqkJCw= 24 | 25 | Name: vulnerability-aging-summary-groups.jasper 26 | SHA1-Digest: CLLoQYxEOZrDkl/ZwyBMzjXUsfg= 27 | 28 | Name: vulnerability-aging-summary.jrxml 29 | SHA1-Digest: cCrvYUWC7Bimbesqen0/dxObog8= 30 | 31 | Name: vulnerability-aging-summary-tags.jasper 32 | SHA1-Digest: kz3uVjMaq0I+hl14cFNPAFRUmfA= 33 | 34 | Name: vulnerability-aging-summary.properties 35 | SHA1-Digest: FJy608FwZ2tjHdEG57M3IMKCGaM= 36 | 37 | Name: vulnerability-aging-summary.pdf 38 | SHA1-Digest: 9c8dVIr0/xSWHD9+tdf3EjN4Jx8= 39 | 40 | Name: vulnerability-aging-summary-sites.jasper 41 | SHA1-Digest: 22vEGC7SOnWYUdbgC4C6IBK0vYY= 42 | 43 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/META-INF/RAPID7-J.RSA: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/META-INF/RAPID7-J.RSA -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/META-INF/RAPID7-J.SF: -------------------------------------------------------------------------------- 1 | Signature-Version: 1.0 2 | SHA1-Digest-Manifest-Main-Attributes: lmfnZ1vIIgOb/XxzNtIv5mIQE6M= 3 | Created-By: 1.6.0_30 (Sun Microsystems Inc.) 4 | SHA1-Digest-Manifest: ybDNfN8BQRAIYSItIhIUQLGufXk= 5 | 6 | Name: vulnerability-aging-summary-tags.jrxml 7 | SHA1-Digest: vo1RuG6oh93QQN+Tn+vXdI2Zzxw= 8 | 9 | Name: vulnerability-aging-summary-groups.jrxml 10 | SHA1-Digest: vQmHH5gCI3K3HatcNbOlZ/tPF0Y= 11 | 12 | Name: vulnerability-aging-summary.jasper 13 | SHA1-Digest: TcrwFLZIYRN2iTDU/oyctE7EBzU= 14 | 15 | Name: vulnerability-aging-summary-sites.jrxml 16 | SHA1-Digest: 1V9ncfiQXAsvPoG2bv94lSE4ZxE= 17 | 18 | Name: vulnerability-aging-summary-groups.pdf 19 | SHA1-Digest: F8GQQ/4M8T4Rw9dNB3IO2SBtnjw= 20 | 21 | Name: vulnerability-aging-summary-sites.pdf 22 | SHA1-Digest: 1xM4Ykkh8CQ0d5VF/WCpDTK41rU= 23 | 24 | Name: vulnerability-aging-summary-tags.jasper 25 | SHA1-Digest: y+SYz/P5CFf3ctqks1FCYVubpyY= 26 | 27 | Name: vulnerability-aging-summary.jrxml 28 | SHA1-Digest: qdIQnJ4SHbWs17sUs88C0/VkzE4= 29 | 30 | Name: vulnerability-aging-summary-groups.jasper 31 | SHA1-Digest: xlugGzM/KHQWIRoFxozQ6+9L5pQ= 32 | 33 | Name: vulnerability-aging-summary.pdf 34 | SHA1-Digest: DfLKIvMB4L1sRqNxktj55ZfDdvM= 35 | 36 | Name: vulnerability-aging-summary.properties 37 | SHA1-Digest: cY/5eZK0y7RSo4FvazNx9VnjiSg= 38 | 39 | Name: vulnerability-aging-summary-sites.jasper 40 | SHA1-Digest: AYs3H6c4OD9lLTMLuRKOymTpvYA= 41 | 42 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-groups.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-groups.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-groups.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-groups.pdf -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-sites.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-sites.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-sites.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-sites.pdf -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-tags.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary-tags.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary.pdf: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary.pdf -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32aging-32summary/vulnerability-aging-summary.properties: -------------------------------------------------------------------------------- 1 | #page header 2 | title=Vulnerability Aging Report Summary 3 | description=This report groups vulnerabilities by severity level and vulnerability age, which is the number of days since each vulnerability was discovered. The summarization of sites and groups will only include the assets selected within the scope of the report. Use this information to prioritize remediation efforts and verify their success. 4 | 5 | #column headers 6 | site_name=Site Name 7 | group_name=Group Name 8 | tag_name=Tag Name 9 | asset_count=Assets 10 | vuln_count=Vulnerabilities 11 | moderate=Moderate Vulnerabilities 12 | severe=Severe Vulnerabilities 13 | critical=Critical Vulnerabilities 14 | 15 | #detail band 16 | title_by_site=Sites 17 | title_by_group=Asset Groups 18 | title_by_tag= Tags 19 | 20 | #summary band 21 | total_summary=Total 22 | 23 | #page footer 24 | page_num=Page {0} of 25 | report_date=Report Date 26 | 27 | #no data 28 | no_data=Based on your scan results or configuration settings, there is no data to display. -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/META-INF/MANIFEST.MF: -------------------------------------------------------------------------------- 1 | Manifest-Version: 1.0 2 | resource-bundle-file: vulnerability-count-comparison.properties 3 | report-engine-version: 1.0.0 4 | main-template-file: vulnerability-count-comparison.jrxml 5 | data-model-version: 1.2.0 6 | 7 | Name: vulnerability-count-comparison.properties 8 | SHA1-Digest: B+z7cvMh2Yt0ZkIeXH0aIPOhVyA= 9 | 10 | Name: vulnerability-count-comparison.jrxml 11 | SHA1-Digest: nrofxcrWGq3UZOsGZuQNvVmpoQs= 12 | 13 | Name: nx_ent.jpg 14 | SHA1-Digest: 9MpzZaSlgauK51/trIGJcl0+5rw= 15 | 16 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/META-INF/RAPID7-J.RSA: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/META-INF/RAPID7-J.RSA -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/META-INF/RAPID7-J.SF: -------------------------------------------------------------------------------- 1 | Signature-Version: 1.0 2 | SHA1-Digest-Manifest-Main-Attributes: QzOuzaNVDgQEyZnArXflE/kH8LQ= 3 | Created-By: 1.6.0_30 (Sun Microsystems Inc.) 4 | SHA1-Digest-Manifest: 538UNuZKNYe4mTFc8FvCK7atMrM= 5 | 6 | Name: vulnerability-count-comparison.properties 7 | SHA1-Digest: 5F1RQKPFB2t3hwB5YDN7vWTsSyA= 8 | 9 | Name: vulnerability-count-comparison.jrxml 10 | SHA1-Digest: 38DTWaAJKTQnXJQU1t27czuYpBs= 11 | 12 | Name: nx_ent.jpg 13 | SHA1-Digest: wA1T898pnr2mnGdIFucY5LKCtvU= 14 | 15 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/nx_ent.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/nx_ent.jpg -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/vulnerability-count-comparison.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/vulnerability-count-comparison.jasper -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/JasperReports/vulnerability-32count-32comparison/vulnerability-count-comparison.properties: -------------------------------------------------------------------------------- 1 | # Resource Bundle file. 2 | # 3 | 4 | #page header 5 | title=Vulnerability Count Comparison 6 | description=This report compares vulnerability counts from scans within the the past 30 days (as of the report date) against those from the preceding 30 days. Use this information to track remediation progress and other changes in your security posture. 7 | 8 | #column headers 9 | vulnerability_title=Vulnerability Title 10 | difference=Difference 11 | vulnerability_id=Vulnerability ID 12 | current_date=Count as of 13 | current_total=Current Total 14 | previous_date=Count as of 15 | previous_total=Preceding Total 16 | 17 | #page footer 18 | footer_generated=Generated by Rapid7 Nexpose 19 | page=Page 20 | report_date=Report Date 21 | of=of 22 | 23 | #no data 24 | no_data=Based on your scan results or configuration settings, there is no data to display. 25 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/vulnerability-32aging-32detail.nrt: -------------------------------------------------------------------------------- 1 | 2 | The Vulnerability Aging Detail Report takes this idea one step further and answers "What assets and vulnerabilities am I vulnerable to that have been discovered in the last 30, 60, 90, and 90+ days?". The report offers detailed break-down by site, asset, and vulnerability. Each count displays the total number of instances of that vulnerability found on the asset. You can also see a breakdown of how many assets have at least one vulnerability in each severity and time category, for each site, and across your entire report scope. 3 | 4 | 5 | 6 | 7 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/vulnerability-32aging-32summary.nrt: -------------------------------------------------------------------------------- 1 | 2 | The Vulnerability Aging Summary Report is intended to answer "How many assets in my sites are subject to vulnerabilities discovered n the last 30, 60, 90, and 90+ days?". This C-level summary shows a synopsis of the sites and asset groups that the assets within the scope of your report are associated to. For each site and asset group, a summary of vulnerabilities discovered by severity is presented. The count of vulnerabilities is the number of vulnerabilities for each asset in the site or group. 3 | 4 | 5 | 6 | 7 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/vulnerability-32count-32comparison.nrt: -------------------------------------------------------------------------------- 1 | 2 | This report template provides you with a list of all your vulnerabilities in a selected site(s), asset group(s) or asset(s) and compares the total number of current instances to the number of instances as of 30 days ago. The report template also provides you with a +/- difference from one time period to the other and is sorted descending by the absolute value of the difference, placing large differences, in either direction, at the top of the report. What a great way to see the most prolific vulnerabilities in your environment, monitor remediation efforts and identify problem areas at a glance. Additionally, vulnerabilities that are completely remediated are reported as a "Current" count of 0, showing you which vulnerabilities you have eliminated from from your environment within the reporting period. 3 | 4 | 5 | 6 | 7 | -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/vulnerability-aging-detail-JASPER-DONOTUSE(modified to make your life easier).sql: -------------------------------------------------------------------------------- 1 | WITH 2 | -- 9/6/2019 - Written by Matt Wyen 3 | -- Version: 1.5.3 4 | -- Runs using old data model (1.1.0) 5 | -- dim_vulnerability did not have date_modified as a column in the old data model 6 | asset_vuln_age AS ( 7 | SELECT fav.asset_id 8 | ,fav.vulnerability_id 9 | ,date_part('days', (CURRENT_DATE - MIN(fasv.date)) + INTERVAL '1 day') AS age 10 | FROM fact_asset_scan_vulnerability_instance fasv 11 | JOIN fact_asset_vulnerability_instance fav ON fasv.asset_id = fav.asset_id 12 | AND fasv.vulnerability_id = fav.vulnerability_id 13 | GROUP BY fav.asset_id 14 | ,fav.vulnerability_id 15 | ), 16 | asset_metadata AS ( 17 | SELECT da.asset_id 18 | ,ds.name AS site_name 19 | ,da.ip_address AS ip_address 20 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g')) AS hostname 21 | FROM dim_asset da 22 | JOIN dim_site_asset dsa ON dsa.asset_id = da.asset_id 23 | JOIN dim_site ds ON ds.site_id = dsa.site_id 24 | ) 25 | SELECT vfa.asset_id 26 | ,am.site_name 27 | ,am.ip_address 28 | ,am.hostname 29 | ,CASE 30 | WHEN am.hostname = ' ' THEN vfa.asset_id::TEXT 31 | WHEN am.hostname IS NULL THEN vfa.asset_id::TEXT 32 | WHEN am.hostname IS NOT NULL THEN am.hostname 33 | ELSE vfa.asset_id::TEXT 34 | END as "Hostname Replace Blank" 35 | ,vfa.vulnerability_title 36 | ,vfa.vulnerability_id 37 | ,vfa.nexpose_id 38 | ,vfa.vulnerability_date_published 39 | ,vfa.vulnerability_date_added 40 | ,vfa.severity 41 | ,vfa.vuln_count 42 | ,vfa.age 43 | ,CASE 44 | WHEN vfa.age < 30 THEN '<30' 45 | WHEN vfa.age >= 30 and vfa.age < 60 THEN '30-60' 46 | WHEN vfa.age >= 60 and vfa.age < 90 THEN '60-90' 47 | ELSE '90+' 48 | END as "Aging" 49 | FROM (-- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 50 | SELECT avd.asset_id 51 | ,dv.title AS vulnerability_title 52 | ,dv.severity 53 | ,dv.vulnerability_id 54 | ,dv.nexpose_id 55 | ,dv.date_published AS vulnerability_date_published 56 | ,dv.date_added AS vulnerability_date_added 57 | ,avd.vuln_count 58 | ,avd.age 59 | FROM ( 60 | SELECT fav.asset_id 61 | ,fav.vulnerability_id 62 | ,1 AS vuln_count 63 | ,ava.age 64 | FROM asset_vuln_age ava 65 | JOIN fact_asset_vulnerability_finding fav ON fav.asset_id = ava.asset_id AND fav.vulnerability_id = ava.vulnerability_id 66 | GROUP BY fav.asset_id 67 | ,fav.vulnerability_id 68 | ,ava.age 69 | ) avd 70 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 71 | ) vfa 72 | JOIN asset_metadata am ON am.asset_id = vfa.asset_id 73 | ORDER BY site_name 74 | ,ip_address 75 | ,vulnerability_title -------------------------------------------------------------------------------- /Community Reports/Old Jasper Reports (DO NOT USE)/vulnerability-aging-detail-JASPER-DONOTUSE.sql: -------------------------------------------------------------------------------- 1 | WITH asset_vuln_age AS 2 | (SELECT fav.asset_id, 3 | fav.vulnerability_id, 4 | date_part('days', (CURRENT_DATE - MIN(fasv.date)) + INTERVAL '1 day') AS age 5 | FROM fact_asset_scan_vulnerability_instance fasv 6 | JOIN fact_asset_vulnerability_instance fav ON fasv.asset_id = fav.asset_id 7 | AND fasv.vulnerability_id = fav.vulnerability_id 8 | GROUP BY fav.asset_id, 9 | fav.vulnerability_id), 10 | asset_metadata AS 11 | (SELECT da.asset_id, 12 | ds.name AS site_name, 13 | da.ip_address AS ip_address, 14 | da.host_name 15 | FROM dim_asset da 16 | JOIN dim_site_asset dsa ON dsa.asset_id = da.asset_id 17 | JOIN dim_site ds ON ds.site_id = dsa.site_id) 18 | SELECT vfa.asset_id, 19 | am.site_name, 20 | am.ip_address, 21 | am.host_name, 22 | vfa.vulnerability_title, 23 | vfa.severity, 24 | vfa.vuln_count, 25 | vfa.age 26 | FROM 27 | (-- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 28 | SELECT avd.asset_id, 29 | dv.title AS vulnerability_title, 30 | dv.severity_score AS severity, 31 | avd.vuln_count, 32 | avd.age 33 | FROM 34 | (SELECT fav.asset_id, 35 | fav.vulnerability_id, 36 | 1 AS vuln_count, 37 | ava.age 38 | FROM asset_vuln_age ava 39 | JOIN fact_asset_vulnerability_finding fav ON fav.asset_id = ava.asset_id 40 | AND fav.vulnerability_id = ava.vulnerability_id 41 | GROUP BY fav.asset_id, 42 | fav.vulnerability_id, 43 | ava.age) avd 44 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id) vfa 45 | JOIN asset_metadata am ON am.asset_id = vfa.asset_id 46 | ORDER BY site_name, 47 | ip_address, 48 | vulnerability_title -------------------------------------------------------------------------------- /Community Reports/Patch Tuesday CVEs.sql: -------------------------------------------------------------------------------- 1 | SELECT ds.name AS site, da.ip_address, da.host_name, dv.title AS vulnerability_title, dos.description AS operating_system, dos.cpe 2 | 3 | FROM fact_asset_vulnerability_finding favf 4 | 5 | JOIN dim_asset da USING (asset_id) 6 | 7 | JOIN dim_operating_system dos USING (operating_system_id) 8 | 9 | JOIN dim_vulnerability dv USING (vulnerability_id) 10 | 11 | JOIN dim_site_asset dsa USING (asset_id) 12 | 13 | JOIN dim_site ds USING (site_id) 14 | 15 | WHERE dv.title LIKE 'Microsoft CVE%' 16 | 17 | AND dv.date_published BETWEEN '2018-10-01 00:00:00' AND '2018-10-30 11:59:59' 18 | 19 | ORDER BY da.ip_address ASC, dv.title ASC -------------------------------------------------------------------------------- /Community Reports/README.md: -------------------------------------------------------------------------------- 1 | # InsightVM / Nexpose SQL Reports: Community 2 | 3 | SQL queries for custom reporting 4 | -------------------------------------------------------------------------------- /Community Reports/Sites with Credential Issues.sql: -------------------------------------------------------------------------------- 1 | SELECT ds.name AS site, da.ip_address, da.host_name, dv.title AS vulnerability_title, dos.description AS operating_system, dos.cpe 2 | 3 | FROM fact_asset_vulnerability_finding favf 4 | 5 | JOIN dim_asset da USING (asset_id) 6 | 7 | JOIN dim_operating_system dos USING (operating_system_id) 8 | 9 | JOIN dim_vulnerability dv USING (vulnerability_id) 10 | 11 | JOIN dim_vulnerability_category dvc USING (vulnerability_id) 12 | 13 | JOIN dim_site_asset dsa USING (asset_id) 14 | 15 | JOIN dim_site ds USING (site_id) 16 | 17 | WHERE (dvc.category_name LIKE '%Default Account%') 18 | 19 | ORDER BY ds.name ASC, dv.title ASC -------------------------------------------------------------------------------- /Community Reports/Sites_Site-Scopes.sql: -------------------------------------------------------------------------------- 1 | SELECT a.site_id, a.name, a.description, string_agg(b.target, ' , '), b.scope 2 | FROM dim_site AS a 3 | left join dim_site_target AS b 4 | on a.site_id = b.site_id 5 | GROUP BY a.site_id, a.name, a.description, b.scope 6 | ORDER BY a.site_id ASC -------------------------------------------------------------------------------- /Community Reports/Unauthenticated-Unmanaged_Assets.sql: -------------------------------------------------------------------------------- 1 | SELECT dsite."name" as "Site", da.ip_address, da.host_name, dos.description as "OS", os.certainty_max 2 | 3 | FROM fact_asset AS fa 4 | 5 | JOIN dim_asset da ON da.asset_id = fa.asset_id 6 | 7 | JOIN ( 8 | 9 | SELECT asset_id, MAX(certainty) as certainty_max 10 | 11 | FROM dim_asset_operating_system 12 | 13 | GROUP BY asset_id 14 | 15 | ) os ON fa.asset_id = os.asset_id AND os.certainty_max < 1 16 | 17 | JOIN dim_operating_system as dos 18 | 19 | ON da.operating_system_id = dos.operating_system_id 20 | 21 | JOIN dim_site_asset as dsa 22 | 23 | ON fa.asset_id = dsa.asset_id 24 | 25 | JOIN dim_site as dsite 26 | 27 | ON dsa.site_id = dsite.site_id 28 | 29 | GROUP BY dsite."name", da.ip_address, da.host_name,dos.description, os.certainty_max 30 | 31 | ORDER BY "Site", da.ip_address -------------------------------------------------------------------------------- /Community Reports/baseline_remediation_export.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | assets_vulns as ( 3 | SELECT 4 | fasv.asset_id, 5 | fasv.vulnerability_id, 6 | baselineComparison (fasv.scan_id, current_scan) AS baseline, 7 | s.baseline_scan, 8 | s.current_scan 9 | FROM 10 | fact_asset_scan_vulnerability_instance fasv 11 | JOIN 12 | (SELECT 13 | asset_id, 14 | scanasof (last_assessed_for _vulnerabilities, ('2018-05-01')) AS baseline_scan, --EXTRACT(MONTH FROM dim_asset and make it = 05) 15 | lastScan (asset_id) AS current_scan 16 | FROM dim_asset 17 | ) s ON s.asset_id = fasv.asset_id 18 | 19 | AND ( 20 | fasv.scan_id = s.baseline_scan 21 | OR fasv.scan_id = s.current_scan 22 | ) 23 | 24 | GROUP BY 25 | fasv.asset_id, 26 | fasv.vulnerability_id, 27 | s.baseline_scan, 28 | s.current_scan 29 | 30 | HAVING 31 | (baselineComparison (fasv.scan_id, current_scan) = 'Same') 32 | OR 33 | (baselineComparison (fasv.scan_id, current_scan) = 'New') 34 | OR 35 | (baselineComparison (fasv.scan_id, current_scan) = 'Old') 36 | ), 37 | 38 | baseline_scan_date as ( 39 | 40 | SELECT 41 | av.asset_id, 42 | finished 43 | FROM assets_vulns av 44 | LEFT JOIN dim_scan ds ON ds.scan_id = av.baseline_scan 45 | GROUP BY av.asset_id, finished 46 | ), 47 | 48 | current_scan_date as ( 49 | SELECT 50 | av.asset_id, 51 | finished 52 | FROM assets_vulns av 53 | LEFT JOIN dim_scan ds ON ds.scan_id = av.current_scan 54 | GROUP BY av.asset_id, finished 55 | ), 56 | 57 | new_vulns as ( 58 | SELECT 59 | av.asset_id, 60 | av.vulnerability_id, 61 | COUNT (av.vulnerability_id) AS new_vulns 62 | FROM 63 | assets_vulns AS av 64 | WHERE 65 | av.baseline = 'New' 66 | GROUP BY 67 | av.asset_id, 68 | av.vulnerability_id 69 | ), 70 | 71 | same_vulns as ( 72 | SELECT 73 | av.asset_id, 74 | av.vulnerability_id, 75 | COUNT (av.vulnerability_id) AS same_vulns 76 | FROM 77 | assets_vulns AS av 78 | WHERE 79 | av.baseline = 'Same' 80 | GROUP BY 81 | av.asset_id, 82 | av.vulnerability_id 83 | ), 84 | 85 | remediated_vulns AS ( 86 | SELECT 87 | av.asset_id, 88 | av.vulnerability_id, 89 | COUNT (av.vulnerability_id) AS remediated_vulns 90 | FROM 91 | assets_vulns AS av 92 | WHERE 93 | av.baseline = 'Old' 94 | GROUP BY 95 | av.asset_id, 96 | av.vulnerability_id 97 | ) 98 | 99 | 100 | SELECT 101 | 'Remediated' as status, 102 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv1.vulnerability_id FROM dim_vulnerability)) AS instance_count, 103 | COUNT(dv1.vulnerability_id) AS instance_count, 104 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv1.vulnerability_id) AS unique_1) AS unique 105 | COUNT(DISTINCT dv1.vulnerability_id)AS unique 106 | FROM remediated_vulns rv 107 | --JOIN remediated_unique ru USING (vulnerability_id) 108 | JOIN dim_asset da1 ON da1.asset_id = rv.asset_id 109 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da1.asset_id 110 | LEFT JOIN current_scan_date csd ON csd.asset_id = da1.asset_id 111 | JOIN dim_vulnerability dv1 ON dv1.vulnerability_id = rv.vulnerability_id 112 | UNION ALL 113 | 114 | SELECT 115 | 'New' as status, 116 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv2.vulnerability_id FROM dim_vulnerability)) AS instance_count, 117 | COUNT(dv2.vulnerability_id) AS instance_count, 118 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv2.vulnerability_id) AS unique_1) AS unique 119 | COUNT(DISTINCT dv2.vulnerability_id)AS unique 120 | FROM new_vulns nv 121 | --JOIN new_unique nu USING (vulnerability_id) 122 | JOIN dim_asset as da2 ON da2.asset_id = nv.asset_id 123 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da2.asset_id 124 | LEFT JOIN current_scan_date csd ON csd.asset_id = da2.asset_id 125 | JOIN dim_vulnerability dv2 ON dv2.vulnerability_id = nv.vulnerability_id 126 | UNION ALL 127 | 128 | SELECT 129 | 'Same' as status, 130 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv2.vulnerability_id FROM dim_vulnerability)) AS instance_count, 131 | COUNT(dv3.vulnerability_id) AS instance_count, 132 | --(SELECT COUNT(*) FROM (SELECT DISTINCT dv3.vulnerability_id) AS unique_1) AS unique 133 | COUNT(DISTINCT dv3.vulnerability_id)AS unique 134 | FROM same_vulns sv 135 | --JOIN same_unique su USING (vulnerability_id) 136 | JOIN dim_asset da3 ON da3.asset_id = sv.asset_id 137 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da3.asset_id 138 | LEFT JOIN current_scan_date csd ON csd.asset_id = da3.asset_id 139 | JOIN dim_vulnerability dv3 ON dv3.vulnerability_id = sv.vulnerability_id 140 | -------------------------------------------------------------------------------- /Community Reports/baseline_unremediated_solutions.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | assets_vulns as ( 3 | SELECT 4 | fasv.asset_id, 5 | fasv.vulnerability_id, 6 | baselineComparison (fasv.scan_id, current_scan) AS baseline, 7 | s.baseline_scan, 8 | s.current_scan 9 | FROM 10 | fact_asset_scan_vulnerability_instance fasv 11 | JOIN 12 | (SELECT 13 | asset_id, 14 | scanasofdate (asset_id, ('2018-05-17')) AS baseline_scan, 15 | lastScan (asset_id) AS current_scan 16 | FROM dim_asset 17 | ) s ON s.asset_id = fasv.asset_id 18 | 19 | AND ( 20 | fasv.scan_id = s.baseline_scan 21 | OR fasv.scan_id = s.current_scan 22 | ) 23 | 24 | GROUP BY 25 | fasv.asset_id, 26 | fasv.vulnerability_id, 27 | s.baseline_scan, 28 | s.current_scan 29 | 30 | HAVING 31 | (baselineComparison (fasv.scan_id, current_scan) = 'Same') 32 | OR 33 | (baselineComparison (fasv.scan_id, current_scan) = 'New') 34 | OR 35 | (baselineComparison (fasv.scan_id, current_scan) = 'Old') 36 | ), 37 | 38 | baseline_scan_date as ( 39 | 40 | SELECT 41 | av.asset_id, 42 | finished 43 | FROM assets_vulns av 44 | LEFT JOIN dim_scan ds ON ds.scan_id = av.baseline_scan 45 | GROUP BY av.asset_id, finished 46 | ), 47 | 48 | current_scan_date as ( 49 | SELECT 50 | av.asset_id, 51 | finished 52 | FROM assets_vulns av 53 | LEFT JOIN dim_scan ds ON ds.scan_id = av.current_scan 54 | GROUP BY av.asset_id, finished 55 | ), 56 | 57 | same_vulns as ( 58 | SELECT 59 | av.asset_id, 60 | av.vulnerability_id, 61 | COUNT (av.vulnerability_id) AS same_vulns 62 | FROM 63 | assets_vulns AS av 64 | WHERE 65 | av.baseline = 'Same' 66 | GROUP BY 67 | av.asset_id, 68 | av.vulnerability_id 69 | ) 70 | 71 | SELECT 72 | 'unchanged' as status, 73 | dv3.vulnerability_id AS "id", 74 | da3.ip_address AS "ip_address", 75 | da3.host_name AS "asset_name", 76 | dv3.description AS "vuln_description", 77 | dv3.title AS "vuln_title", 78 | ds.fix AS "solution", 79 | ds.solution_type AS "solution_type", 80 | ds.estimate AS "remediation_time", 81 | ds.summary AS "solution_summary" 82 | FROM same_vulns sv 83 | JOIN dim_asset da3 ON da3.asset_id = sv.asset_id 84 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da3.asset_id 85 | LEFT JOIN current_scan_date csd ON csd.asset_id = da3.asset_id 86 | JOIN dim_vulnerability dv3 ON dv3.vulnerability_id = sv.vulnerability_id 87 | JOIN dim_asset_vulnerability_solution davs ON davs.asset_id = da3.asset_id 88 | JOIN dim_solution ds ON ds.solution_id = davs.solution_id 89 | -------------------------------------------------------------------------------- /Community Reports/remediated baseline totals by site.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | site_last_scan AS ( 4 | 5 | SELECT site_id, 6 | (SELECT scan_id AS last_scan, finished 7 | FROM dim_site_scan 8 | JOIN dim_scan USING (scan_id) 9 | WHERE site_id = ds.site_id 10 | ORDER BY finished DESC 11 | LIMIT 1) AS last_scan 12 | FROM dim_site ds 13 | ), 14 | 15 | site_baseline_scan AS ( 16 | 17 | SELECT site_id, finished, 18 | (SELECT finished AS last_scan 19 | FROM dim_site_scan 20 | JOIN dim_scan USING (scan_id) 21 | WHERE site_id = ds.site_id AND finished LIKE '2018-05-16' 22 | ORDER BY finished DESC 23 | LIMIT 1) AS baseline_scan 24 | FROM dim_site ds 25 | ), 26 | 27 | last_vuln_count AS (SELECT sls.site_id, count(fasv.vulnerability_id) AS last_vuln_count 28 | 29 | FROM site_last_scan AS sls 30 | LEFT OUTER JOIN fact_asset_scan_vulnerability_finding AS fasv ON sls.last_scan = fasv.scan_id 31 | JOIN dim_vulnerability dv ON dv.vulnerability_id = fasv.vulnerability_id 32 | GROUP BY sls.site_id), 33 | 34 | 35 | previous_vuln_count AS (SELECT sps.site_id, count(fasv.vulnerability_id) AS previous_vuln_count 36 | 37 | FROM site_previous_scan AS sps 38 | LEFT OUTER JOIN fact_asset_scan_vulnerability_finding AS fasv ON sps.previous_scan = fasv.scan_id 39 | JOIN dim_vulnerability dv ON dv.vulnerability_id = fasv.vulnerability_id 40 | GROUP BY sps.site_id) 41 | 42 | 43 | SELECT 44 | ds.site_id, 45 | ds.name, 46 | fs.assets AS "Total Assets", 47 | ds2.started AS "Last Scan Date", 48 | fs.vulnerabilities AS "Total Current Vulnerabilities Discovered(last_scan)", 49 | lvc.last_vuln_count AS "Total New Vulnerabilities Discovered(last_scan)", 50 | pvc.previous_vuln_count AS "Total Unaddressed Vulnerabilities", 51 | 52 | FROM dim_site ds 53 | JOIN fact_site fs ON fs.site_id = ds.site_id 54 | JOIN dim_scan ds2 ON ds2.scan_id = ds.last_scan_id 55 | LEFT OUTER JOIN last_vuln_count AS lvc ON lvc.site_id = ds.site_id 56 | LEFT OUTER JOIN previous_vuln_count AS pvc ON pvc.site_id = lvc.site_id -------------------------------------------------------------------------------- /Community Reports/solution_export.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | da.ip_address AS "ip_address", 3 | da.host_name AS "asset_name", 4 | dv.description AS "vuln_description", 5 | dv.title AS "vuln_title", 6 | dv.severity_score AS "severity_score", 7 | dv.severity AS "vuln_severity", 8 | dv.exploits AS "vuln_exploit_count", 9 | ds.fix AS "solution", 10 | ds.solution_type AS "solution_type", 11 | ds.estimate AS "remediation_time", 12 | ds.summary AS "solution_summary" 13 | FROM fact_asset_scan_vulnerability_instance AS favi 14 | JOIN dim_vulnerability dv ON dv.vulnerability_id = favi.vulnerability_id 15 | JOIN dim_asset da ON da.asset_id = favi.asset_id 16 | JOIN dim_asset_vulnerability_solution davs ON davs.asset_id = da.asset_id 17 | JOIN dim_solution ds ON ds.solution_id = davs.solution_id 18 | --WHERE dv.severity = 'Critical' -------------------------------------------------------------------------------- /Community Reports/vuln_dashboard_by_site.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | site_last_scan AS ( 4 | 5 | SELECT site_id, 6 | 7 | (SELECT scan_id AS last_scan 8 | FROM dim_site_scan 9 | JOIN dim_scan USING (scan_id) 10 | WHERE site_id = ds.site_id 11 | ORDER BY finished DESC 12 | LIMIT 1) AS last_scan 13 | FROM dim_site ds 14 | 15 | ), 16 | 17 | site_previous_scan AS ( 18 | 19 | SELECT site_id, 20 | 21 | (SELECT scan_id AS last_scan 22 | FROM dim_site_scan 23 | JOIN dim_scan USING (scan_id) 24 | WHERE site_id = ds.site_id AND scan_id NOT IN (SELECT last_scan FROM site_last_scan WHERE site_id = ds.site_id) 25 | ORDER BY finished DESC 26 | LIMIT 1) AS previous_scan 27 | FROM dim_site ds 28 | ), 29 | 30 | last_vuln_count AS (SELECT sls.site_id, count(fasv.vulnerability_id) AS last_vuln_count 31 | SUM(CASE WHEN dv.severity = 'Critical' THEN 1 ELSE 0 END) AS critical_vulnerabilities, 32 | SUM(CASE WHEN dv.severity = 'Severe' THEN 1 ELSE 0 END) AS severe_vulnerabilities, 33 | SUM(CASE WHEN dv.severity = 'Moderate' THEN 1 ELSE 0 END) AS moderate_vulnerabilities 34 | FROM site_last_scan AS sls 35 | LEFT OUTER JOIN fact_asset_scan_vulnerability_finding AS fasv ON sls.last_scan = fasv.scan_id 36 | JOIN dim_vulnerability dv ON dv.vulnerability_id = fasv.vulnerability_id 37 | GROUP BY sls.site_id), 38 | 39 | 40 | previous_vuln_count AS (SELECT sps.site_id, count(fasv.vulnerability_id) AS previous_vuln_count 41 | SUM(CASE WHEN dv.severity = 'Critical' THEN 1 ELSE 0 END) AS critical_vulnerabilities, 42 | SUM(CASE WHEN dv.severity = 'Severe' THEN 1 ELSE 0 END) AS severe_vulnerabilities, 43 | SUM(CASE WHEN dv.severity = 'Moderate' THEN 1 ELSE 0 END) AS moderate_vulnerabilities 44 | FROM site_previous_scan AS sps 45 | LEFT OUTER JOIN fact_asset_scan_vulnerability_finding AS fasv ON sps.previous_scan = fasv.scan_id 46 | JOIN dim_vulnerability dv ON dv.vulnerability_id = fasv.vulnerability_id 47 | GROUP BY sps.site_id) 48 | 49 | 50 | SELECT 51 | ds.site_id, 52 | ds.name, 53 | fs.assets AS "Total Assets", 54 | ds2.started AS "Last Scan Date", 55 | fs.vulnerabilities AS "Total Current Vulnerabilities Discovered(last_scan)", 56 | fs.critical_vulnerabilities AS "Total Critical Vulnerabilities", 57 | fs.severe_vulnerabilities AS "Total Severe Vulnerabilities", 58 | fs.moderate_vulnerabilities AS "Total Moderate Vulnerabilities", 59 | lvc.last_vuln_count AS "Total New Vulnerabilities Discovered(last_scan)", 60 | (lvc.critical_vulnerabilities - pvc.critical_vulnerabilities) AS "Total New Critical Vulnerabilities(last_scan)", 61 | (lvc.severe_vulnerabilities - pvc.severe_vulnerabilities) AS "Total New Severe Vulnerabilities(last_scan)", 62 | (lvc.moderate_vulnerabilities - pvc.moderate_vulnerabilities) AS "Total New Moderate Vulnerabilities(last_scan)", 63 | pvc.previous_vuln_count AS "Total Unaddressed Vulnerabilities", 64 | pvc.severe_vulnerabilities AS "Total Unaddressed Severe Vulnerabilities", 65 | pvc.moderate_vulnerabilities AS "Total Unaddressed Moderate Vulnerabilities" 66 | FROM dim_site ds 67 | JOIN fact_site fs ON fs.site_id = ds.site_id 68 | JOIN dim_scan ds2 ON ds2.scan_id = ds.last_scan_id 69 | LEFT OUTER JOIN last_vuln_count AS lvc ON lvc.site_id = ds.site_id 70 | LEFT OUTER JOIN previous_vuln_count AS pvc ON pvc.site_id = lvc.site_id -------------------------------------------------------------------------------- /Community Reports/vuln_detail_category.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_urls AS ( 3 | SELECT vulnerability_id, array_to_string(array_agg(reference), ' , ') AS references 4 | FROM dim_vulnerability_reference 5 | GROUP BY vulnerability_id), 6 | category AS ( 7 | SELECT vulnerability_id, category_name, category_id 8 | FROM dim_vulnerability_category 9 | GROUP BY vulnerability_id, category_name, category_id), 10 | hostname AS ( 11 | SELECT asset_id, host_name AS hostname 12 | FROM dim_asset_host_name 13 | GROUP BY asset_id, host_name) 14 | 15 | SELECT 16 | da.ip_address, 17 | da.host_name as asset, 18 | h.hostname as hostname, 19 | --dos.description as operating_system, 20 | dv.nexpose_id as vuln_id, 21 | dv.title as vuln_title, 22 | round(dv.riskscore::numeric,0) as vuln_riskscore, 23 | proofastext(dv.description) as vuln_description, 24 | --s.solution as solution, 25 | c.category_name as category, 26 | 27 | --parent_category = 28 | CASE 29 | WHEN c.category_id in (5,6,10,14,22,25,29,37,38,40,41,47,49,52,53,56,60,61,63,66,67,68,69,71,72,73,74,77,78,84,85,86,90,92,93,94,95,96,97,99,100,101,103,105,106,107,109,110,111,113,118,119,120,122,124,125,129,130,131,134,136,137,138,139,140,144,145,146,149,150,151,152,155,156,157,158,159,160,161,163,167,168,169,171,172,173,174,176,177,178,179,181,182,183,184,185,186,187,189,191,192,193,194,197,200,202,203,204,206,209,211,212,213,214,215,217,218,219,220,221,226,227,228,229,230,231,235,236,239,240,241,242) 30 | THEN '3rd Party' 31 | WHEN c.category_id in (2,13,21,42,64,70,76,83,87,135,148,164,180) 32 | THEN 'Exploit Method' 33 | WHEN c.category_id in (3,9,11,16,18,20,23,24,27,28,31,32,33,36,39,43,44,50,51,54,55,59,79,80,81,82,88,89,91,102,108,116,121,123,132,133,142,143,153,154,166,170,188,190,195,196,198,199,201,207,208,216,222,224,232,233,234,237,238,243,244) 34 | THEN 'OS' 35 | WHEN c.category_id in (17,26,128) 36 | THEN 'Exploit Result' 37 | WHEN c.category_id in (1,8,15,34,35,48,58,112,147,162) 38 | THEN 'OS & 3rd Party' 39 | WHEN c.category_id in (4,7,12,19,30,45,46,57,62,65,75,98,104,114,115,117,126,127,141,165,175,210,223,225) 40 | THEN 'Technology' 41 | ELSE 'n/a' 42 | END AS parent_category, 43 | 44 | --c.category_id as cid, 45 | 46 | --classification = 47 | CASE 48 | WHEN c.category_id in (2,13,17,21,26,42,64,83,87,128) 49 | THEN 'Attack Type' 50 | WHEN c.category_id in (76,180,188) 51 | THEN 'Config' 52 | WHEN c.category_id in (63,90,95,97,99,139,183) 53 | THEN 'DB' 54 | WHEN c.category_id in (12,19,30,45,46,57,62,65,75,98,104,114,115,117,126,141,165,175,210,223) 55 | THEN 'Generic Tech' 56 | WHEN c.category_id in (5,101,118,127,169,203) 57 | THEN 'Mail' 58 | WHEN c.category_id in (70,135,148,164) 59 | THEN 'Malware' 60 | WHEN c.category_id in (1,8,15,23,27,32,34,35,43,48,55,58,88,91,112,147,153,159,162,171,176,178,190,191,196,240) 61 | THEN 'Mixed' 62 | WHEN c.category_id in (14,22,37,38,40,41,53,61,68,69,72,73,74,78,93,100,103,109,113,136,150,157,163,181,182,197,206,213,218,219,225,226,231,242) 63 | THEN 'Non-Runtime' 64 | WHEN c.category_id in (3,9,11,16,18,20,24,28,31,33,36,39,44,50,51,54,59,79,80,81,82,89,102,108,116,121,123,132,133,142,143,154,166,170,195,198,199,201,207,208,216,222,224,232,233,234,237,238,243,244) 65 | THEN 'OS' 66 | WHEN c.category_id in (47,49,52,66,67,71,77,84,85,86,92,94,96,105,107,110,111,120,122,124,129,130,131,134,140,144,146,151,155,156,158,160,161,167,173,174,177,179,184,185,186,187,200,202,204,209,211,212,214,215,217,220,221,229,230,235,241) 67 | THEN 'Runitme' 68 | WHEN c.category_id in (4,6,7,10,25,29,56,60,106,119,125,137,138,145,149,152,168,172,189,192,193,194,227,228,236,239) 69 | THEN 'Web' 70 | ELSE 'n/a' 71 | END AS classification, 72 | 73 | proofastext(f.proof) as vuln_proof, 74 | vu.references, 75 | -- f.port as "port# (-1 = n/a)", 76 | dv.date_added as vuln_date_into_nexpose, 77 | to_char(f.date, 'YYYY-mm-dd') as asset_last_scan 78 | 79 | FROM fact_asset_vulnerability_instance f 80 | JOIN dim_vulnerability dv USING (vulnerability_id) 81 | JOIN dim_asset da USING (asset_id) 82 | JOIN hostname h USING (asset_id) 83 | --JOIN dim_operating_system dos USING (operating_system_id) 84 | JOIN dim_vulnerability_reference dvr USING (vulnerability_id) 85 | JOIN vuln_urls vu USING (vulnerability_id) 86 | JOIN category c USING (vulnerability_id) 87 | --JOIN dim_vulnerability_solution USING (vulnerability_id) 88 | --JOIN dim_asset_vulnerability_finding_rollup_solution davfrs USING (vulnerability_id) 89 | 90 | --JOIN dim_solution s USING (solution_id) 91 | 92 | --ORDER BY dv.riskscore DESC -------------------------------------------------------------------------------- /Community Reports/vuln_detail_dlx_severity.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT vulnerability_id, array_to_string(array_agg(reference), ', ') AS references 4 | FROM dim_vulnerability 5 | JOIN dim_vulnerability_reference USING (vulnerability_id) 6 | GROUP BY vulnerability_id 7 | ) 8 | SELECT da.ip_address, da.host_name, da.mac_address, 9 | dv.title AS vulnerability, dvs.description AS status, favi.date AS discovered_date, 10 | CASE WHEN favi.port = -1 THEN NULL ELSE favi.port END AS port, 11 | dp.name AS protocol, dsvc.name AS service, proofAsText(dv.description) AS vulnerability_description, 12 | proofAsText(favi.proof) AS proof, round(dv.cvss_score::numeric, 2) AS cvss_score, 13 | round(dv.cvss_v3_score::numeric, 2) AS cvss_v3_score, 14 | 15 | --dlx_severity, 16 | CASE 17 | WHEN dv.cvss_v3_score IS NOT NULL THEN 18 | CASE 19 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 9.00 AND 10.00 THEN 'Critical' 20 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 7.00 AND 8.99 THEN 'High' 21 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 4.00 AND 6.99 THEN 'Medium' 22 | ELSE 'Low' 23 | END 24 | ELSE 25 | CASE 26 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 9.00 AND 10.00 THEN 'Critical' 27 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 7.00 AND 8.99 THEN 'High' 28 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 4.00 AND 6.99 THEN 'Medium' 29 | ELSE 'Low' 30 | END 31 | END AS dlx_severity, 32 | 33 | vr.references, dv.exploits, dv.malware_kits 34 | FROM fact_asset_vulnerability_instance favi 35 | JOIN dim_asset da USING (asset_id) 36 | JOIN dim_vulnerability dv USING (vulnerability_id) 37 | JOIN dim_site_asset dsa USING (asset_id) 38 | JOIN dim_site ds USING (site_id) 39 | JOIN dim_vulnerability_status dvs USING (status_id) 40 | JOIN dim_protocol dp USING (protocol_id) 41 | JOIN dim_service dsvc USING (service_id) 42 | JOIN vuln_references vr USING (vulnerability_id) 43 | ORDER BY ds.name, da.ip_address 44 | -------------------------------------------------------------------------------- /Data Warehouse/active_vulnerability_exceptions.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | dve.vulnerability_exception_id, 3 | dve.vulnerability_id, 4 | dv.nexpose_id, 5 | dv.title, 6 | round(dv.risk_score :: numeric, 0) AS risk, 7 | dv.severity, 8 | dv.severity_score, 9 | dve.scope, 10 | dve.scope_description, 11 | dag.asset_group_id, 12 | dag.name AS asset_group_name, 13 | dag.description, 14 | dve.reason, 15 | dve.additional_comments, 16 | dve.review_comment, 17 | date(dve.submitted_date) AS submitted_date, 18 | date(dve.review_date) AS review_date, 19 | date(dve.expiration_date) AS expiration_date, 20 | dve.submitted_by, 21 | dve.reviewed_by, 22 | dve.status 23 | FROM 24 | dim_vulnerability_exception dve 25 | JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 26 | LEFT JOIN dim_asset_group dag ON dag.asset_group_id = dve.group_id 27 | WHERE 28 | dve.status NOT LIKE 'Recalled' 29 | AND dve.expiration_date > current_date; 30 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/2020_DW/DW - Asset Report/DW_Asset_Report.sql: -------------------------------------------------------------------------------- 1 | with 2 | -- 2020/06/04 - Written by Matt Wyen 3 | -- Version: 1.0.0 4 | asset_metadata as ( 5 | select 6 | fa.asset_id 7 | , da.ip_address 8 | -- UPPER wraps the Regex and formats as uppercase 9 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 10 | , UPPER(regexp_replace(da.host_name, '([.][\w.]+)', '', 'g')) as hostname 11 | , da.host_name as hostname_full 12 | -- This is an aggregate of all sites this asset belongs to, don't be surprised if you see more than what you filtered on via the console 13 | , round(fa.risk_score::numeric, 0) as total_asset_risk 14 | from 15 | fact_asset fa 16 | left join dim_asset da on fa.asset_id = da.asset_id 17 | where 18 | fa.asset_id is not null 19 | ) 20 | , asset_software as ( 21 | select 22 | das.asset_id 23 | , vendor 24 | , family 25 | , name 26 | , version 27 | , type 28 | from 29 | dim_asset_software das 30 | ) 31 | /*Level of Grain: A vulnerability on an asset. 32 | Fact Type: accumulating snapshot 33 | Description: This fact table provides an accumulating snapshot for vulnerability age and occurrence information on an asset. 34 | For every vulnerability to which an asset is currently vulnerable, there will be one fact record. 35 | The record indicates when the vulnerability was first found, last found, and its current age. 36 | The age is computed as the difference between the time the vulnerability was first discovered on the asset, and the current time. 37 | If the vulnerability was temporarily remediated, but rediscovered, the age will be from the first discovery time. 38 | If a vulnerability was found on a service, remediated and discovered on another service, 39 | the age is still computed as the first time the vulnerability was found on any service on the asset.*/ 40 | select 41 | am.asset_id 42 | -- Reference of the all sites aggregate from asset metadata 43 | , am.ip_address 44 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 45 | , case 46 | when am.hostname = ' ' then am.ip_address::TEXT 47 | when am.hostname is null then am.ip_address::TEXT 48 | when am.hostname is not null then am.hostname 49 | else am.ip_address::TEXT 50 | end as "Hostname" 51 | , am.hostname_full 52 | -- Legible risk_score 53 | , am.total_asset_risk as "Asset: Risk" 54 | from 55 | asset_metadata am 56 | where 57 | am.asset_id is not null 58 | order by 59 | asset_id 60 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV - Vulnerability Exceptions - WH/WH_Vulnerability_Exceptions_by_asset(limited to cvss score 0.1 to 2.9).sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_metadata AS ( 3 | SELECT fa.asset_id 4 | ,da.ip_address 5 | -- UPPER wraps the Regex and formats as uppercase 6 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 7 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 8 | -- This makes the risk score legible and gets rid of extra decimal places 9 | -- This specific riskscore is for the total asset risk 10 | ,round(fa.risk_score::numeric,0) AS total_asset_risk 11 | -- Total asset vulnerabilities (aggregate) 12 | ,fa.critical_vulnerabilities AS total_asset_critical 13 | ,fa.severe_vulnerabilities AS total_asset_severe 14 | ,fa.moderate_vulnerabilities AS total_asset_moderate 15 | FROM fact_asset fa 16 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 17 | WHERE fa.asset_id IS NOT NULL 18 | ), 19 | asset_group AS ( 20 | SELECT dag.name AS asset_group_name 21 | ,dag.description AS asset_group_description 22 | ,daga.asset_id 23 | ,daga.asset_group_id 24 | FROM dim_asset_group dag 25 | LEFT JOIN dim_asset_group_asset daga ON daga.asset_group_id = dag.asset_group_id 26 | ), 27 | vulnerability_exception AS ( 28 | SELECT dve.vulnerability_exception_id 29 | ,dve.scope AS exception_scope 30 | ,dve.status AS exception_status 31 | ,dve.reason AS exception_reason 32 | ,dve.asset_id 33 | --,dve.site_id 34 | ,dve.group_id 35 | ,dv.nexpose_id 36 | ,dv.title 37 | ,dv.severity 38 | ,dv.cvss_score 39 | ,round(dv.risk_score::numeric,0) AS vulnerability_risk 40 | ,dve.additional_comments 41 | ,dve.review_comment 42 | ,dve.expiration_date 43 | FROM dim_vulnerability_exception dve 44 | LEFT OUTER JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 45 | WHERE dve.expiration_date >= current_date 46 | OR dve.expiration_date IS NULL 47 | ) 48 | SELECT DISTINCT fae.asset_id 49 | ,am.ip_address 50 | ,am.hostname 51 | ,am.total_asset_risk 52 | ,ve.exception_scope 53 | ,ve.exception_status 54 | ,ve.exception_reason 55 | ,ve.nexpose_id 56 | ,ve.title AS "Vulnerability Title" 57 | ,ve.severity 58 | ,ve.cvss_score 59 | ,ve.vulnerability_risk 60 | ,ag.asset_group_name 61 | ,ve.additional_comments 62 | ,ve.review_comment 63 | ,ve.expiration_date 64 | FROM fact_asset_event fae 65 | LEFT OUTER JOIN vulnerability_exception ve ON fae.vulnerability_exception_id = ve.vulnerability_exception_id 66 | LEFT OUTER JOIN asset_metadata am ON fae.asset_id = am.asset_id 67 | LEFT OUTER JOIN asset_group ag ON fae.asset_id = ag.asset_id AND ve.group_id = ag.asset_group_id 68 | WHERE fae.vulnerability_exception_id IS NOT NULL 69 | AND ve.exception_status = ('Approved') 70 | -- you must select a group_id here or comment out the group_id 71 | -- get it by quering SELECT * FROM dim_asset_group 72 | AND ve.group_id = ('72') 73 | AND ve.cvss_score =0 AND ve.cvss_score >2.9 -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV - Vulnerability Exceptions - WH/WH_Vulnerability_Exceptions_by_asset(not-limited).sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_metadata AS ( 3 | SELECT fa.asset_id 4 | ,da.ip_address 5 | -- UPPER wraps the Regex and formats as uppercase 6 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 7 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 8 | -- This makes the risk score legible and gets rid of extra decimal places 9 | -- This specific risk score is for the total asset risk 10 | ,round(fa.risk_score::numeric,0) AS total_asset_risk 11 | -- Total asset vulnerabilities (aggregate) 12 | ,fa.critical_vulnerabilities AS total_asset_critical 13 | ,fa.severe_vulnerabilities AS total_asset_severe 14 | ,fa.moderate_vulnerabilities AS total_asset_moderate 15 | FROM fact_asset fa 16 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 17 | WHERE fa.asset_id IS NOT NULL 18 | ), 19 | asset_group AS ( 20 | SELECT dag.name AS asset_group_name 21 | ,dag.description AS asset_group_description 22 | ,daga.asset_id 23 | ,daga.asset_group_id 24 | FROM dim_asset_group dag 25 | LEFT JOIN dim_asset_group_asset daga ON daga.asset_group_id = dag.asset_group_id 26 | ), 27 | vulnerability_exception AS ( 28 | SELECT dve.vulnerability_exception_id 29 | ,dve.scope AS exception_scope 30 | ,dve.status AS exception_status 31 | ,dve.reason AS exception_reason 32 | ,dve.asset_id 33 | --,dve.site_id 34 | ,dve.group_id 35 | ,dv.nexpose_id 36 | ,dv.title 37 | ,dv.severity 38 | ,dv.cvss_score 39 | ,round(dv.risk_score::numeric,0) AS vulnerability_risk 40 | ,dve.additional_comments 41 | ,dve.review_comment 42 | ,dve.expiration_date 43 | FROM dim_vulnerability_exception dve 44 | LEFT OUTER JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 45 | WHERE dve.expiration_date >= current_date 46 | OR dve.expiration_date IS NULL 47 | ) 48 | SELECT DISTINCT fae.asset_id 49 | ,am.ip_address 50 | ,am.hostname 51 | ,am.total_asset_risk 52 | ,ve.exception_scope 53 | ,ve.exception_status 54 | ,ve.exception_reason 55 | ,ve.nexpose_id 56 | ,ve.title AS "Vulnerability Title" 57 | ,ve.severity 58 | ,ve.cvss_score 59 | ,ve.vulnerability_risk 60 | ,ag.asset_group_name 61 | ,ve.additional_comments 62 | ,ve.review_comment 63 | ,ve.expiration_date 64 | FROM fact_asset_event fae 65 | LEFT OUTER JOIN vulnerability_exception ve ON fae.vulnerability_exception_id = ve.vulnerability_exception_id 66 | LEFT OUTER JOIN asset_metadata am ON fae.asset_id = am.asset_id 67 | LEFT OUTER JOIN asset_group ag ON fae.asset_id = ag.asset_id AND ve.group_id = ag.asset_group_id 68 | WHERE fae.vulnerability_exception_id IS NOT NULL 69 | AND ve.exception_status = ('Approved') 70 | -- you must select a group_id here or comment out the group_id 71 | -- get it by querying SELECT * FROM dim_asset_group 72 | AND ve.group_id = ('72') 73 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV - Vulnerability Exceptions - WH/WH_exception_report.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_metadata AS ( 3 | SELECT fa.asset_id 4 | ,da.ip_address 5 | -- UPPER wraps the Regex and formats as uppercase 6 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 7 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 8 | -- This makes the risk score legible and gets rid of extra decimal places 9 | -- This specific riskscore is for the total asset risk 10 | ,round(fa.risk_score::numeric,0) AS total_asset_risk 11 | -- Total asset vulnerabilities (aggregate) 12 | ,fa.critical_vulnerabilities AS total_asset_critical 13 | ,fa.severe_vulnerabilities AS total_asset_severe 14 | ,fa.moderate_vulnerabilities AS total_asset_moderate 15 | FROM fact_asset fa 16 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 17 | WHERE fa.asset_id IS NOT NULL 18 | ), 19 | asset_group AS ( 20 | SELECT dag.name AS asset_group_name 21 | ,dag.description AS asset_group_description 22 | ,daga.asset_id 23 | ,daga.asset_group_id 24 | FROM dim_asset_group dag 25 | LEFT JOIN dim_asset_group_asset daga ON daga.asset_group_id = dag.asset_group_id 26 | ), 27 | vulnerability_exception AS ( 28 | SELECT dve.vulnerability_exception_id 29 | ,dve.scope AS exception_scope 30 | ,dve.status AS exception_status 31 | ,dve.reason AS exception_reason 32 | ,dve.asset_id 33 | --,dve.site_id 34 | ,dve.group_id 35 | ,dv.nexpose_id 36 | ,dv.title 37 | ,dv.severity 38 | ,round(dv.risk_score::numeric,0) AS vulnerability_risk 39 | ,dve.additional_comments 40 | ,dve.review_comment 41 | ,dve.expiration_date 42 | FROM dim_vulnerability_exception dve 43 | LEFT OUTER JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 44 | WHERE dve.expiration_date >= current_date 45 | OR dve.expiration_date IS NULL 46 | ) 47 | SELECT fae.asset_id 48 | ,am.ip_address 49 | ,am.hostname 50 | ,am.total_asset_risk 51 | ,ve.exception_scope 52 | ,ve.exception_status 53 | ,ve.exception_reason 54 | ,ve.nexpose_id 55 | ,ve.title AS "Vulnerability Title" 56 | ,ve.severity 57 | ,ve.vulnerability_risk 58 | ,ag.asset_group_name 59 | FROM fact_asset_event fae 60 | LEFT JOIN vulnerability_exception ve ON fae.vulnerability_exception_id = ve.vulnerability_exception_id 61 | LEFT JOIN asset_metadata am ON fae.asset_id = am.asset_id 62 | LEFT JOIN asset_group ag ON fae.asset_id = ag.asset_id 63 | WHERE fae.vulnerability_exception_id IS NOT NULL -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV - Vulnerability Exceptions - WH/test.sql: -------------------------------------------------------------------------------- 1 | SELECT * 2 | FROM fact_asset_event fae 3 | LEFT JOIN dim_asset da ON fae.asset_id = da.asset_id 4 | LEFT JOIN dim_vulnerability_exception dve ON dve.vulnerability_exception_id = fae.vulnerability_exception_id AND dve.asset_id = fae.asset_id 5 | --LEFT JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 6 | WHERE dve.expiration_date >= current_date 7 | OR dve.expiration_date IS NULL -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV - Vulnerability Exceptions - WH/test2.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_metadata AS ( 3 | SELECT fa.asset_id 4 | ,da.ip_address 5 | -- UPPER wraps the Regex and formats as uppercase 6 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 7 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 8 | -- This makes the risk score legible and gets rid of extra decimal places 9 | -- This specific riskscore is for the total asset risk 10 | ,round(fa.risk_score::numeric,0) AS total_asset_risk 11 | -- Total asset vulnerabilities (aggregate) 12 | ,fa.critical_vulnerabilities AS total_asset_critical 13 | ,fa.severe_vulnerabilities AS total_asset_severe 14 | ,fa.moderate_vulnerabilities AS total_asset_moderate 15 | FROM fact_asset fa 16 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 17 | WHERE fa.asset_id IS NOT NULL 18 | ), 19 | asset_group AS ( 20 | SELECT dag.name AS asset_group_name 21 | ,dag.description AS asset_group_description 22 | ,daga.asset_id 23 | ,daga.asset_group_id 24 | FROM dim_asset_group dag 25 | LEFT JOIN dim_asset_group_asset daga ON daga.asset_group_id = dag.asset_group_id 26 | ), 27 | vulnerability_exception AS ( 28 | SELECT dve.vulnerability_exception_id 29 | ,dve.scope AS exception_scope 30 | ,dve.status AS exception_status 31 | ,dve.reason AS exception_reason 32 | ,dve.asset_id 33 | --,dve.site_id 34 | ,dve.group_id 35 | ,dv.nexpose_id 36 | ,dv.title 37 | ,dv.severity 38 | ,round(dv.risk_score::numeric,0) AS vulnerability_risk 39 | ,dve.additional_comments 40 | ,dve.review_comment 41 | ,dve.expiration_date 42 | FROM dim_vulnerability_exception dve 43 | LEFT OUTER JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 44 | WHERE dve.expiration_date >= current_date 45 | OR dve.expiration_date IS NULL 46 | ) 47 | SELECT fae.asset_id 48 | ,am.ip_address 49 | ,am.hostname 50 | ,am.total_asset_risk 51 | ,ve.exception_scope 52 | ,ve.exception_status 53 | ,ve.exception_reason 54 | ,ve.nexpose_id 55 | ,ve.title AS "Vulnerability Title" 56 | ,ve.severity 57 | ,ve.vulnerability_risk 58 | ,ag.asset_group_name 59 | ,ve.additional_comments 60 | ,ve.review_comment 61 | ,ve.expiration_date 62 | FROM fact_asset_event fae 63 | LEFT OUTER JOIN vulnerability_exception ve ON fae.vulnerability_exception_id = ve.vulnerability_exception_id 64 | LEFT OUTER JOIN asset_metadata am ON fae.asset_id = am.asset_id 65 | LEFT OUTER JOIN asset_group ag ON fae.asset_id = ag.asset_id AND ve.group_id = ag.asset_group_id 66 | WHERE fae.vulnerability_exception_id IS NOT NULL 67 | AND ve.exception_status = ('Approved') -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV Reports/Detail Aging/DATA_WAREHOUSE_REPORT_Vulnerability_Aging_Detail_(includes r7 aging code).sql: -------------------------------------------------------------------------------- 1 | WITH 2 | -- 9/6/2019 - Written by Matt Wyen 3 | -- Version: 2.6.3 4 | -- Moderate revision change, 2.5.1 caused issues with the sub-query, causing a 600MB CSV file to generate 5 | asset_metadata AS ( 6 | SELECT fa.asset_id 7 | ,da.ip_address 8 | -- UPPER wraps the Regex and formats as uppercase 9 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 10 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 11 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 12 | ,da.sites 13 | -- This makes the risk score legible and gets rid of extra decimal places 14 | -- This specific riskscore is for the total asset risk 15 | ,round(fa.risk_score::numeric, 0) AS total_asset_risk 16 | ,fa.critical_vulnerabilities AS total_asset_critical 17 | ,fa.severe_vulnerabilities AS total_asset_severe 18 | ,fa.moderate_vulnerabilities AS total_asset_moderate 19 | FROM fact_asset fa 20 | JOIN dim_asset da ON fa.asset_id = da.asset_id 21 | ) 22 | SELECT vfa.asset_id 23 | -- Reference of the all sites aggregate from asset metadata 24 | ,am.sites AS "All Sites" 25 | ,am.ip_address 26 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 27 | ,CASE 28 | WHEN am.hostname = ' ' THEN vfa.asset_id::TEXT 29 | WHEN am.hostname IS NULL THEN vfa.asset_id::TEXT 30 | WHEN am.hostname IS NOT NULL THEN am.hostname 31 | ELSE vfa.asset_id::TEXT 32 | END as "Hostname" 33 | ,vfa.vulnerability_title 34 | ,vfa.vulnerability_id 35 | ,vfa.nexpose_id 36 | -- Preformated severity 37 | ,vfa.severity 38 | -- Legible riskscore 39 | ,vfa.risk AS "Individual Vulnerability Risk" 40 | ,am.total_asset_risk AS "Total Asset Risk" 41 | ,vfa.exploits 42 | ,vfa.malware_kits 43 | ,am.total_asset_critical AS "Total Asset Critical" 44 | ,am.total_asset_severe AS "Total Asset Severe" 45 | ,am.total_asset_moderate "Total Asset Moderate" 46 | ,vfa.vulnerability_date_published 47 | ,vfa.vulnerability_date_added 48 | ,vfa.vulnerability_date_modified 49 | FROM ( -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 50 | SELECT avd.asset_id 51 | ,dv.title AS vulnerability_title 52 | ,dv.vulnerability_id 53 | ,dv.nexpose_id 54 | -- Preformated severity 55 | ,dv.severity 56 | -- This makes the risk score legible and gets rid of extra decimal places 57 | -- This specific riskscore is only for individual vulnerability risk NOT total asset risk 58 | ,round(dv.risk_score::numeric, 0) AS risk 59 | ,dv.exploits 60 | ,dv.malware_kits 61 | ,dv.date_published AS vulnerability_date_published 62 | ,dv.date_added AS vulnerability_date_added 63 | ,dv.date_modified AS vulnerability_date_modified 64 | FROM ( 65 | SELECT favf.asset_id 66 | ,favf.vulnerability_id 67 | FROM fact_asset_vulnerability_finding favf 68 | ) avd 69 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 70 | ) vfa 71 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 72 | -- Note there is no WHERE clause on purpose, you have to filter assets via the InsightVM console SQL report - You select an Asset, Site or Asset Group 73 | ORDER BY asset_id 74 | ,vulnerability_title 75 | ,severity -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/DEV Reports/Detail Aging/DATA_WAREHOUSE_REPORT_Vulnerability_Aging_Detail_(includes r7 aging code)v2.7.1_DEV.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | -- 9/12/2019 - Written by Matt Wyen 3 | -- Version: 2.7.1 4 | -- Moderate revision change, 2.5.1 caused issues with the sub-query, causing a 600MB CSV file to generate 5 | -- Moderate revision change, 2.7.1 speed optimization with WHERE statements 6 | asset_metadata AS ( 7 | SELECT fa.asset_id 8 | ,da.ip_address 9 | -- UPPER wraps the Regex and formats as uppercase 10 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 11 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)','','g')) AS hostname 12 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 13 | ,da.sites 14 | -- This makes the risk score legible and gets rid of extra decimal places 15 | -- This specific riskscore is for the total asset risk 16 | ,round(fa.risk_score::numeric,0) AS total_asset_risk 17 | -- Total asset vulnerabilities (aggregate) 18 | ,fa.critical_vulnerabilities AS total_asset_critical 19 | ,fa.severe_vulnerabilities AS total_asset_severe 20 | ,fa.moderate_vulnerabilities AS total_asset_moderate 21 | FROM fact_asset fa 22 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 23 | WHERE fa.asset_id IS NOT NULL 24 | ) 25 | -- vulnerability_metadata AS ( 26 | -- SELECT 27 | -- FROM dim_vulnerability dv 28 | -- WHERE 29 | -- ) 30 | SELECT vfa.asset_id 31 | -- Reference of the all sites aggregate from asset metadata 32 | ,am.sites AS "All Sites" 33 | ,am.ip_address 34 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 35 | ,CASE 36 | WHEN am.hostname = ' ' THEN am.ip_address::TEXT 37 | WHEN am.hostname IS NULL THEN am.ip_address::TEXT 38 | WHEN am.hostname IS NOT NULL THEN am.hostname 39 | ELSE am.ip_address::TEXT 40 | END as "Hostname" 41 | ,vfa.vulnerability_title AS "Vulnerability: Title" 42 | ,vfa.vulnerability_id 43 | ,vfa.nexpose_id 44 | -- Preformated severity 45 | ,vfa.severity AS "Vulnerability: Severity" 46 | -- Legible riskscore 47 | ,vfa.risk AS "Vulnerability: Risk" 48 | ,am.total_asset_risk AS "Asset: Risk" 49 | ,vfa.exploits AS "Asset: Exploits" 50 | ,vfa.malware_kits "Asset: Malware Kits" 51 | ,am.total_asset_critical AS "Asset: Critical" 52 | ,am.total_asset_severe AS "Asset: Severe" 53 | ,am.total_asset_moderate "Asset: Moderate" 54 | ,vfa.vulnerability_date_published AS "Vulnerability: Published" 55 | ,vfa.vulnerability_date_added AS "Vulnerability: Added" 56 | ,vfa.vulnerability_date_modified AS "Vulnerability: Modified" 57 | FROM ( -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 58 | SELECT avd.asset_id 59 | ,dv.title AS vulnerability_title 60 | ,dv.vulnerability_id 61 | ,dv.nexpose_id 62 | -- Preformated severity 63 | ,dv.severity 64 | -- This makes the risk score legible and gets rid of extra decimal places 65 | -- This specific riskscore is only for individual vulnerability risk NOT total asset risk 66 | ,round(dv.risk_score::numeric, 0) AS risk 67 | ,dv.exploits 68 | ,dv.malware_kits 69 | ,dv.date_published AS vulnerability_date_published 70 | ,dv.date_added AS vulnerability_date_added 71 | ,dv.date_modified AS vulnerability_date_modified 72 | FROM ( 73 | SELECT favf.asset_id 74 | ,favf.vulnerability_id 75 | FROM fact_asset_vulnerability_finding favf 76 | ) avd 77 | LEFT JOIN dim_vulnerability dv ON avd.vulnerability_id = dv.vulnerability_id 78 | WHERE avd.vulnerability_id IS NOT NULL 79 | ) vfa 80 | LEFT JOIN asset_metadata am ON vfa.asset_id = am.asset_id 81 | WHERE vfa.asset_id IS NOT NULL 82 | ORDER BY asset_id 83 | ,vulnerability_title 84 | ,severity; -------------------------------------------------------------------------------- /Dev-ScratchPad/Data Warehouse Reporting/Working_Do_Not_Modify/Vulnerability_By_Asset.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT da.asset_id 18 | ,fa.risk_score AS asset_risk 19 | ,fa.critical_vulnerabilities AS total_asset_critical 20 | ,fa.severe_vulnerabilities AS total_asset_severe 21 | ,fa.moderate_vulnerabilities AS total_asset_moderate 22 | ,fa.vulnerabilities AS total_asset_vulnerabilities 23 | ,daga.asset_group_id 24 | FROM dim_asset da 25 | LEFT JOIN fact_asset fa ON da.asset_id = fa.asset_id 26 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 27 | GROUP BY da.asset_id, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 28 | ) 29 | --begin SELECT 30 | SELECT da.ip_address AS "IP" 31 | ,regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 32 | ,dfa.asset_group_id AS "Asset Group ID" 33 | ,da.mac_address AS "MAC" 34 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 35 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 36 | ,dfa.total_asset_severe AS "Total Asset Severe" 37 | ,dfa.total_asset_critical AS "Total Asset Critical" 38 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 39 | ,vr.title AS "Vulnerability Title" 40 | ,favi.date AS "Vulnerability Test Date" 41 | ,vr.severity AS "Severity" 42 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 43 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 44 | END AS "PORT" 45 | ,vr.description AS "Vulnerability Description" 46 | ,htmltotext(favi.proof) AS "Proof" 47 | ,favi.port AS "Port" 48 | ,vr.references AS "References" 49 | ,vr.exploits AS "Exploits" 50 | ,vr.malware_kits AS "Malware Kits" 51 | --end SELECT 52 | --begin FROM/JOIN 53 | FROM fact_asset_vulnerability_instance favi 54 | JOIN dim_asset da USING (asset_id) 55 | JOIN dim_site_asset dsa USING (asset_id) 56 | JOIN dim_site ds USING (site_id) 57 | JOIN vuln_references vr USING (vulnerability_id) 58 | JOIN dfa_assets dfa USING (asset_id) 59 | --end FROM/JOIN 60 | WHERE dfa.asset_group_id = 2 61 | ORDER BY ds.name, da.ip_address, vr.severity DESC; 62 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/1568231171420.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | dve.vulnerability_exception_id, 3 | dve.vulnerability_id, 4 | dv.nexpose_id, 5 | dv.title, 6 | round(dv.risk_score :: numeric, 0) AS risk, 7 | dv.severity, 8 | dv.severity_score, 9 | dve.scope, 10 | dve.scope_description, 11 | dag.asset_group_id, 12 | dag.name AS asset_group_name, 13 | dag.description, 14 | dve.reason, 15 | dve.additional_comments, 16 | dve.review_comment -- use the date() command to convert timestamps to date only format 17 | , 18 | date(dve.submitted_date) AS submitted_date, 19 | date(dve.review_date) AS review_date, 20 | date(dve.expiration_date) AS expiration_date, 21 | dve.submitted_by, 22 | dve.reviewed_by, 23 | dve.status 24 | FROM 25 | dim_vulnerability_exception dve 26 | JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 27 | LEFT JOIN dim_asset_group dag ON dag.asset_group_id = dve.group_id -- removes any vulnerability exceptions with the status of Recalled 28 | WHERE 29 | dve.status NOT LIKE 'Recalled' -- removed any vulnerability exceptions that expired before NOW aka when you ran the report 30 | AND dve.expiration_date > now(); 31 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/20190517/dev1.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | LEFT JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT fa.asset_id 18 | ,da.ip_address AS ip 19 | ,da.mac_address AS mac 20 | ,da.host_name AS hostname 21 | ,da.os_description AS os 22 | ,fa.risk_score AS asset_risk 23 | ,fa.critical_vulnerabilities AS total_asset_critical 24 | ,fa.severe_vulnerabilities AS total_asset_severe 25 | ,fa.moderate_vulnerabilities AS total_asset_moderate 26 | ,fa.vulnerabilities AS total_asset_vulnerabilities 27 | ,daga.asset_group_id 28 | FROM fact_asset fa 29 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 30 | LEFT JOIN dim_asset_group_asset daga ON fa.asset_id = daga.asset_id 31 | GROUP BY fa.asset_id, da.ip_address, da.mac_address, da.host_name, da.os_description, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 32 | ) 33 | --begin SELECT 34 | SELECT dfa.asset_id 35 | ,dfa.ip 36 | ,dfa.mac 37 | ,regexp_replace(dfa.hostname, '([\.][\w\.]+)', '', 'g') AS "Hostname" 38 | ,dfa.os 39 | ,dfa.asset_group_id AS "Asset Group ID" 40 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 41 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 42 | ,dfa.total_asset_severe AS "Total Asset Severe" 43 | ,dfa.total_asset_critical AS "Total Asset Critical" 44 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 45 | ,vr.title AS "Vulnerability Title" 46 | ,favi.date AS "Vulnerability Test Date" 47 | ,vr.severity AS "Severity" 48 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 49 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 50 | END AS "PORT" 51 | ,vr.description AS "Vulnerability Description" 52 | ,htmltotext(favi.proof) AS "Proof" 53 | ,favi.port AS "Port" 54 | ,vr.references AS "References" 55 | ,vr.exploits AS "Exploits" 56 | ,vr.malware_kits AS "Malware Kits" 57 | --end SELECT 58 | --begin FROM/JOIN 59 | FROM fact_asset_vulnerability_instance favi 60 | JOIN vuln_references vr USING (vulnerability_id) 61 | JOIN dfa_assets dfa USING (asset_id) 62 | --end FROM/JOIN 63 | WHERE dfa.asset_group_id = 2 64 | ORDER BY dfa.asset_id, dfa.ip, vr.severity DESC; 65 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/20190517/dev2.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT DISTINCT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | LEFT JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT fa.asset_id 18 | ,da.ip_address AS ip 19 | ,da.mac_address AS mac 20 | ,da.host_name AS hostname 21 | ,da.os_description AS os 22 | ,fa.risk_score AS asset_risk 23 | ,fa.critical_vulnerabilities AS total_asset_critical 24 | ,fa.severe_vulnerabilities AS total_asset_severe 25 | ,fa.moderate_vulnerabilities AS total_asset_moderate 26 | ,fa.vulnerabilities AS total_asset_vulnerabilities 27 | ,daga.asset_group_id 28 | FROM fact_asset fa 29 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 30 | LEFT JOIN dim_asset_group_asset daga ON fa.asset_id = daga.asset_id 31 | GROUP BY fa.asset_id, da.ip_address, da.mac_address, da.host_name, da.os_description, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 32 | ) 33 | --begin SELECT 34 | SELECT favi.asset_id 35 | ,dfa.ip 36 | ,dfa.mac 37 | ,regexp_replace(dfa.hostname, '([\.][\w\.]+)', '', 'g') AS "Hostname" 38 | ,dfa.os 39 | ,dfa.asset_group_id AS "Asset Group ID" 40 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 41 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 42 | ,dfa.total_asset_severe AS "Total Asset Severe" 43 | ,dfa.total_asset_critical AS "Total Asset Critical" 44 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 45 | ,vr.title AS "Vulnerability Title" 46 | ,favi.status 47 | ,favi.date AS "Vulnerability Test Date" 48 | ,vr.severity AS "Severity" 49 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 50 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 51 | END AS "PORT" 52 | ,vr.description AS "Vulnerability Description" 53 | ,htmltotext(favi.proof) AS "Proof" 54 | ,favi.service AS "Service" 55 | ,favi.port AS "Port" 56 | ,favi.protocol AS "Protocol" 57 | ,vr.references AS "References" 58 | ,vr.exploits AS "Exploits" 59 | ,vr.malware_kits AS "Malware Kits" 60 | --end SELECT 61 | --begin FROM/JOIN 62 | FROM fact_asset_vulnerability_instance favi 63 | JOIN vuln_references vr ON favi.vulnerability_id = vr.vulnerability_id 64 | JOIN dfa_assets dfa ON favi.asset_id = dfa.asset_id 65 | --end FROM/JOIN 66 | WHERE dfa.asset_group_id = 2 67 | ORDER BY favi.asset_id, dfa.ip, vr.severity DESC; 68 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/20190517/dev3.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT DISTINCT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | LEFT JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT fa.asset_id 18 | ,da.ip_address AS ip 19 | ,da.mac_address AS mac 20 | ,da.host_name AS hostname 21 | ,da.os_description AS os 22 | ,fa.risk_score AS asset_risk 23 | ,fa.critical_vulnerabilities AS total_asset_critical 24 | ,fa.severe_vulnerabilities AS total_asset_severe 25 | ,fa.moderate_vulnerabilities AS total_asset_moderate 26 | ,fa.vulnerabilities AS total_asset_vulnerabilities 27 | ,daga.asset_group_id 28 | FROM fact_asset fa 29 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 30 | LEFT JOIN dim_asset_group_asset daga ON fa.asset_id = daga.asset_id 31 | GROUP BY fa.asset_id, da.ip_address, da.mac_address, da.host_name, da.os_description, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 32 | ) 33 | --begin SELECT 34 | SELECT favi.asset_id 35 | ,dfa.ip 36 | ,dfa.mac 37 | ,regexp_replace(dfa.hostname, '([\.][\w\.]+)', '', 'g') AS "Hostname" 38 | ,dfa.os 39 | ,dfa.asset_group_id AS "Asset Group ID" 40 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 41 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 42 | ,dfa.total_asset_severe AS "Total Asset Severe" 43 | ,dfa.total_asset_critical AS "Total Asset Critical" 44 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 45 | ,vr.title AS "Vulnerability Title" 46 | ,favi.status 47 | ,favi.date AS "Vulnerability Test Date" 48 | ,vr.severity AS "Severity" 49 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 50 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 51 | END AS "PORT" 52 | ,vr.description AS "Vulnerability Description" 53 | ,htmltotext(favi.proof) AS "Proof" 54 | ,favi.service AS "Service" 55 | ,favi.port AS "Port" 56 | ,favi.protocol AS "Protocol" 57 | ,vr.references AS "References" 58 | ,vr.exploits AS "Exploits" 59 | ,vr.malware_kits AS "Malware Kits" 60 | --end SELECT 61 | --begin FROM/JOIN 62 | FROM fact_asset_vulnerability_instance favi 63 | JOIN vuln_references vr ON favi.vulnerability_id = vr.vulnerability_id 64 | JOIN dfa_assets dfa ON favi.asset_id = dfa.asset_id 65 | --end FROM/JOIN 66 | WHERE dfa.asset_group_id = 2 67 | ORDER BY favi.asset_id, dfa.ip, vr.severity DESC; 68 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Aging_Detail_RAW_REPORTING-DATA-MODEL.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | -- Needs to be tested, probably broken 3 | -- Created by Matt Wyen 4 | vuln_references AS ( 5 | SELECT dv.vulnerability_id 6 | ,dv.severity AS severity 7 | ,dv.risk_score AS vulnerability_risk 8 | ,dv.nexpose_id AS nexpose_id 9 | ,dv.title AS title 10 | ,dv.description AS description 11 | ,dv.exploits 12 | ,dv.malware_kits 13 | FROM dim_vulnerability dv 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT da.asset_id 18 | ,da.ip_address AS ip_address 19 | ,da.mac_address AS mac_address 20 | ,da.host_name AS host_name 21 | ,fa.risk_score AS asset_risk 22 | ,fa.critical_vulnerabilities AS total_asset_critical 23 | ,fa.severe_vulnerabilities AS total_asset_severe 24 | ,fa.moderate_vulnerabilities AS total_asset_moderate 25 | ,fa.vulnerabilities AS total_asset_vulnerabilities 26 | ,daga.asset_group_id AS asset_group_id 27 | FROM fact_asset fa 28 | LEFT JOIN dim_asset da ON da.asset_id = fa.asset_id 29 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 30 | GROUP BY da.asset_id, da.ip_address,da.mac_address,da.host_name, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 31 | ) 32 | --begin SELECT 33 | SELECT dfa.ip_address AS "IP" 34 | ,dfa.mac_address AS "MAC" 35 | ,dfa.host_name AS "Hostname" 36 | ,dfa.asset_group_id AS "Asset Group ID" 37 | ,to_char(round(dfa.asset_risk::numeric,0),'999G999G999') AS "Total Asset Risk" 38 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 39 | ,dfa.total_asset_severe AS "Total Asset Severe" 40 | ,dfa.total_asset_critical AS "Total Asset Critical" 41 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 42 | ,vr.nexpose_id AS "Nexpose ID" 43 | ,favi.status AS "Vulnerability Status" 44 | ,vr.title AS "Vulnerability" 45 | ,favi.date AS "Discovered Date" 46 | ,vr.severity AS "Vulnerability Severity" 47 | ,to_char(round(vr.vulnerability_risk::numeric,0),'999G999G999') AS "Vulnerability Risk" 48 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 49 | END AS "PORT" 50 | ,favi.protocol AS "Protocol" 51 | ,vr.exploits AS "Exploits" 52 | ,vr.malware_kits AS "Malware Kits" 53 | --,vr.description AS "Vulnerability Description" 54 | --,favi.proof AS "Proof" 55 | --end SELECT 56 | --begin FROM/JOIN 57 | FROM fact_asset_vulnerability_instance favi 58 | JOIN vuln_references vr ON vr.vulnerability_id = favi.vulnerability_id 59 | JOIN dfa_assets dfa ON dfa.asset_id = favi.asset_id 60 | --end FROM/JOIN 61 | WHERE dfa.asset_group_id = 2 AND vr.severity = 'Critical' 62 | ORDER BY dfa.host_name, dfa.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Aging_Detail_RAW_v2.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | /* Created by Matt Wyen 4/15/19 3 | Last Commited 4/23/19 4 | https://help.rapid7.com/nexpose/en-us/warehouse/warehouse-schema.html 5 | fact_asset table is where counts of vulnerabilities come from */ 6 | custom_tags AS ( 7 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS custom_tags 8 | FROM dim_tag 9 | JOIN dim_tag_asset USING (tag_id) 10 | WHERE tag_type = 'CUSTOM' 11 | GROUP BY asset_id 12 | ), 13 | location_tags AS ( 14 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS location_tags 15 | FROM dim_tag 16 | JOIN dim_tag_asset USING (tag_id) 17 | WHERE tag_type = 'LOCATION' 18 | GROUP BY asset_id 19 | ), 20 | owner_tags AS ( 21 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS owner_tags 22 | FROM dim_tag 23 | JOIN dim_tag_asset USING (tag_id) 24 | WHERE tag_type = 'OWNER' 25 | GROUP BY asset_id 26 | ), 27 | criticality_tags AS ( 28 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS criticality_tags 29 | FROM dim_tag 30 | JOIN dim_tag_asset USING (tag_id) 31 | WHERE tag_type = 'CRITICALITY' 32 | GROUP BY asset_id 33 | ), 34 | remediations AS ( 35 | SELECT DISTINCT fr.solution_id AS ultimate_soln_id, summary, fix, estimate, riskscore, dshs.solution_id AS solution_id 36 | FROM fact_remediation(10,'riskscore DESC') fr 37 | JOIN dim_solution ds USING (solution_id) 38 | JOIN dim_solution_highest_supercedence dshs ON (fr.solution_id = dshs.superceding_solution_id AND ds.solution_id = dshs.superceding_solution_id) 39 | ), 40 | assets AS ( 41 | SELECT DISTINCT asset_id, host_name, sites, ip_address, mac_address, last_assessed_for_vulnerabilities 42 | FROM dim_asset da 43 | GROUP BY asset_id, host_name, sites, ip_address, mac_address, last_assessed_for_vulnerabilities 44 | ) 45 | SELECT DISTINCT 46 | csv(DISTINCT dv.title) AS "Vulnerability Title", 47 | dv.description AS "Vulnerability Description", 48 | to_char(round(dv.riskscore::numeric,0),'999G999G999') AS "Vulnerability Risk", 49 | fav.age AS "Age", 50 | fav.age_in_days AS "Age in Days", 51 | fav.first_discovered AS "First Discovered", 52 | fav.most_recently_discovered AS "Most Recently Discovered", 53 | dv.nexpose_id AS "ID / CVE", 54 | asset_id AS "Asset ID", 55 | host_name AS "Hostname", 56 | ip_address AS "IP", 57 | last_assessed_for_vulnerabilities AS "Last Assessed", 58 | to_char(round(fa.riskscore::numeric,0),'999G999G999') AS "Asset Risk", 59 | summary AS "Solution", 60 | dos.description AS "Operating System", 61 | fa.critical_vulnerabilities AS "Critical", 62 | fa.severe_vulnerabilities AS "Severe", 63 | fa.moderate_vulnerabilities AS "Moderate", 64 | fa.vulnerabilities AS "Total", 65 | sites AS "Sites", 66 | ct.custom_tags AS "Custom Tags", 67 | lt.location_tags AS "Location Tags", 68 | ot.owner_tags AS "Owner Tags", 69 | crt.criticality_tags AS "Criticality Tags", 70 | fix as "Fix" 71 | FROM remediations r 72 | JOIN dim_asset_vulnerability_solution dvs USING (solution_id) 73 | JOIN dim_vulnerability dv USING (vulnerability_id) 74 | JOIN assets USING (asset_id) 75 | JOIN dim_asset_operating_system USING (asset_id) 76 | JOIN dim_operating_system dos USING (operating_system_id) 77 | JOIN dim_tag_asset dta USING (asset_id) 78 | JOIN dim_tag dt ON dta.tag_id = dt.tag_id 79 | JOIN fact_asset fa USING (asset_id) 80 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 81 | LEFT OUTER JOIN location_tags lt USING (asset_id) 82 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 83 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 84 | LEFT OUTER JOIN fact_asset_vulnerability_age fav USING (asset_id) 85 | GROUP BY dv.nexpose_id, dv.title, dv.description, summary, fix, to_char(round(dv.riskscore::numeric,0),'999G999G999'), fav.age, fav.age_in_days, fav.first_discovered, fav.most_recently_discovered, dv.severity, to_char(round(fa.riskscore::numeric,0),'999G999G999'), host_name, dos.description, ip_address, asset_id, last_assessed_for_vulnerabilities, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, sites, ct.custom_tags, lt.location_tags, ot.owner_tags, crt.criticality_tags 86 | ORDER BY "Hostname" DESC 87 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Aging_Detail_RAW_v3.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,dv.severity AS severity 5 | ,dv.risk_score AS vulnerability_risk 6 | ,dv.nexpose_id AS nexpose_id 7 | ,dv.title AS title 8 | ,dv.description AS description 9 | ,dv.exploits 10 | ,dv.malware_kits 11 | FROM dim_vulnerability dv 12 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 13 | ), 14 | dfa_assets AS ( 15 | SELECT da.asset_id 16 | ,da.ip_address AS ip_address 17 | ,da.mac_address AS mac_address 18 | ,da.host_name AS host_name 19 | ,fa.risk_score AS asset_risk 20 | ,fa.critical_vulnerabilities AS total_asset_critical 21 | ,fa.severe_vulnerabilities AS total_asset_severe 22 | ,fa.moderate_vulnerabilities AS total_asset_moderate 23 | ,fa.vulnerabilities AS total_asset_vulnerabilities 24 | ,daga.asset_group_id AS asset_group_id 25 | FROM fact_asset fa 26 | LEFT JOIN dim_asset da ON da.asset_id = fa.asset_id 27 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 28 | GROUP BY da.asset_id, da.ip_address,da.mac_address,da.host_name, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 29 | ) 30 | --begin SELECT 31 | SELECT dfa.ip_address AS "IP" 32 | ,dfa.mac_address AS "MAC" 33 | ,dfa.host_name AS "Hostname" 34 | ,dfa.asset_group_id AS "Asset Group ID" 35 | ,to_char(round(dfa.asset_risk::numeric,0),'999G999G999') AS "Total Asset Risk" 36 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 37 | ,dfa.total_asset_severe AS "Total Asset Severe" 38 | ,dfa.total_asset_critical AS "Total Asset Critical" 39 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 40 | ,vr.nexpose_id AS "Nexpose ID" 41 | ,favi.status AS "Vulnerability Status" 42 | ,vr.title AS "Vulnerability" 43 | ,favi.date AS "Discovered Date" 44 | ,vr.severity AS "Vulnerability Severity" 45 | ,to_char(round(vr.vulnerability_risk::numeric,0),'999G999G999') AS "Vulnerability Risk" 46 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 47 | END AS "PORT" 48 | ,favi.protocol AS "Protocol" 49 | ,vr.exploits AS "Exploits" 50 | ,vr.malware_kits AS "Malware Kits" 51 | --,vr.description AS "Vulnerability Description" 52 | --,favi.proof AS "Proof" 53 | --end SELECT 54 | --begin FROM/JOIN 55 | FROM fact_asset_vulnerability_instance favi 56 | JOIN vuln_references vr ON vr.vulnerability_id = favi.vulnerability_id 57 | JOIN dfa_assets dfa ON dfa.asset_id = favi.asset_id 58 | --end FROM/JOIN 59 | WHERE dfa.asset_group_id = 2 AND vr.severity = 'Critical' 60 | ORDER BY dfa.host_name, dfa.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Modified-vuln-age-detail.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vulnerability_count AS ( 3 | SELECT COUNT(*) FROM (SELECT DISTINCT vulnerability_id FROM fact_asset_vulnerability_instance) AS vcount; 4 | ), 5 | vulnerability_raw AS ( 6 | SELECT vulnerability_id 7 | FROM fact_asset_vulnerability_instance 8 | GROUP BY favi.asset_id, favi.vulnerability_id 9 | ) 10 | SELECT 11 | FROM ( 12 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 13 | SELECT avd.asset_id, dv.title AS vulnerability_title 14 | ,dv.severity_score AS severity 15 | FROM ( 16 | SELECT favi.asset_id 17 | ,favi.vulnerability_id 18 | ,ava.age 19 | FROM asset_vuln_age ava 20 | JOIN fact_asset_vulnerability_finding favi ON favi.asset_id = ava.asset_id AND favi.vulnerability_id = ava.vulnerability_id 21 | GROUP BY favi.asset_id, favi.vulnerability_id, ava.age 22 | ) avd 23 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 24 | ) vfa 25 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 26 | ORDER BY asset_id, vulnerability_title 27 | 28 | SELECT DISTINCT ON (vulnerability_id) 29 | FROM fact_asset_vulnerability_instance -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Untitled-1.sql: -------------------------------------------------------------------------------- 1 | SELECT dve.vulnerability_exception_id 2 | ,dve.vulnerability_id 3 | ,dv.title 4 | ,dv.severity 5 | ,round(dv.riskscore::numeric, 0) AS risk 6 | ,dve.scope_id 7 | ,dve.reason_id 8 | ,dve.status_id 9 | ,dve.group_id 10 | ,dve.additional_comments 11 | ,dve.review_comment 12 | ,dve.submitted_date 13 | ,dve.review_date 14 | ,dve.expiration_date 15 | ,dve.submitted_by 16 | ,dve.reviewed_by 17 | FROM dim_vulnerability_exception dve 18 | JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Untitled-2.sql: -------------------------------------------------------------------------------- 1 | with assets_vulns as ( 2 | SELECT 3 | fasv.asset_id, 4 | fasv.vulnerability_id, 5 | baselineComparison (fasv.scan_id, current_scan) AS baseline, 6 | s.baseline_scan, 7 | s.current_scan 8 | FROM 9 | fact_asset_scan_vulnerability_instance fasv 10 | JOIN ( 11 | SELECT 12 | asset_id, 13 | previousScan (asset_id) AS baseline_scan, 14 | lastScan (asset_id) AS current_scan 15 | FROM 16 | dim_asset 17 | ) s ON s.asset_id = fasv.asset_id 18 | AND ( 19 | fasv.scan_id = s.baseline_scan 20 | OR fasv.scan_id = s.current_scan 21 | ) 22 | GROUP BY 23 | fasv.asset_id, 24 | fasv.vulnerability_id, 25 | s.baseline_scan, 26 | s.current_scan 27 | HAVING 28 | ( 29 | baselineComparison (fasv.scan_id, current_scan) = 'Same' 30 | ) 31 | OR ( 32 | baselineComparison (fasv.scan_id, current_scan) = 'New' 33 | ) 34 | OR ( 35 | baselineComparison (fasv.scan_id, current_scan) = 'Old' 36 | ) 37 | ) -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Untitled-3.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | the_whole_report AS ( 3 | SELECT dve.vulnerability_exception_id 4 | ,dve.vulnerability_id 5 | ,dv.nexpose_id 6 | ,dv.title 7 | ,round(dv.risk_score::numeric, 0) AS risk 8 | ,dv.severity 9 | ,dv.severity_score 10 | ,dve.scope 11 | ,dve.scope_description 12 | ,dve.group_id 13 | ,dag.asset_group_id 14 | ,dag.name 15 | ,dag.description 16 | ,dag.dynamic_membership 17 | ,dve.reason 18 | ,dve.additional_comments 19 | ,dve.review_comment 20 | ,dve.submitted_date 21 | ,dve.review_date 22 | ,dve.expiration_date 23 | ,dve.submitted_by 24 | ,dve.reviewed_by 25 | ,dve.status 26 | FROM dim_vulnerability_exception dve 27 | JOIN dim_vulnerability dv ON dv.vulnerability_id = dve.vulnerability_id 28 | JOIN dim_asset_group dag ON dag.asset_group_id = dve.group_id 29 | -- removes any vulnerability exceptions with the status of Recalled 30 | WHERE dve.status NOT LIKE 'Recalled' 31 | -- removed any vulnerability exceptions that expired before NOW aka when you ran the report 32 | AND dve.expiration_date > now(); 33 | ) 34 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vuln-Aging.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id 9 | ,favi.vulnerability_id 10 | ), 11 | asset_metadata AS ( 12 | SELECT da.asset_id 13 | ,da.ip_address AS ip_address 14 | ,da.host_name 15 | ,da.sites 16 | FROM dim_asset da 17 | ) 18 | SELECT vfa.asset_id 19 | ,am.sites AS "All Sites" 20 | ,am.ip_address 21 | ,regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 22 | ,vfa.vulnerability_title 23 | --THIS CAN BE OPTOMIZED - SEVERITY IS CALCULATED ALREADY 24 | ,vfa.severity AS "RAW Severity" 25 | ,CASE 26 | WHEN vfa.severity = 0 THEN 'None/Moderate' 27 | WHEN vfa.severity BETWEEN 1 and 3 THEN 'Moderate' 28 | WHEN vfa.severity BETWEEN 4 and 7 THEN 'Severe' 29 | WHEN vfa.severity BETWEEN 8 and 10 THEN 'Critical' 30 | ELSE '?' 31 | END as "Severity" 32 | ,vfa.vuln_count AS "Vulnerability Count" 33 | ,vfa.age AS "Vulnerability Age-in-Days" 34 | ,CASE 35 | WHEN vfa.age < 30 THEN '<30' 36 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 37 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '60-90' 38 | ELSE '90+' 39 | END as "Aging" 40 | FROM ( 41 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 42 | SELECT avd.asset_id 43 | ,dv.title AS vulnerability_title 44 | ,dv.severity_score AS severity 45 | ,avd.vuln_count 46 | ,avd.age 47 | FROM ( 48 | SELECT favf.asset_id 49 | ,favf.vulnerability_id 50 | ,1 AS vuln_count 51 | ,ava.age 52 | FROM asset_vuln_age ava 53 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = ava.asset_id AND favf.vulnerability_id = ava.vulnerability_id 54 | GROUP BY favf.asset_id 55 | ,favf.vulnerability_id 56 | ,ava.age 57 | ) avd 58 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 59 | ) vfa 60 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 61 | ORDER BY asset_id 62 | ,vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vuln_Aging_Detail_old_format.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id, favi.vulnerability_id 9 | ), 10 | asset_metadata AS ( 11 | SELECT da.asset_id 12 | ,da.ip_address AS ip_address 13 | ,da.host_name 14 | ,da.sites 15 | FROM dim_asset da 16 | ) 17 | SELECT vfa.asset_id 18 | ,am.sites AS "All Sites" 19 | ,am.ip_address 20 | ,regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 21 | ,vfa.vulnerability_title 22 | ,vfa.severity AS "RAW Severity" 23 | ,CASE 24 | WHEN vfa.severity = 0 THEN 'None/Moderate' 25 | WHEN vfa.severity BETWEEN 1 and 3 THEN 'Moderate' 26 | WHEN vfa.severity BETWEEN 4 and 7 THEN 'Severe' 27 | WHEN vfa.severity BETWEEN 8 and 10 THEN 'Critical' 28 | ELSE '?' 29 | END as "Severity" 30 | ,vfa.vuln_count AS "Vulnerability Count" 31 | ,vfa.age AS "Vulnerability Age-in-Days" 32 | , CASE 33 | WHEN vfa.age < 30 THEN '<30' 34 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 35 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '61-90' 36 | ELSE '90+' 37 | END as "Aging" 38 | FROM ( 39 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 40 | SELECT avd.asset_id, dv.title AS vulnerability_title 41 | ,dv.severity_score AS severity 42 | ,avd.vuln_count 43 | ,avd.age 44 | FROM ( 45 | SELECT favi.asset_id 46 | ,favi.vulnerability_id 47 | ,1 AS vuln_count 48 | ,ava.age 49 | FROM asset_vuln_age ava 50 | JOIN fact_asset_vulnerability_finding favi ON favi.asset_id = ava.asset_id AND favi.vulnerability_id = ava.vulnerability_id 51 | GROUP BY favi.asset_id, favi.vulnerability_id, ava.age 52 | ) avd 53 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 54 | ) vfa 55 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 56 | ORDER BY asset_id, vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_Aging_Detail_UPPER-Hostname.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id 9 | ,favi.vulnerability_id 10 | ), 11 | asset_metadata AS ( 12 | SELECT da.asset_id 13 | ,da.ip_address AS ip_address 14 | ,da.host_name 15 | ,da.sites 16 | FROM dim_asset da 17 | ) 18 | SELECT vfa.asset_id 19 | ,am.sites AS "All Sites" 20 | ,am.ip_address 21 | ,UPPER(regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g')) AS "Hostname" 22 | ,vfa.vulnerability_title 23 | --THIS CAN BE OPTOMIZED - SEVERITY IS CALCULATED ALREADY 24 | ,vfa.severity AS "RAW Severity" 25 | ,CASE 26 | WHEN vfa.severity = 0 THEN 'None/Moderate' 27 | WHEN vfa.severity BETWEEN 1 and 3 THEN 'Moderate' 28 | WHEN vfa.severity BETWEEN 4 and 7 THEN 'Severe' 29 | WHEN vfa.severity BETWEEN 8 and 10 THEN 'Critical' 30 | ELSE '?' 31 | END as "Severity" 32 | ,vfa.vuln_count AS "Vulnerability Count" 33 | ,vfa.age AS "Vulnerability Age-in-Days" 34 | ,CASE 35 | WHEN vfa.age < 30 THEN '<30' 36 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 37 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '60-90' 38 | ELSE '90+' 39 | END as "Aging" 40 | FROM ( 41 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 42 | SELECT avd.asset_id 43 | ,dv.title AS vulnerability_title 44 | ,dv.severity_score AS severity 45 | ,avd.vuln_count 46 | ,avd.age 47 | FROM ( 48 | SELECT favf.asset_id 49 | ,favf.vulnerability_id 50 | ,1 AS vuln_count 51 | ,ava.age 52 | FROM asset_vuln_age ava 53 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = ava.asset_id AND favf.vulnerability_id = ava.vulnerability_id 54 | GROUP BY favf.asset_id 55 | ,favf.vulnerability_id 56 | ,ava.age 57 | ) avd 58 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 59 | ) vfa 60 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 61 | ORDER BY asset_id 62 | ,vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_Aging_Detail_comments.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id 9 | ,favi.vulnerability_id 10 | ), 11 | asset_metadata AS ( 12 | SELECT da.asset_id 13 | ,da.ip_address 14 | ,da.host_name 15 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 16 | ,da.sites 17 | FROM dim_asset da 18 | ) 19 | SELECT vfa.asset_id 20 | -- Reference of the all sites aggregate from asset metadata 21 | ,am.sites AS "All Sites" 22 | ,am.ip_address 23 | ,UPPER(regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g')) AS "Hostname" 24 | ,vfa.vulnerability_title 25 | -- Preformated severity 26 | ,vfa.severity 27 | ,vfa.age AS "Vulnerability Age-in-Days" 28 | ,CASE 29 | WHEN vfa.age < 30 THEN '<30' 30 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 31 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '60-90' 32 | ELSE '90+' 33 | END as "Aging" 34 | FROM ( 35 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 36 | SELECT avd.asset_id 37 | ,dv.title AS vulnerability_title 38 | -- Preformated severity 39 | ,dv.severity 40 | -- This makes the risk score legible and gets rid of extra decimal places 41 | ,round(dv.riskscore::numeric, 0) AS risk 42 | ,dv.exploits 43 | ,dv.malware_kits 44 | ,avd.age 45 | FROM ( 46 | SELECT favf.asset_id 47 | ,favf.vulnerability_id 48 | ,ava.age 49 | FROM asset_vuln_age ava 50 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = ava.asset_id AND favf.vulnerability_id = ava.vulnerability_id 51 | GROUP BY favf.asset_id 52 | ,favf.vulnerability_id 53 | ,ava.age 54 | ) avd 55 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 56 | ) vfa 57 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 58 | -- Note there is no WHERE clause on purpose, you have to filter assets via the InsightVM console SQL report - You select an Asset, Site or Asset Group 59 | ORDER BY asset_id 60 | ,vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_Aging_Detail_replace_blank_hostnames.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id 9 | ,favi.vulnerability_id 10 | ), 11 | asset_metadata AS ( 12 | SELECT da.asset_id 13 | ,da.ip_address 14 | -- UPPER wraps the Regex and formats as uppercase 15 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 16 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g')) AS hostname 17 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 18 | ,da.sites 19 | FROM dim_asset da 20 | ) 21 | SELECT vfa.asset_id 22 | -- Reference of the all sites aggregate from asset metadata 23 | ,am.sites AS "All Sites" 24 | ,am.ip_address 25 | ,am.hostname 26 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 27 | ,CASE 28 | WHEN am.hostname = ' ' THEN vfa.asset_id::TEXT 29 | WHEN am.hostname IS NULL THEN vfa.asset_id::TEXT 30 | WHEN am.hostname IS NOT NULL THEN am.hostname 31 | ELSE vfa.asset_id::TEXT 32 | END as "Hostname Replace Blank" 33 | ,vfa.vulnerability_title 34 | -- Preformated severity 35 | ,vfa.severity 36 | -- Legible riskscore 37 | ,vfa.risk 38 | ,vfa.exploits 39 | ,vfa.malware_kits 40 | ,vfa.age AS "Age-in-Days" 41 | ,CASE 42 | WHEN vfa.age < 30 THEN '<30' 43 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 44 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '60-90' 45 | ELSE '90+' 46 | END as "Aging" 47 | FROM ( 48 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 49 | SELECT avd.asset_id 50 | ,dv.title AS vulnerability_title 51 | -- Preformated severity 52 | ,dv.severity 53 | -- This makes the risk score legible and gets rid of extra decimal places 54 | ,round(dv.riskscore::numeric, 0) AS risk 55 | ,dv.exploits 56 | ,dv.malware_kits 57 | ,avd.age 58 | FROM ( 59 | SELECT favf.asset_id 60 | ,favf.vulnerability_id 61 | ,ava.age 62 | FROM asset_vuln_age ava 63 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = ava.asset_id AND favf.vulnerability_id = ava.vulnerability_id 64 | GROUP BY favf.asset_id 65 | ,favf.vulnerability_id 66 | ,ava.age 67 | ) avd 68 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 69 | ) vfa 70 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 71 | -- Note there is no WHERE clause on purpose, you have to filter assets via the InsightVM console SQL report - You select an Asset, Site or Asset Group 72 | ORDER BY asset_id 73 | ,vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_By_Asset_DEV.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT da.asset_id 18 | ,fa.risk_score AS asset_risk 19 | ,fa.critical_vulnerabilities AS total_asset_critical 20 | ,fa.severe_vulnerabilities AS total_asset_severe 21 | ,fa.moderate_vulnerabilities AS total_asset_moderate 22 | ,fa.vulnerabilities AS total_asset_vulnerabilities 23 | ,daga.asset_group_id 24 | ,dag.name AS asset_group_name 25 | FROM dim_asset da 26 | LEFT JOIN fact_asset fa ON da.asset_id = fa.asset_id 27 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 28 | LEFT JOIN dim_asset_group dag ON daga.asset_group_id = dag.asset_group_id 29 | GROUP BY da.asset_id, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id, dag.name 30 | ), 31 | custom_tags AS ( 32 | SELECT asset_id, CSV(name ORDER BY name) AS custom_tags 33 | FROM dim_tag 34 | JOIN dim_asset_tag USING (tag_id) 35 | WHERE type = 'CUSTOM' 36 | GROUP BY asset_id 37 | ), 38 | location_tags AS ( 39 | SELECT asset_id, CSV(name ORDER BY name) AS location_tags 40 | FROM dim_tag 41 | JOIN dim_asset_tag USING (tag_id) 42 | WHERE type = 'LOCATION' 43 | GROUP BY asset_id 44 | ), 45 | owner_tags AS ( 46 | SELECT asset_id, CSV(name ORDER BY name) AS owner_tags 47 | FROM dim_tag 48 | JOIN dim_asset_tag USING (tag_id) 49 | WHERE type = 'OWNER' 50 | GROUP BY asset_id 51 | ), 52 | criticality_tags AS ( 53 | SELECT asset_id, CSV(name ORDER BY name) AS criticality_tags 54 | FROM dim_tag 55 | JOIN dim_asset_tag USING (tag_id) 56 | WHERE type = 'CRITICALITY' 57 | GROUP BY asset_id 58 | ) 59 | --begin SELECT 60 | SELECT da.ip_address AS "IP" 61 | ,regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 62 | ,dfa.asset_group_id AS "Asset Group ID" 63 | ,dfa.asset_group_name AS "Asset Group" 64 | ,da.mac_address AS "MAC" 65 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 66 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 67 | ,dfa.total_asset_severe AS "Total Asset Severe" 68 | ,dfa.total_asset_critical AS "Total Asset Critical" 69 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 70 | ,vr.title AS "Vulnerability Title" 71 | ,favi.date AS "Vulnerability Test Date" 72 | ,vr.severity AS "Severity" 73 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 74 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 75 | END AS "PORT" 76 | ,vr.description AS "Vulnerability Description" 77 | ,htmltotext(favi.proof) AS "Proof" 78 | ,favi.port AS "Port" 79 | ,vr.references AS "References" 80 | ,vr.exploits AS "Exploits" 81 | ,vr.malware_kits AS "Malware Kits" 82 | ,ct.custom_tags AS "Custom Tags" 83 | ,lt.location_tags AS "Location Tags" 84 | ,ot.owner_tags AS "Owner Tags" 85 | ,crt.criticality_tags AS "Criticality Tags" 86 | --end SELECT 87 | --begin FROM/JOIN 88 | FROM fact_asset_vulnerability_instance favi 89 | JOIN dim_asset da USING (asset_id) 90 | JOIN dim_site_asset dsa USING (asset_id) 91 | JOIN dim_site ds USING (site_id) 92 | JOIN vuln_references vr USING (vulnerability_id) 93 | JOIN dfa_assets dfa USING (asset_id) 94 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 95 | LEFT OUTER JOIN location_tags lt USING (asset_id) 96 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 97 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 98 | --end FROM/JOIN 99 | WHERE dfa.asset_group_id = 2 100 | ORDER BY ds.name, da.ip_address, vr.severity DESC; 101 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_By_Asset_Dev2.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,dv.severity AS severity 6 | ,dv.risk_score AS vulnerability_risk 7 | ,dv.nexpose_id 8 | ,dv.title 9 | ,dv.description 10 | ,dv.exploits 11 | ,dv.malware_kits 12 | FROM dim_vulnerability dv 13 | JOIN dim_vulnerability_reference USING (vulnerability_id) 14 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT da.asset_id 18 | ,fa.risk_score AS asset_risk 19 | ,fa.critical_vulnerabilities AS total_asset_critical 20 | ,fa.severe_vulnerabilities AS total_asset_severe 21 | ,fa.moderate_vulnerabilities AS total_asset_moderate 22 | ,fa.vulnerabilities AS total_asset_vulnerabilities 23 | ,daga.asset_group_id 24 | ,da.ip_address AS IP 25 | ,da.mac_address AS MAC 26 | ,da.host_name AS Hostname 27 | ,dag.name AS asset_group_name 28 | FROM dim_asset da 29 | LEFT JOIN fact_asset fa ON da.asset_id = fa.asset_id 30 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 31 | LEFT JOIN dim_asset_group dag ON daga.asset_group_id = dag.asset_group_id 32 | GROUP BY da.asset_id, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id, da.ip_address, da.mac_address, da.host_name, dag.name 33 | ), 34 | custom_tags AS ( 35 | SELECT asset_id, CSV(name ORDER BY name) AS custom_tags 36 | FROM dim_tag 37 | JOIN dim_asset_tag USING (tag_id) 38 | WHERE type = 'CUSTOM' 39 | GROUP BY asset_id 40 | ), 41 | location_tags AS ( 42 | SELECT asset_id, CSV(name ORDER BY name) AS location_tags 43 | FROM dim_tag 44 | JOIN dim_asset_tag USING (tag_id) 45 | WHERE type = 'LOCATION' 46 | GROUP BY asset_id 47 | ), 48 | owner_tags AS ( 49 | SELECT asset_id, CSV(name ORDER BY name) AS owner_tags 50 | FROM dim_tag 51 | JOIN dim_asset_tag USING (tag_id) 52 | WHERE type = 'OWNER' 53 | GROUP BY asset_id 54 | ), 55 | criticality_tags AS ( 56 | SELECT asset_id, CSV(name ORDER BY name) AS criticality_tags 57 | FROM dim_tag 58 | JOIN dim_asset_tag USING (tag_id) 59 | WHERE type = 'CRITICALITY' 60 | GROUP BY asset_id 61 | ) 62 | --begin SELECT 63 | SELECT dfa.IP 64 | ,dfa.MAC 65 | ,regexp_replace(dfa.Hostname, '([\.][\w\.]+)', '', 'g') AS "Hostname" 66 | ,dfa.asset_group_id AS "Asset Group ID" 67 | ,dfa.asset_group_name AS "Asset Group" 68 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 69 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 70 | ,dfa.total_asset_severe AS "Total Asset Severe" 71 | ,dfa.total_asset_critical AS "Total Asset Critical" 72 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 73 | ,vr.title AS "Vulnerability Title" 74 | ,favi.date AS "Vulnerability Test Date" 75 | ,vr.severity AS "Severity" 76 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 77 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 78 | END AS "PORT" 79 | ,vr.description AS "Vulnerability Description" 80 | ,htmltotext(favi.proof) AS "Proof" 81 | ,favi.port AS "Port" 82 | ,vr.references AS "References" 83 | ,vr.exploits AS "Exploits" 84 | ,vr.malware_kits AS "Malware Kits" 85 | ,ct.custom_tags AS "Custom Tags" 86 | ,lt.location_tags AS "Location Tags" 87 | ,ot.owner_tags AS "Owner Tags" 88 | ,crt.criticality_tags AS "Criticality Tags" 89 | --end SELECT 90 | --begin FROM/JOIN 91 | FROM fact_asset_vulnerability_instance favi 92 | JOIN vuln_references vr USING (vulnerability_id) 93 | JOIN dfa_assets dfa USING (asset_id) 94 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 95 | LEFT OUTER JOIN location_tags lt USING (asset_id) 96 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 97 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 98 | --end FROM/JOIN 99 | WHERE dfa.asset_group_id = 2 100 | ORDER BY dfa.Hostname, dfa.IP, vr.severity DESC; 101 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/Vulnerability_By_Asset_Dev4.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,dv.severity AS severity 5 | ,dv.risk_score AS vulnerability_risk 6 | ,dv.nexpose_id 7 | ,dv.title 8 | ,dv.description 9 | ,dv.exploits 10 | ,dv.malware_kits 11 | FROM dim_vulnerability dv 12 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 13 | ), 14 | dfa_assets AS ( 15 | SELECT da.asset_id 16 | ,fa.risk_score AS asset_risk 17 | ,fa.critical_vulnerabilities AS total_asset_critical 18 | ,fa.severe_vulnerabilities AS total_asset_severe 19 | ,fa.moderate_vulnerabilities AS total_asset_moderate 20 | ,fa.vulnerabilities AS total_asset_vulnerabilities 21 | ,daga.asset_group_id 22 | ,da.ip_address AS IP 23 | ,da.mac_address AS MAC 24 | ,da.host_name AS Hostname 25 | ,dag.name AS asset_group_name 26 | FROM fact_asset fa 27 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 28 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 29 | LEFT JOIN dim_asset_group dag ON daga.asset_group_id = dag.asset_group_id 30 | GROUP BY da.asset_id, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id, da.ip_address, da.mac_address, da.host_name, dag.name 31 | ), 32 | custom_tags AS ( 33 | SELECT asset_id, CSV(name ORDER BY name) AS custom_tags 34 | FROM dim_tag 35 | JOIN dim_asset_tag USING (tag_id) 36 | WHERE type = 'CUSTOM' 37 | GROUP BY asset_id 38 | ), 39 | location_tags AS ( 40 | SELECT asset_id, CSV(name ORDER BY name) AS location_tags 41 | FROM dim_tag 42 | JOIN dim_asset_tag USING (tag_id) 43 | WHERE type = 'LOCATION' 44 | GROUP BY asset_id 45 | ), 46 | owner_tags AS ( 47 | SELECT asset_id, CSV(name ORDER BY name) AS owner_tags 48 | FROM dim_tag 49 | JOIN dim_asset_tag USING (tag_id) 50 | WHERE type = 'OWNER' 51 | GROUP BY asset_id 52 | ), 53 | criticality_tags AS ( 54 | SELECT asset_id, CSV(name ORDER BY name) AS criticality_tags 55 | FROM dim_tag 56 | JOIN dim_asset_tag USING (tag_id) 57 | WHERE type = 'CRITICALITY' 58 | GROUP BY asset_id 59 | ) 60 | --begin SELECT 61 | SELECT dfa.IP 62 | ,dfa.MAC 63 | ,regexp_replace(dfa.Hostname, '([\.][\w\.]+)', '', 'g') AS "Hostname" 64 | ,dfa.asset_id AS "Asset ID" 65 | ,dfa.asset_group_id AS "Asset Group ID" 66 | ,dfa.asset_group_name AS "Asset Group" 67 | ,round(dfa.asset_risk::numeric, 0) AS "Total Asset Risk" 68 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 69 | ,dfa.total_asset_severe AS "Total Asset Severe" 70 | ,dfa.total_asset_critical AS "Total Asset Critical" 71 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 72 | ,vr.title AS "Vulnerability Title" 73 | ,round(age(favi.date, 'days')::numeric, 0) AS "Age In Days" 74 | , (CASE 75 | WHEN round(age(favi.date, 'days')::numeric, 0) < 30 THEN '<30' 76 | WHEN round(age(favi.date, 'days')::numeric, 0) > 30 and round(age(favi.date, 'days')::numeric, 0) <= 60 THEN '30-60' 77 | WHEN round(age(favi.date, 'days')::numeric, 0) > 60 and round(age(favi.date, 'days')::numeric, 0) <= 90 THEN '61-90' 78 | ELSE '90+' 79 | END) Aging 80 | ,vr.severity AS "Severity" 81 | ,round(vr.vulnerability_risk::numeric, 0) AS "Vulnerability Risk" 82 | ,htmltotext(vr.description) AS "Vulnerability Description" 83 | ,htmltotext(favi.proof) AS "Proof" 84 | ,favi.port AS "Port" 85 | ,vr.exploits AS "Exploits" 86 | ,vr.malware_kits AS "Malware Kits" 87 | ,ct.custom_tags AS "Custom Tags" 88 | ,lt.location_tags AS "Location Tags" 89 | ,ot.owner_tags AS "Owner Tags" 90 | ,crt.criticality_tags AS "Criticality Tags" 91 | --end SELECT 92 | --begin FROM/JOIN 93 | FROM fact_asset_vulnerability_instance favi 94 | LEFT JOIN vuln_references vr ON favi.vulnerability_id = vr.vulnerability_id 95 | LEFT JOIN dfa_assets dfa ON favi.asset_id = dfa.asset_id 96 | LEFT OUTER JOIN custom_tags ct ON favi.asset_id = ct.asset_id 97 | LEFT OUTER JOIN location_tags lt ON favi.asset_id = lt.asset_id 98 | LEFT OUTER JOIN owner_tags ot ON favi.asset_id = ot.asset_id 99 | LEFT OUTER JOIN criticality_tags crt ON favi.asset_id = crt.asset_id 100 | --end FROM/JOIN 101 | WHERE dfa.asset_group_id = 2 102 | ORDER BY dfa.Hostname, dfa.IP, vr.severity DESC; 103 | -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/alsdgjalg.sql: -------------------------------------------------------------------------------- 1 | --SELECT COUNT(*) FROM (SELECT DISTINCT vulnerability_id FROM fact_asset_vulnerability_instance) AS temp; 2 | -- 3 | --SELECT vulnerability_id 4 | --FROM fact_asset_vulnerability_instance 5 | --vulnerability_count AS ( 6 | -- SELECT COUNT(*) FROM (SELECT DISTINCT vulnerability_id FROM fact_asset_vulnerability_instance) AS --v_id_count; 7 | --), 8 | -------------------------------------------------------------------------------- 9 | WITH 10 | vulnerability_raw AS ( 11 | SELECT favi.asset_id 12 | ,favi.vulnerability_id AS v_id 13 | FROM fact_asset_vulnerability_instance favi 14 | GROUP BY favi.asset_id, favi.vulnerability_id 15 | ), 16 | asset_metadata AS ( 17 | SELECT da.asset_id 18 | ,da.ip_address AS ip_address 19 | ,da.host_name 20 | FROM dim_asset da 21 | GROUP BY da.asset_id, da.ip_address, da.host_name 22 | ) 23 | SELECT vfa.asset_id 24 | ,am.sites AS "All Sites" 25 | ,am.ip_address 26 | ,regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 27 | ,vfa.vulnerability_title 28 | ,vfa.severity 29 | FROM ( 30 | SELECT vraw.asset_id 31 | ,vraw.vulnerability_id AS v_id 32 | ,dv.title AS vulnerability_title 33 | ,dv.severity 34 | FROM vulnerability_raw AS vraw 35 | JOIN dim_vulnerability dv ON dv.vulnerability_id = vraw.vulnerability_id 36 | ) vfa 37 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 38 | ORDER BY asset_id, vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/alsdgjalg2.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vulnerability_raw AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id AS vulnerability_id 5 | FROM fact_asset_vulnerability_instance favi 6 | GROUP BY favi.asset_id, favi.vulnerability_id 7 | ), 8 | asset_metadata AS ( 9 | SELECT da.asset_id 10 | ,da.ip_address AS ip_address 11 | ,da.host_name 12 | FROM dim_asset da 13 | GROUP BY da.asset_id, da.ip_address, da.host_name 14 | ) 15 | SELECT vfa.asset_id 16 | ,am.ip_address 17 | ,regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g') AS "Hostname" 18 | ,vfa.vulnerability_id 19 | ,vfa.nexpose_id 20 | ,vfa.vulnerability_title 21 | ,vfa.severity 22 | ,vfa.risk 23 | ,vfa.exploits 24 | ,vfa.malware_kits 25 | FROM ( 26 | SELECT vraw.asset_id 27 | ,vraw.vulnerability_id 28 | ,dv.nexpose_id 29 | ,dv.title AS vulnerability_title 30 | ,dv.severity 31 | ,round(dv.riskscore::numeric, 0) AS risk 32 | ,dv.exploits 33 | ,dv.malware_kits 34 | FROM vulnerability_raw AS vraw 35 | JOIN dim_vulnerability dv ON dv.vulnerability_id = vraw.vulnerability_id 36 | ) vfa 37 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 38 | ORDER BY asset_id, vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/compate-temp.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | asset_vuln_age AS ( 3 | SELECT favi.asset_id 4 | ,favi.vulnerability_id 5 | ,date_part('days', (CURRENT_DATE - MIN(fasvi.date)) + INTERVAL '1 day') AS age 6 | FROM fact_asset_scan_vulnerability_instance fasvi 7 | JOIN fact_asset_vulnerability_instance favi ON fasvi.asset_id = favi.asset_id AND fasvi.vulnerability_id = favi.vulnerability_id 8 | GROUP BY favi.asset_id 9 | ,favi.vulnerability_id 10 | ), 11 | asset_metadata AS ( 12 | SELECT da.asset_id 13 | ,da.ip_address 14 | -- UPPER wraps the Regex and formats as uppercase 15 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 16 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g')) AS hostname 17 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 18 | ,da.sites 19 | FROM dim_asset da 20 | ) 21 | SELECT vfa.asset_id 22 | -- Reference of the all sites aggregate from asset metadata 23 | ,am.sites AS "All Sites" 24 | ,am.ip_address 25 | ,am.hostname 26 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 27 | ,CASE 28 | WHEN am.hostname = ' ' THEN vfa.asset_id::TEXT 29 | WHEN am.hostname IS NULL THEN vfa.asset_id::TEXT 30 | WHEN am.hostname IS NOT NULL THEN am.hostname 31 | ELSE vfa.asset_id::TEXT 32 | END as "Hostname Replace Blank" 33 | ,vfa.vulnerability_title 34 | -- Preformated severity 35 | ,vfa.severity 36 | -- Legible riskscore 37 | ,vfa.risk 38 | ,vfa.exploits 39 | ,vfa.malware_kits 40 | ,vfa.age AS "Age-in-Days" 41 | ,CASE 42 | WHEN vfa.age < 30 THEN '<30' 43 | WHEN vfa.age > 30 and vfa.age <= 60 THEN '30-60' 44 | WHEN vfa.age > 60 and vfa.age <= 90 THEN '61-90' 45 | ELSE '90+' 46 | END as "Aging" 47 | FROM ( 48 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 49 | SELECT avd.asset_id 50 | ,dv.title AS vulnerability_title 51 | -- Preformated severity 52 | ,dv.severity 53 | -- This makes the risk score legible and gets rid of extra decimal places 54 | ,round(dv.riskscore::numeric, 0) AS risk 55 | ,dv.exploits 56 | ,dv.malware_kits 57 | ,avd.age 58 | FROM ( 59 | SELECT favf.asset_id 60 | ,favf.vulnerability_id 61 | ,ava.age 62 | FROM asset_vuln_age ava 63 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = ava.asset_id AND favf.vulnerability_id = ava.vulnerability_id 64 | GROUP BY favf.asset_id 65 | ,favf.vulnerability_id 66 | ,ava.age 67 | ) avd 68 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 69 | ) vfa 70 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 71 | -- Note there is no WHERE clause on purpose, you have to filter assets via the InsightVM console SQL report - You select an Asset, Site or Asset Group 72 | ORDER BY asset_id 73 | ,vulnerability_title -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev-test-aging_5.sql: -------------------------------------------------------------------------------- 1 | SELECT dss.site_id AS "Site ID", da.host_name, da.ip_address, dos.description AS "Operating System", 2 | fa.scan_started AS "Last Scan Date", ds.name AS "Software Name", ds.version AS "Software Version" 3 | FROM dim_asset da 4 | JOIN dim_operating_system dos ON dos.operating_system_id = da.operating_system_id 5 | JOIN fact_asset fa ON fa.asset_id = da.asset_id 6 | JOIN dim_asset_software das ON das.asset_id = da.asset_id 7 | JOIN dim_software ds ON ds.software_id = das.software_id 8 | JOIN dim_scan ds2 ON ds2.scan_id = fa.last_scan_id 9 | JOIN dim_site_scan dss ON dss.scan_id = ds2.scan_id -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev-test-agingreport-4.sql: -------------------------------------------------------------------------------- 1 | SELECT 2 | csv(DISTINCT dv.title) AS "Vulnerability Title", 3 | dv.description AS "Vulnerability Description", 4 | to_char(round(dv.riskscore::numeric,0),'999G999G999') AS "Vulnerability Risk", 5 | fav.age AS "Age", 6 | fav.age_in_days AS "Age in Days", 7 | fav.first_discovered AS "First Discovered", 8 | fav.most_recently_discovered AS "Most Recently Discovered", 9 | dv.nexpose_id AS "ID / CVE", 10 | asset_id AS "Asset ID", 11 | host_name AS "Hostname", 12 | ip_address AS "IP", 13 | last_assessed_for_vulnerabilities AS "Last Assessed", 14 | to_char(round(fa.riskscore::numeric,0),'999G999G999') AS "Asset Risk", 15 | summary AS "Solution", 16 | dos.description AS "Operating System", 17 | fa.critical_vulnerabilities AS "Critical", 18 | fa.severe_vulnerabilities AS "Severe", 19 | fa.moderate_vulnerabilities AS "Moderate", 20 | fa.vulnerabilities AS "Total", 21 | sites AS "Sites", 22 | ct.custom_tags AS "Custom Tags", 23 | lt.location_tags AS "Location Tags", 24 | ot.owner_tags AS "Owner Tags", 25 | crt.criticality_tags AS "Criticality Tags", 26 | fix as "Fix" 27 | FROM remediations r 28 | JOIN dim_asset_vulnerability_solution dvs USING (solution_id) 29 | JOIN dim_vulnerability dv USING (vulnerability_id) 30 | JOIN assets USING (asset_id) 31 | JOIN dim_asset_operating_system USING (asset_id) 32 | JOIN dim_operating_system dos USING (operating_system_id) 33 | JOIN dim_tag_asset dta USING (asset_id) 34 | JOIN dim_tag dt ON dta.tag_id = dt.tag_id 35 | JOIN fact_asset fa USING (asset_id) 36 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 37 | LEFT OUTER JOIN location_tags lt USING (asset_id) 38 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 39 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 40 | LEFT OUTER JOIN fact_asset_vulnerability_age fav USING (asset_id) 41 | GROUP BY dv.nexpose_id, dv.title, dv.description, summary, fix, to_char(round(dv.riskscore::numeric,0),'999G999G999'), fav.age, fav.age_in_days, fav.first_discovered, fav.most_recently_discovered, dv.severity, to_char(round(fa.riskscore::numeric,0),'999G999G999'), host_name, dos.description, ip_address, asset_id, last_assessed_for_vulnerabilities, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, sites, ct.custom_tags, lt.location_tags, ot.owner_tags, crt.criticality_tags 42 | ORDER BY "Hostname" DESC -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev10.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id, array_to_string(array_agg(reference), ', ') AS references 4 | ,fava.age_in_days AS aid 5 | FROM dim_vulnerability dv 6 | JOIN dim_vulnerability_reference USING (vulnerability_id) 7 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 8 | GROUP BY dv.vulnerability_id, fava.age_in_days 9 | ) 10 | --begin SELECT 11 | SELECT da.ip_address 12 | ,da.host_name 13 | ,da.mac_address 14 | ,dv.title AS vulnerability 15 | ,dvs.description AS status 16 | ,favi.date AS discovered_date 17 | ,vr.aid AS "Age" 18 | , CASE 19 | WHEN vr.aid < 30 THEN '<30' 20 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 21 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 22 | ELSE '90+' 23 | END as "Aging" 24 | ,CASE WHEN favi.port = -1 THEN NULL ELSE favi.port END AS port 25 | ,dp.name AS protocol 26 | ,dsvc.name AS service 27 | ,proofAsText(dv.description) AS vulnerability_description 28 | ,proofAsText(favi.proof) AS proof 29 | ,vr.references 30 | ,dv.exploits 31 | ,dv.malware_kits 32 | --end SELECT 33 | --begin FROM/JOIN 34 | FROM fact_asset_vulnerability_instance favi 35 | JOIN dim_asset da USING (asset_id) 36 | JOIN dim_vulnerability dv USING (vulnerability_id) 37 | JOIN dim_site_asset dsa USING (asset_id) 38 | JOIN dim_site ds USING (site_id) 39 | JOIN dim_vulnerability_status dvs USING (status_id) 40 | JOIN dim_protocol dp USING (protocol_id) 41 | JOIN dim_service dsvc USING (service_id) 42 | JOIN vuln_references vr USING (vulnerability_id) 43 | --end FROM/JOIN 44 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev11.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,fava.age_in_days AS aid 6 | ,dv.severity AS severity 7 | FROM dim_vulnerability dv 8 | JOIN dim_vulnerability_reference USING (vulnerability_id) 9 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 10 | GROUP BY dv.vulnerability_id, dv.severity, fava.age_in_days 11 | ) 12 | --begin SELECT 13 | SELECT da.ip_address AS "IP" 14 | ,da.host_name AS "Hostname" 15 | ,da.mac_address AS "MAC" 16 | ,dv.title AS "Vulnerability" 17 | ,dvs.description AS "Status" 18 | ,favi.date AS "Discovered Date" 19 | ,vr.aid AS "Age" 20 | , CASE 21 | WHEN vr.aid < 30 THEN '<30' 22 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 23 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 24 | ELSE '90+' 25 | END as "Aging" 26 | ,vr.severity AS "Severity" 27 | ,CASE WHEN favi.port = -1 THEN NULL ELSE favi.port END AS "PORT" 28 | ,dp.name AS "Protocol" 29 | ,dsvc.name AS "Service" 30 | ,proofAsText(dv.description) AS "Vulnerability Description" 31 | ,proofAsText(favi.proof) AS "Proof" 32 | ,vr.references AS "References" 33 | ,dv.exploits AS "Exploits" 34 | ,dv.malware_kits AS "Malware Kits" 35 | --end SELECT 36 | --begin FROM/JOIN 37 | FROM fact_asset_vulnerability_instance favi 38 | JOIN dim_asset da USING (asset_id) 39 | JOIN dim_vulnerability dv USING (vulnerability_id) 40 | JOIN dim_site_asset dsa USING (asset_id) 41 | JOIN dim_site ds USING (site_id) 42 | JOIN dim_vulnerability_status dvs USING (status_id) 43 | JOIN dim_protocol dp USING (protocol_id) 44 | JOIN dim_service dsvc USING (service_id) 45 | JOIN vuln_references vr USING (vulnerability_id) 46 | --end FROM/JOIN 47 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev12.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,fava.age_in_days AS aid 6 | ,dv.severity AS severity 7 | ,to_char(round(dv.riskscore::numeric,0),'999G999G999') AS vulnerability_risk 8 | FROM dim_vulnerability dv 9 | JOIN dim_vulnerability_reference USING (vulnerability_id) 10 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 11 | GROUP BY dv.vulnerability_id, dv.severity, dv.riskscore, fava.age_in_days 12 | ), 13 | dfa_assets AS ( 14 | SELECT da.asset_id 15 | ,to_char(round(fa.riskscore::numeric,0),'999G999G999') AS asset_risk 16 | ,fa.critical_vulnerabilities AS total_asset_critical 17 | ,fa.severe_vulnerabilities AS total_asset_severe 18 | ,fa.moderate_vulnerabilities AS total_asset_moderate 19 | ,fa.vulnerabilities AS total_asset_vulnerabilities 20 | FROM dim_asset da 21 | JOIN fact_asset fa USING (asset_id) 22 | GROUP BY da.asset_id, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities 23 | ) 24 | --begin SELECT 25 | SELECT da.ip_address AS "IP" 26 | ,da.host_name AS "Hostname" 27 | ,da.mac_address AS "MAC" 28 | ,dfa.asset_risk AS "Total Asset Risk" 29 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 30 | ,dfa.total_asset_severe AS "Total Asset Severe" 31 | ,dfa.total_asset_critical AS "Total Asset Critical" 32 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 33 | ,dv.title AS "Vulnerability" 34 | ,dvs.description AS "Status" 35 | ,favi.date AS "Discovered Date" 36 | ,vr.aid AS "Age" 37 | , CASE 38 | WHEN vr.aid < 30 THEN '<30' 39 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 40 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 41 | ELSE '90+' 42 | END as "Aging" 43 | ,vr.severity AS "Severity" 44 | ,vr.vulnerability_risk AS "Vulnerability Risk" 45 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 46 | END AS "PORT" 47 | ,dp.name AS "Protocol" 48 | ,dsvc.name AS "Service" 49 | ,proofAsText(dv.description) AS "Vulnerability Description" 50 | ,proofAsText(favi.proof) AS "Proof" 51 | ,vr.references AS "References" 52 | ,dv.exploits AS "Exploits" 53 | ,dv.malware_kits AS "Malware Kits" 54 | --end SELECT 55 | --begin FROM/JOIN 56 | FROM fact_asset_vulnerability_instance favi 57 | JOIN dim_asset da USING (asset_id) 58 | JOIN dim_vulnerability dv USING (vulnerability_id) 59 | JOIN dim_site_asset dsa USING (asset_id) 60 | JOIN dim_site ds USING (site_id) 61 | JOIN dim_vulnerability_status dvs USING (status_id) 62 | JOIN dim_protocol dp USING (protocol_id) 63 | JOIN dim_service dsvc USING (service_id) 64 | JOIN vuln_references vr USING (vulnerability_id) 65 | JOIN dfa_assets dfa USING (asset_id) 66 | --end FROM/JOIN 67 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev13.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,fava.age_in_days AS aid 6 | ,dv.severity AS severity 7 | ,to_char(round(dv.riskscore::numeric,0),'999G999G999') AS vulnerability_risk 8 | FROM dim_vulnerability dv 9 | JOIN dim_vulnerability_reference USING (vulnerability_id) 10 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 11 | GROUP BY dv.vulnerability_id, dv.severity, dv.riskscore, fava.age_in_days 12 | ), 13 | dfa_assets AS ( 14 | SELECT da.asset_id 15 | ,to_char(round(fa.riskscore::numeric,0),'999G999G999') AS asset_risk 16 | ,fa.critical_vulnerabilities AS total_asset_critical 17 | ,fa.severe_vulnerabilities AS total_asset_severe 18 | ,fa.moderate_vulnerabilities AS total_asset_moderate 19 | ,fa.vulnerabilities AS total_asset_vulnerabilities 20 | FROM dim_asset da 21 | JOIN fact_asset fa USING (asset_id) 22 | GROUP BY da.asset_id, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities 23 | ), 24 | custom_tags AS ( 25 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS custom_tags 26 | FROM dim_tag 27 | JOIN dim_tag_asset USING (tag_id) 28 | WHERE tag_type = 'CUSTOM' 29 | GROUP BY asset_id 30 | ), 31 | location_tags AS ( 32 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS location_tags 33 | FROM dim_tag 34 | JOIN dim_tag_asset USING (tag_id) 35 | WHERE tag_type = 'LOCATION' 36 | GROUP BY asset_id 37 | ), 38 | owner_tags AS ( 39 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS owner_tags 40 | FROM dim_tag 41 | JOIN dim_tag_asset USING (tag_id) 42 | WHERE tag_type = 'OWNER' 43 | GROUP BY asset_id 44 | ), 45 | criticality_tags AS ( 46 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS criticality_tags 47 | FROM dim_tag 48 | JOIN dim_tag_asset USING (tag_id) 49 | WHERE tag_type = 'CRITICALITY' 50 | GROUP BY asset_id 51 | ) 52 | --begin SELECT 53 | SELECT da.ip_address AS "IP" 54 | ,da.host_name AS "Hostname" 55 | ,da.mac_address AS "MAC" 56 | ,dfa.asset_risk AS "Total Asset Risk" 57 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 58 | ,dfa.total_asset_severe AS "Total Asset Severe" 59 | ,dfa.total_asset_critical AS "Total Asset Critical" 60 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 61 | ,dv.title AS "Vulnerability" 62 | ,dvs.description AS "Status" 63 | ,favi.date AS "Discovered Date" 64 | ,vr.aid AS "Age" 65 | , CASE 66 | WHEN vr.aid < 30 THEN '<30' 67 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 68 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 69 | ELSE '90+' 70 | END as "Aging" 71 | ,vr.severity AS "Severity" 72 | ,vr.vulnerability_risk AS "Vulnerability Risk" 73 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 74 | END AS "PORT" 75 | ,dp.name AS "Protocol" 76 | ,dsvc.name AS "Service" 77 | ,proofAsText(dv.description) AS "Vulnerability Description" 78 | ,proofAsText(favi.proof) AS "Proof" 79 | ,vr.references AS "References" 80 | ,dv.exploits AS "Exploits" 81 | ,dv.malware_kits AS "Malware Kits" 82 | ,ct.custom_tags AS "Custom Tags" 83 | ,lt.location_tags AS "Location Tags" 84 | ,ot.owner_tags AS "Owner Tags" 85 | ,crt.criticality_tags AS "Criticality Tags" 86 | --end SELECT 87 | --begin FROM/JOIN 88 | FROM fact_asset_vulnerability_instance favi 89 | JOIN dim_asset da USING (asset_id) 90 | JOIN dim_vulnerability dv USING (vulnerability_id) 91 | JOIN dim_site_asset dsa USING (asset_id) 92 | JOIN dim_site ds USING (site_id) 93 | JOIN dim_vulnerability_status dvs USING (status_id) 94 | JOIN dim_protocol dp USING (protocol_id) 95 | JOIN dim_service dsvc USING (service_id) 96 | JOIN vuln_references vr USING (vulnerability_id) 97 | JOIN dfa_assets dfa USING (asset_id) 98 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 99 | LEFT OUTER JOIN location_tags lt USING (asset_id) 100 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 101 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 102 | --end FROM/JOIN 103 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev14.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,fava.age_in_days AS aid 6 | ,dv.severity AS severity 7 | ,to_char(round(dv.riskscore::numeric,0),'999G999G999') AS vulnerability_risk 8 | FROM dim_vulnerability dv 9 | JOIN dim_vulnerability_reference USING (vulnerability_id) 10 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 11 | GROUP BY dv.vulnerability_id, dv.severity, dv.riskscore, fava.age_in_days 12 | ), 13 | dfa_assets AS ( 14 | SELECT da.asset_id 15 | ,to_char(round(fa.riskscore::numeric,0),'999G999G999') AS asset_risk 16 | ,fa.critical_vulnerabilities AS total_asset_critical 17 | ,fa.severe_vulnerabilities AS total_asset_severe 18 | ,fa.moderate_vulnerabilities AS total_asset_moderate 19 | ,fa.vulnerabilities AS total_asset_vulnerabilities 20 | FROM dim_asset da 21 | JOIN fact_asset fa USING (asset_id) 22 | GROUP BY da.asset_id, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities 23 | ), 24 | custom_tags AS ( 25 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS custom_tags 26 | FROM dim_tag 27 | JOIN dim_tag_asset USING (tag_id) 28 | WHERE tag_type = 'CUSTOM' 29 | GROUP BY asset_id 30 | ), 31 | location_tags AS ( 32 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS location_tags 33 | FROM dim_tag 34 | JOIN dim_tag_asset USING (tag_id) 35 | WHERE tag_type = 'LOCATION' 36 | GROUP BY asset_id 37 | ), 38 | owner_tags AS ( 39 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS owner_tags 40 | FROM dim_tag 41 | JOIN dim_tag_asset USING (tag_id) 42 | WHERE tag_type = 'OWNER' 43 | GROUP BY asset_id 44 | ), 45 | criticality_tags AS ( 46 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS criticality_tags 47 | FROM dim_tag 48 | JOIN dim_tag_asset USING (tag_id) 49 | WHERE tag_type = 'CRITICALITY' 50 | GROUP BY asset_id 51 | ) 52 | --begin SELECT 53 | SELECT da.ip_address AS "IP" 54 | ,da.host_name AS "Hostname" 55 | ,da.mac_address AS "MAC" 56 | ,dfa.asset_risk AS "Total Asset Risk" 57 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 58 | ,dfa.total_asset_severe AS "Total Asset Severe" 59 | ,dfa.total_asset_critical AS "Total Asset Critical" 60 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 61 | ,dv.title AS "Vulnerability" 62 | ,dvs.description AS "Status" 63 | ,favi.date AS "Discovered Date" 64 | ,vr.aid AS "Age" 65 | , CASE 66 | WHEN vr.aid < 30 THEN '<30' 67 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 68 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 69 | ELSE '90+' 70 | END as "Aging" 71 | ,vr.severity AS "Severity" 72 | ,vr.vulnerability_risk AS "Vulnerability Risk" 73 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 74 | END AS "PORT" 75 | ,dp.name AS "Protocol" 76 | ,dsvc.name AS "Service" 77 | ,proofAsText(dv.description) AS "Vulnerability Description" 78 | ,proofAsText(favi.proof) AS "Proof" 79 | ,vr.references AS "References" 80 | ,dv.exploits AS "Exploits" 81 | ,dv.malware_kits AS "Malware Kits" 82 | ,ct.custom_tags AS "Custom Tags" 83 | ,lt.location_tags AS "Location Tags" 84 | ,ot.owner_tags AS "Owner Tags" 85 | ,crt.criticality_tags AS "Criticality Tags" 86 | --end SELECT 87 | --begin FROM/JOIN 88 | FROM fact_asset_vulnerability_instance favi 89 | JOIN dim_asset da USING (asset_id) 90 | JOIN dim_vulnerability dv USING (vulnerability_id) 91 | JOIN dim_site_asset dsa USING (asset_id) 92 | JOIN dim_site ds USING (site_id) 93 | JOIN dim_vulnerability_status dvs USING (status_id) 94 | JOIN dim_protocol dp USING (protocol_id) 95 | JOIN dim_service dsvc USING (service_id) 96 | JOIN vuln_references vr USING (vulnerability_id) 97 | JOIN dfa_assets dfa USING (asset_id) 98 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 99 | LEFT OUTER JOIN location_tags lt USING (asset_id) 100 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 101 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 102 | --end FROM/JOIN 103 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev15.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,array_to_string(array_agg(reference), ', ') AS references 5 | ,fava.age_in_days AS aid 6 | ,dv.severity AS severity 7 | ,to_char(round(dv.riskscore::numeric,0),'999G999G999') AS vulnerability_risk 8 | FROM dim_vulnerability dv 9 | JOIN dim_vulnerability_reference USING (vulnerability_id) 10 | LEFT OUTER JOIN fact_asset_vulnerability_age fava ON fava.vulnerability_id = dv.vulnerability_id 11 | GROUP BY dv.vulnerability_id, dv.severity, dv.riskscore, fava.age_in_days 12 | ), 13 | dfa_assets AS ( 14 | SELECT da.asset_id 15 | ,to_char(round(fa.riskscore::numeric,0),'999G999G999') AS asset_risk 16 | ,fa.critical_vulnerabilities AS total_asset_critical 17 | ,fa.severe_vulnerabilities AS total_asset_severe 18 | ,fa.moderate_vulnerabilities AS total_asset_moderate 19 | ,fa.vulnerabilities AS total_asset_vulnerabilities 20 | FROM dim_asset da 21 | LEFT JOIN fact_asset fa ON da.asset_id = fa.asset_id 22 | GROUP BY da.asset_id, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities 23 | ) 24 | --begin SELECT 25 | SELECT da.ip_address AS "IP" 26 | ,da.host_name AS "Hostname" 27 | ,da.mac_address AS "MAC" 28 | ,dfa.asset_risk AS "Total Asset Risk" 29 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 30 | ,dfa.total_asset_severe AS "Total Asset Severe" 31 | ,dfa.total_asset_critical AS "Total Asset Critical" 32 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 33 | ,dv.title AS "Vulnerability" 34 | ,dvs.description AS "Status" 35 | ,favi.date AS "Discovered Date" 36 | ,vr.aid AS "Age" 37 | , CASE 38 | WHEN vr.aid < 30 THEN '<30' 39 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 40 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 41 | ELSE '90+' 42 | END as "Aging" 43 | ,vr.severity AS "Severity" 44 | ,vr.vulnerability_risk AS "Vulnerability Risk" 45 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 46 | END AS "PORT" 47 | ,dp.name AS "Protocol" 48 | ,dsvc.name AS "Service" 49 | ,proofAsText(dv.description) AS "Vulnerability Description" 50 | ,proofAsText(favi.proof) AS "Proof" 51 | ,vr.references AS "References" 52 | ,dv.exploits AS "Exploits" 53 | ,dv.malware_kits AS "Malware Kits" 54 | --end SELECT 55 | --begin FROM/JOIN 56 | FROM fact_asset_vulnerability_instance favi 57 | JOIN dim_asset da USING (asset_id) 58 | JOIN dim_vulnerability dv USING (vulnerability_id) 59 | JOIN dim_site_asset dsa USING (asset_id) 60 | JOIN dim_site ds USING (site_id) 61 | JOIN dim_vulnerability_status dvs USING (status_id) 62 | JOIN dim_protocol dp USING (protocol_id) 63 | JOIN dim_service dsvc USING (service_id) 64 | JOIN vuln_references vr USING (vulnerability_id) 65 | JOIN dfa_assets dfa USING (asset_id) 66 | --end FROM/JOIN 67 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev16.1_test.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,dv.severity AS severity 5 | ,dv.riskscore AS vulnerability_risk 6 | ,dv.nexpose_id AS nexpose_id 7 | ,dv.title AS title 8 | ,dv.description AS description 9 | ,dv.exploits 10 | ,dv.malware_kits 11 | FROM dim_vulnerability dv 12 | GROUP BY dv.vulnerability_id, dv.severity, dv.riskscore, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 13 | ), 14 | dfa_assets AS ( 15 | SELECT da.asset_id 16 | ,da.ip_address AS ip_address 17 | ,da.mac_address AS mac_address 18 | ,da.host_name AS host_name 19 | ,fa.riskscore AS asset_risk 20 | ,fa.critical_vulnerabilities AS total_asset_critical 21 | ,fa.severe_vulnerabilities AS total_asset_severe 22 | ,fa.moderate_vulnerabilities AS total_asset_moderate 23 | ,fa.vulnerabilities AS total_asset_vulnerabilities 24 | ,daga.asset_group_id AS asset_group_id 25 | FROM fact_asset fa 26 | LEFT JOIN dim_asset da ON da.asset_id = fa.asset_id 27 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 28 | GROUP BY da.asset_id, da.ip_address,da.mac_address,da.host_name, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 29 | ) 30 | --begin SELECT 31 | SELECT dfa.ip_address AS "IP" 32 | ,dfa.mac_address AS "MAC" 33 | ,dfa.host_name AS "Hostname" 34 | ,dfa.asset_group_id AS "Asset Group ID" 35 | ,to_char(round(dfa.asset_risk::numeric,0),'999G999G999') AS "Total Asset Risk" 36 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 37 | ,dfa.total_asset_severe AS "Total Asset Severe" 38 | ,dfa.total_asset_critical AS "Total Asset Critical" 39 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 40 | ,vr.nexpose_id AS "Nexpose ID" 41 | ,favi.status AS "Vulnerability Status" 42 | ,vr.title AS "Vulnerability" 43 | ,favi.date AS "Discovered Date" 44 | ,vr.severity AS "Vulnerability Severity" 45 | ,to_char(round(vr.vulnerability_risk::numeric,0),'999G999G999') AS "Vulnerability Risk" 46 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 47 | END AS "PORT" 48 | ,favi.protocol AS "Protocol" 49 | ,vr.exploits AS "Exploits" 50 | ,vr.malware_kits AS "Malware Kits" 51 | --,vr.description AS "Vulnerability Description" 52 | --,favi.proof AS "Proof" 53 | --end SELECT 54 | --begin FROM/JOIN 55 | FROM fact_asset_vulnerability_instance favi 56 | JOIN vuln_references vr ON vr.vulnerability_id = favi.vulnerability_id 57 | JOIN dfa_assets dfa ON dfa.asset_id = favi.asset_id 58 | --end FROM/JOIN 59 | WHERE dfa.asset_group_id = 2 AND vr.severity = 'Critical' 60 | ORDER BY dfa.host_name, dfa.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev16.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,dv.severity AS severity 5 | ,dv.risk_score AS vulnerability_risk 6 | ,dv.nexpose_id AS nexpose_id 7 | ,dv.title AS title 8 | ,dv.description AS description 9 | ,dv.exploits 10 | ,dv.malware_kits 11 | FROM dim_vulnerability dv 12 | GROUP BY dv.vulnerability_id, dv.severity, dv.risk_score, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 13 | ), 14 | dfa_assets AS ( 15 | SELECT da.asset_id 16 | ,da.ip_address AS ip_address 17 | ,da.mac_address AS mac_address 18 | ,da.host_name AS host_name 19 | ,fa.risk_score AS asset_risk 20 | ,fa.critical_vulnerabilities AS total_asset_critical 21 | ,fa.severe_vulnerabilities AS total_asset_severe 22 | ,fa.moderate_vulnerabilities AS total_asset_moderate 23 | ,fa.vulnerabilities AS total_asset_vulnerabilities 24 | ,daga.asset_group_id AS asset_group_id 25 | FROM fact_asset fa 26 | LEFT JOIN dim_asset da ON da.asset_id = fa.asset_id 27 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 28 | GROUP BY da.asset_id, da.ip_address,da.mac_address,da.host_name, fa.risk_score, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 29 | ) 30 | --begin SELECT 31 | SELECT dfa.ip_address AS "IP" 32 | ,dfa.mac_address AS "MAC" 33 | ,dfa.host_name AS "Hostname" 34 | ,dfa.asset_group_id AS "Asset Group ID" 35 | ,to_char(round(dfa.asset_risk::numeric,0),'999G999G999') AS "Total Asset Risk" 36 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 37 | ,dfa.total_asset_severe AS "Total Asset Severe" 38 | ,dfa.total_asset_critical AS "Total Asset Critical" 39 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 40 | ,vr.nexpose_id AS "Nexpose ID" 41 | ,favi.status AS "Vulnerability Status" 42 | ,vr.title AS "Vulnerability" 43 | ,favi.date AS "Discovered Date" 44 | ,vr.severity AS "Vulnerability Severity" 45 | ,to_char(round(vr.vulnerability_risk::numeric,0),'999G999G999') AS "Vulnerability Risk" 46 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 47 | END AS "PORT" 48 | ,favi.protocol AS "Protocol" 49 | ,vr.exploits AS "Exploits" 50 | ,vr.malware_kits AS "Malware Kits" 51 | --,vr.description AS "Vulnerability Description" 52 | --,favi.proof AS "Proof" 53 | --end SELECT 54 | --begin FROM/JOIN 55 | FROM fact_asset_vulnerability_instance favi 56 | JOIN vuln_references vr ON vr.vulnerability_id = favi.vulnerability_id 57 | JOIN dfa_assets dfa ON dfa.asset_id = favi.asset_id 58 | --end FROM/JOIN 59 | WHERE dfa.asset_group_id = 2 AND vr.severity = 'Critical' 60 | ORDER BY dfa.host_name, dfa.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev6.sql: -------------------------------------------------------------------------------- 1 | SELECT dss.site_id AS "Site ID", da.host_name, da.ip_address, dos.description AS "Operating System", 2 | fa.scan_started AS "Last Scan Date", favf.vulnerability_id AS "Vulnerability ID" 3 | FROM dim_asset da 4 | JOIN dim_operating_system dos ON dos.operating_system_id = da.operating_system_id 5 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = da.asset_id 6 | JOIN fact_asset fa ON fa.asset_id = da.asset_id 7 | JOIN dim_asset_software das ON das.asset_id = da.asset_id 8 | JOIN dim_scan ds2 ON ds2.scan_id = fa.last_scan_id 9 | JOIN dim_site_scan dss ON dss.scan_id = ds2.scan_id -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev7.sql: -------------------------------------------------------------------------------- 1 | SELECT dss.site_id AS "Site ID" 2 | ,da.host_name AS "Hostname" 3 | ,da.ip_address AS "IP" 4 | ,dos.description AS "OS" 5 | ,fa.scan_started AS "Last Scan Date" 6 | ,favf.vulnerability_id AS "Vulnerability ID" 7 | ,dv.nexpose_id AS "Nexpose ID" 8 | ,dv.title AS "V Title" 9 | FROM dim_asset da 10 | JOIN dim_operating_system dos ON dos.operating_system_id = da.operating_system_id 11 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = da.asset_id 12 | JOIN dim_vulnerability dv ON dv.vulnerability_id = favf.vulnerability_id 13 | JOIN fact_asset fa ON fa.asset_id = da.asset_id 14 | JOIN dim_asset_software das ON das.asset_id = da.asset_id 15 | JOIN dim_scan ds2 ON ds2.scan_id = fa.last_scan_id 16 | JOIN dim_site_scan dss ON dss.scan_id = ds2.scan_id -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev8.sql: -------------------------------------------------------------------------------- 1 | SELECT dss.site_id AS "Site ID" 2 | ,da.host_name AS "Hostname" 3 | ,da.ip_address AS "IP" 4 | ,dos.description AS "OS" 5 | ,fa.scan_started AS "Last Scan Date" 6 | ,favf.vulnerability_id AS "Vulnerability ID" 7 | ,to_char(fava.first_discovered,'MM/DD/YYYY') AS discovered_date 8 | ,fava.age_in_days AS "Age in Days" 9 | ,dv.nexpose_id AS "Nexpose ID" 10 | ,dv.title AS "V Title" 11 | FROM dim_asset da 12 | JOIN dim_operating_system dos ON dos.operating_system_id = da.operating_system_id 13 | JOIN fact_asset_vulnerability_finding favf ON favf.asset_id = da.asset_id 14 | JOIN fact_asset_vulnerability_age fava (favf.asset_id, favf.vulnerability_id) 15 | JOIN dim_vulnerability dv ON dv.vulnerability_id = favf.vulnerability_id 16 | JOIN fact_asset fa ON fa.asset_id = da.asset_id 17 | JOIN dim_asset_software das ON das.asset_id = da.asset_id 18 | JOIN dim_scan ds2 ON ds2.scan_id = fa.last_scan_id 19 | JOIN dim_site_scan dss ON dss.scan_id = ds2.scan_id 20 | ORDER BY "Hostname", "Vulnerability ID" -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev9.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT vulnerability_id, array_to_string(array_agg(reference), ', ') AS references 4 | ,age_in_days AS aid 5 | FROM dim_vulnerability 6 | JOIN dim_vulnerability_reference USING (vulnerability_id) 7 | JOIN fact_asset_vulnerability_age USING (vulnerability_id) 8 | GROUP BY vulnerability_id, age_in_days 9 | ) 10 | --begin SELECT 11 | SELECT da.ip_address 12 | ,da.host_name 13 | ,da.mac_address 14 | ,dv.title AS vulnerability 15 | ,dvs.description AS status 16 | ,favi.date AS discovered_date 17 | ,vr.aid AS "Age" 18 | , CASE 19 | WHEN vr.aid < 30 THEN '<30' 20 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 21 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 22 | ELSE '90+' 23 | END as "Aging" 24 | ,CASE WHEN favi.port = -1 THEN NULL ELSE favi.port END AS port 25 | ,dp.name AS protocol 26 | ,dsvc.name AS service 27 | ,proofAsText(dv.description) AS vulnerability_description 28 | ,proofAsText(favi.proof) AS proof 29 | ,round(dv.cvss_score::numeric, 2) AS cvss_score 30 | ,round(dv.cvss_v3_score::numeric, 2) AS cvss_v3_score 31 | --dlx_severity, 32 | , CASE 33 | WHEN dv.cvss_v3_score IS NOT NULL THEN 34 | CASE 35 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 9.00 AND 10.00 THEN 'Critical' 36 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 7.00 AND 8.99 THEN 'High' 37 | WHEN round(dv.cvss_v3_score::numeric, 2) BETWEEN 4.00 AND 6.99 THEN 'Medium' 38 | ELSE 'Low' 39 | END 40 | ELSE 41 | CASE 42 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 9.00 AND 10.00 THEN 'Critical' 43 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 7.00 AND 8.99 THEN 'High' 44 | WHEN round(dv.cvss_score::numeric, 2) BETWEEN 4.00 AND 6.99 THEN 'Medium' 45 | ELSE 'Low' 46 | END 47 | END AS dlx_severity 48 | --end dlx_severity 49 | ,vr.references 50 | ,dv.exploits 51 | ,dv.malware_kits 52 | --end SELECT 53 | --begin FROM/JOIN 54 | FROM fact_asset_vulnerability_instance favi 55 | JOIN dim_asset da USING (asset_id) 56 | JOIN dim_vulnerability dv USING (vulnerability_id) 57 | JOIN dim_site_asset dsa USING (asset_id) 58 | JOIN dim_site ds USING (site_id) 59 | JOIN dim_vulnerability_status dvs USING (status_id) 60 | JOIN dim_protocol dp USING (protocol_id) 61 | JOIN dim_service dsvc USING (service_id) 62 | JOIN vuln_references vr USING (vulnerability_id) 63 | --end FROM/JOIN 64 | ORDER BY ds.name, da.ip_address -------------------------------------------------------------------------------- /Dev-ScratchPad/Junk-Old/2019_or_older/dev_nxpasgjaslrgjalkjga.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vuln_references AS ( 3 | SELECT dv.vulnerability_id 4 | ,dv.severity AS severity 5 | ,dv.riskscore AS vulnerability_risk 6 | ,dv.nexpose_id AS nexpose_id 7 | ,dv.title AS title 8 | ,dv.description AS description 9 | ,dv.exploits 10 | ,dv.malware_kits 11 | ,fava.age_in_days AS aid 12 | FROM dim_vulnerability dv 13 | LEFT JOIN fact_asset_vulnerability_age fava ON dv.vulnerability_id = fava.vulnerability_id 14 | GROUP BY dv.vulnerability_id, fava.age_in_days, dv.severity, dv.riskscore, dv.nexpose_id, dv.title, dv.description, dv.exploits, dv.malware_kits 15 | ), 16 | dfa_assets AS ( 17 | SELECT da.asset_id 18 | ,da.ip_address AS ip_address 19 | ,da.mac_address AS mac_address 20 | ,da.host_name AS host_name 21 | ,fa.riskscore AS asset_risk 22 | ,fa.critical_vulnerabilities AS total_asset_critical 23 | ,fa.severe_vulnerabilities AS total_asset_severe 24 | ,fa.moderate_vulnerabilities AS total_asset_moderate 25 | ,fa.vulnerabilities AS total_asset_vulnerabilities 26 | ,daga.asset_group_id AS asset_group_id 27 | FROM fact_asset fa 28 | LEFT JOIN dim_asset da ON da.asset_id = fa.asset_id 29 | LEFT JOIN dim_asset_group_asset daga ON da.asset_id = daga.asset_id 30 | GROUP BY da.asset_id, da.ip_address,da.mac_address,da.host_name, fa.riskscore, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, daga.asset_group_id 31 | ) 32 | --begin SELECT 33 | SELECT dfa.ip_address AS "IP" 34 | ,dfa.mac_address AS "MAC" 35 | ,dfa.host_name AS "Hostname" 36 | ,dfa.asset_group_id AS "Asset Group ID" 37 | ,to_char(round(dfa.asset_risk::numeric,0),'999G999G999') AS "Total Asset Risk" 38 | ,dfa.total_asset_moderate AS "Total Asset Moderate" 39 | ,dfa.total_asset_severe AS "Total Asset Severe" 40 | ,dfa.total_asset_critical AS "Total Asset Critical" 41 | ,dfa.total_asset_vulnerabilities AS "Total Asset Vulnerabilities" 42 | ,vr.nexpose_id AS "Nexpose ID" 43 | ,vr.aid AS "Age" 44 | , CASE 45 | WHEN vr.aid < 30 THEN '<30' 46 | WHEN vr.aid > 30 and vr.aid <= 60 THEN '30-60' 47 | WHEN vr.aid > 60 and vr.aid <= 90 THEN '61-90' 48 | ELSE '90+' 49 | END as "Aging" 50 | ,vr.title AS "Vulnerability" 51 | ,favi.date AS "Discovered Date" 52 | ,vr.severity AS "Vulnerability Severity" 53 | ,to_char(round(vr.vulnerability_risk::numeric,0),'999G999G999') AS "Vulnerability Risk" 54 | , CASE WHEN favi.port = -1 THEN NULL ELSE favi.port 55 | END AS "PORT" 56 | ,favi.protocol_id AS "Protocol" 57 | ,vr.exploits AS "Exploits" 58 | ,vr.malware_kits AS "Malware Kits" 59 | --,vr.description AS "Vulnerability Description" 60 | --,favi.proof AS "Proof" 61 | --end SELECT 62 | --begin FROM/JOIN 63 | FROM fact_asset_vulnerability_instance favi 64 | JOIN vuln_references vr ON vr.vulnerability_id = favi.vulnerability_id 65 | JOIN dfa_assets dfa ON dfa.asset_id = favi.asset_id 66 | --end FROM/JOIN 67 | WHERE dfa.asset_group_id = 2 AND vr.severity = 'Critical' 68 | ORDER BY dfa.host_name, dfa.ip_address -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | BSD 3-Clause License 2 | 3 | Copyright (c) 2019-2020, Rapid7, Inc. and nexpose-resource contributors 4 | All rights reserved. 5 | 6 | Redistribution and use in source and binary forms, with or without 7 | modification, are permitted provided that the following conditions are met: 8 | 9 | 1. Redistributions of source code must retain the above copyright notice, this 10 | list of conditions and the following disclaimer. 11 | 12 | 2. Redistributions in binary form must reproduce the above copyright notice, 13 | this list of conditions and the following disclaimer in the documentation 14 | and/or other materials provided with the distribution. 15 | 16 | 3. Neither the name of the copyright holder nor the names of its 17 | contributors may be used to endorse or promote products derived from 18 | this software without specific prior written permission. 19 | 20 | THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS" 21 | AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE 22 | IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE 23 | DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT HOLDER OR CONTRIBUTORS BE LIABLE 24 | FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL 25 | DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR 26 | SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER 27 | CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, 28 | OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE 29 | OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. 30 | -------------------------------------------------------------------------------- /Prebuilt Queries/New_and_Remediated_Vulnerabilities.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | 3 | assets_vulns AS ( 4 | SELECT 5 | fasv.asset_id, 6 | fasv.vulnerability_id, 7 | baselineComparison (fasv.scan_id, current_scan) AS baseline, 8 | s.baseline_scan, 9 | s.current_scan 10 | FROM 11 | fact_asset_scan_vulnerability_instance fasv 12 | JOIN ( 13 | SELECT 14 | asset_id, 15 | previousScan (asset_id) AS baseline_scan, 16 | lastScan (asset_id) AS current_scan 17 | FROM 18 | dim_asset 19 | ) s ON s.asset_id = fasv.asset_id 20 | AND ( 21 | fasv.scan_id = s.baseline_scan 22 | OR fasv.scan_id = s.current_scan 23 | ) 24 | GROUP BY 25 | fasv.asset_id, 26 | fasv.vulnerability_id, 27 | s.baseline_scan, 28 | s.current_scan 29 | HAVING 30 | ( 31 | baselineComparison (fasv.scan_id, current_scan) = 'Same' 32 | ) 33 | OR ( 34 | baselineComparison (fasv.scan_id, current_scan) = 'New' 35 | ) 36 | OR ( 37 | baselineComparison (fasv.scan_id, current_scan) = 'Old' 38 | ) 39 | ), 40 | --END assets_vulns 41 | baseline_scan_date AS ( 42 | SELECT 43 | av.asset_id, 44 | finished 45 | FROM assets_vulns av 46 | LEFT JOIN dim_scan ds ON ds.scan_id = av.baseline_scan 47 | GROUP BY av.asset_id, finished 48 | ), 49 | --END baseline_scan_date 50 | current_scan_date AS ( 51 | SELECT 52 | av.asset_id, 53 | finished 54 | FROM assets_vulns av 55 | LEFT JOIN dim_scan ds ON ds.scan_id = av.current_scan 56 | GROUP BY av.asset_id, finished 57 | ), 58 | --END current_scan_date 59 | new_vulns AS ( 60 | SELECT 61 | av.asset_id, 62 | av.vulnerability_id, 63 | COUNT (av.vulnerability_id) AS new_vulns 64 | FROM 65 | assets_vulns AS av 66 | WHERE 67 | av.baseline = 'New' 68 | GROUP BY 69 | av.asset_id, 70 | av.vulnerability_id 71 | ), 72 | --END new_vulns 73 | remediated_vulns AS ( 74 | SELECT 75 | av.asset_id, 76 | av.vulnerability_id, 77 | COUNT (av.vulnerability_id) AS remediated_vulns 78 | FROM 79 | assets_vulns AS av 80 | WHERE 81 | av.baseline = 'Old' 82 | GROUP BY 83 | av.asset_id, 84 | av.vulnerability_id 85 | ), 86 | --END remediated_vulns 87 | vuln_exploit_count AS ( 88 | SELECT 89 | CASE WHEN ec1.vulnerability_id IS NOT NULL THEN ec1.vulnerability_id ELSE ec2.vulnerability_id END AS vulnerability_id, metasploit, exploitdb 90 | FROM 91 | (SELECT 92 | av.vulnerability_id, 93 | COUNT(dve.source) AS metasploit 94 | FROM assets_vulns av 95 | JOIN dim_vulnerability_exploit dve ON av.vulnerability_id = dve.vulnerability_id 96 | WHERE dve.source = 'Metasploit' 97 | GROUP BY 98 | av.vulnerability_id 99 | ) ec1 100 | FULL JOIN 101 | (SELECT 102 | av.vulnerability_id, 103 | COUNT(dve.source) AS exploitdb 104 | FROM assets_vulns av 105 | JOIN dim_vulnerability_exploit dve ON av.vulnerability_id = dve.vulnerability_id 106 | WHERE dve.source = 'Exploit DB' 107 | GROUP BY 108 | av.vulnerability_id 109 | ) ec2 110 | ON ec2.vulnerability_id = ec1.vulnerability_id 111 | ) 112 | --END vuln_exploit_count 113 | SELECT 114 | 'Remediated' AS status, 115 | da1.ip_address AS ip_address, 116 | da1.host_name AS hostname, 117 | bsd.finished AS baseline_scan_datetime, 118 | csd.finished AS current_scan_datetime, 119 | dv1.vulnerability_id, 120 | dv1.title, 121 | CAST(dv1.cvss_score AS decimal(10,2)) AS cvss_score, 122 | CAST(dv1.riskscore AS decimal(10,0)) AS riskscore, 123 | dv1.malware_kits, 124 | CASE WHEN vec.metasploit IS NULL THEN 0 ELSE vec.metasploit END AS metasploit, 125 | CASE WHEN vec.exploitdb IS NULL THEN 0 ELSE vec.exploitdb END AS exploitdb 126 | FROM 127 | remediated_vulns rv 128 | JOIN dim_asset da1 ON da1.asset_id = rv.asset_id 129 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da1.asset_id 130 | LEFT JOIN current_scan_date csd ON csd.asset_id = da1.asset_id 131 | JOIN dim_vulnerability dv1 ON dv1.vulnerability_id = rv.vulnerability_id 132 | LEFT JOIN vuln_exploit_count vec ON vec.vulnerability_id = rv.vulnerability_id 133 | UNION ALL 134 | SELECT 135 | 'New' AS status, 136 | da2.ip_address AS ip_address, 137 | da2.host_name AS hostname, 138 | bsd.finished AS baseline_scan_datetime, 139 | csd.finished AS current_scan_datetime, 140 | dv2.vulnerability_id, 141 | dv2.title, 142 | CAST(dv2.cvss_score AS decimal(10,2)) AS cvss_score, 143 | CAST(dv2.riskscore AS decimal(10,0)) AS riskscore, 144 | dv2.malware_kits, 145 | CASE WHEN vec.metasploit IS NULL THEN 0 ELSE vec.metasploit END AS metasploit, 146 | CASE WHEN vec.exploitdb IS NULL THEN 0 ELSE vec.exploitdb END AS exploitdb 147 | FROM 148 | new_vulns nv 149 | JOIN dim_asset AS da2 ON da2.asset_id = nv.asset_id 150 | LEFT JOIN baseline_scan_date bsd ON bsd.asset_id = da2.asset_id 151 | LEFT JOIN current_scan_date csd ON csd.asset_id = da2.asset_id 152 | JOIN dim_vulnerability dv2 ON dv2.vulnerability_id = nv.vulnerability_id 153 | LEFT JOIN vuln_exploit_count vec ON vec.vulnerability_id = nv.vulnerability_id 154 | ORDER BY status DESC, ip_address, hostname, title -------------------------------------------------------------------------------- /Prebuilt Queries/Report_on_a_Single_Vulnerability.sql: -------------------------------------------------------------------------------- 1 | WITH remediations AS ( 2 | 3 | SELECT DISTINCT fr.solution_id AS ultimate_soln_id, summary, fix, estimate, riskscore, dshs.solution_id AS solution_id 4 | 5 | FROM fact_remediation(10,'riskscore DESC') fr 6 | 7 | JOIN dim_solution ds USING (solution_id) 8 | JOIN dim_solution_highest_supercedence dshs ON (fr.solution_id = dshs.superceding_solution_id AND ds.solution_id = dshs.superceding_solution_id) 9 | 10 | ), 11 | 12 | assets AS ( 13 | 14 | SELECT DISTINCT asset_id, host_name, ip_address 15 | 16 | FROM dim_asset 17 | 18 | GROUP BY asset_id, host_name, ip_address 19 | 20 | ) 21 | 22 | SELECT DISTINCT 23 | 24 | csv(DISTINCT dv.title) AS "Vulnerability Title", 25 | 26 | host_name AS "Asset Hostname", ip_address AS "Asset IP", 27 | 28 | round(sum(dv.riskscore)) AS "Asset Risk", 29 | 30 | summary AS "Solution", 31 | 32 | fix as "Fix" 33 | 34 | FROM remediations r 35 | JOIN dim_asset_vulnerability_solution dvs USING (solution_id) 36 | JOIN dim_vulnerability dv USING (vulnerability_id) 37 | JOIN assets USING (asset_id) 38 | 39 | WHERE dv.title = 'TLS Server Supports TLS version 1.0' 40 | 41 | GROUP BY r.riskscore, host_name, ip_address, asset_id, summary, fix 42 | ORDER BY "Asset Risk" DESC -------------------------------------------------------------------------------- /Prebuilt Queries/assets_grouped_count-of-vuln-by-severity.sql: -------------------------------------------------------------------------------- 1 | SELECT da.ip_address AS "IP", da.host_name AS "Hostname", dos.description as "OS", da.last_assessed_for_vulnerabilities AS "Last Assessed", fa.risk_score AS risk, fa.critical_vulnerabilities AS "Critical", fa.severe_vulnerabilities AS "Severe", fa.moderate_vulnerabilities AS "Moderate" 2 | 3 | /* Required to output fa.risk_score */ 4 | /* (CASE risk WHEN 0 THEN NULL ELSE risk END) / (CASE assets WHEN 0 THEN NULL ELSE assets END) AS "RiskPerAsset" */ 5 | CAST(fa.risk_score as decimal(10,0)) as risk, 6 | 7 | /* Created by Matt Wyen 8 | https://help.rapid7.com/nexpose/en-us/warehouse/warehouse-schema.html 9 | fact_asset table is where counts of vulnerabilities come from */ 10 | FROM fact_asset AS fa 11 | 12 | JOIN dim_asset da ON da.asset_id = fa.asset_id 13 | 14 | JOIN dim_operating_system as dos 15 | 16 | ON da.operating_system_id = dos.operating_system_id 17 | 18 | JOIN dim_site_asset as dsa 19 | 20 | ON fa.asset_id = dsa.asset_id 21 | 22 | /* I'm not sure if dim_site is required at this point - possible remove in DEV to test speed of report generation */ 23 | JOIN dim_site as dsite 24 | 25 | ON dsa.site_id = dsite.site_id 26 | 27 | /* Add all SELECT arguments here - this adds the column to the output */ 28 | GROUP BY da.host_name, da.ip_address, dos.description, da.last_assessed_for_vulnerabilities, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.risk_score 29 | 30 | ORDER BY "Hostname", "IP" -------------------------------------------------------------------------------- /Prebuilt Queries/assets_grouped_count-of-vuln-by-severity_v3.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | /* Created by Matt Wyen 3 | https://help.rapid7.com/nexpose/en-us/warehouse/warehouse-schema.html 4 | fact_asset table is where counts of vulnerabilities come from */ 5 | custom_tags AS ( 6 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS custom_tags 7 | FROM dim_tag 8 | JOIN dim_tag_asset USING (tag_id) 9 | WHERE tag_type = 'CUSTOM' 10 | GROUP BY asset_id 11 | ), 12 | location_tags AS ( 13 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS location_tags 14 | FROM dim_tag 15 | JOIN dim_tag_asset USING (tag_id) 16 | WHERE tag_type = 'LOCATION' 17 | GROUP BY asset_id 18 | ), 19 | owner_tags AS ( 20 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS owner_tags 21 | FROM dim_tag 22 | JOIN dim_tag_asset USING (tag_id) 23 | WHERE tag_type = 'OWNER' 24 | GROUP BY asset_id 25 | ), 26 | criticality_tags AS ( 27 | SELECT asset_id, CSV(tag_name ORDER BY tag_name) AS criticality_tags 28 | FROM dim_tag 29 | JOIN dim_tag_asset USING (tag_id) 30 | WHERE tag_type = 'CRITICALITY' 31 | GROUP BY asset_id 32 | ) 33 | 34 | Select DISTINCT da.ip_address AS "IP", da.host_name AS "Hostname", da.mac_address AS "MAC", dos.description AS "Operating System", da.last_assessed_for_vulnerabilities AS "Last Assessed", fa.critical_vulnerabilities AS "Critical", fa.severe_vulnerabilities AS "Severe", fa.moderate_vulnerabilities AS "Moderate", fa.vulnerabilities AS "Total", to_char(round(fa.riskscore::numeric,0),'999G999G999') AS "Risk", ct.custom_tags AS "Custom Tags", lt.location_tags AS "Location Tags", ot.owner_tags AS "Owner Tags", crt.criticality_tags AS "Criticality Tags" 35 | 36 | FROM dim_asset AS da 37 | JOIN dim_operating_system dos USING (operating_system_id) 38 | JOIN dim_tag_asset AS dta USING (asset_id) 39 | JOIN dim_tag AS dt ON dta.tag_id = dt.tag_id 40 | JOIN fact_asset as fa USING (asset_id) 41 | LEFT OUTER JOIN custom_tags ct USING (asset_id) 42 | LEFT OUTER JOIN location_tags lt USING (asset_id) 43 | LEFT OUTER JOIN owner_tags ot USING (asset_id) 44 | LEFT OUTER JOIN criticality_tags crt USING (asset_id) 45 | 46 | /* Add all SELECT arguments here - this adds the column to the output */ 47 | GROUP BY da.ip_address, da.host_name, da.mac_address, dos.description, da.last_assessed_for_vulnerabilities, fa.critical_vulnerabilities, fa.severe_vulnerabilities, fa.moderate_vulnerabilities, fa.vulnerabilities, to_char(round(fa.riskscore::numeric,0),'999G999G999'), ct.custom_tags, lt.location_tags, ot.owner_tags, crt.criticality_tags 48 | 49 | ORDER BY "Hostname", "IP" -------------------------------------------------------------------------------- /Prebuilt Queries/assets_vulns.sql: -------------------------------------------------------------------------------- 1 | with assets_vulns as ( 2 | SELECT 3 | fasv.asset_id, 4 | fasv.vulnerability_id, 5 | baselineComparison (fasv.scan_id, current_scan) AS baseline, 6 | s.baseline_scan, 7 | s.current_scan 8 | FROM 9 | fact_asset_scan_vulnerability_instance fasv 10 | JOIN ( 11 | SELECT 12 | asset_id, 13 | previousScan (asset_id) AS baseline_scan, 14 | lastScan (asset_id) AS current_scan 15 | FROM 16 | dim_asset 17 | ) s ON s.asset_id = fasv.asset_id 18 | AND ( 19 | fasv.scan_id = s.baseline_scan 20 | OR fasv.scan_id = s.current_scan 21 | ) 22 | GROUP BY 23 | fasv.asset_id, 24 | fasv.vulnerability_id, 25 | s.baseline_scan, 26 | s.current_scan 27 | HAVING 28 | ( 29 | baselineComparison (fasv.scan_id, current_scan) = 'Same' 30 | ) 31 | OR ( 32 | baselineComparison (fasv.scan_id, current_scan) = 'New' 33 | ) 34 | OR ( 35 | baselineComparison (fasv.scan_id, current_scan) = 'Old' 36 | ) 37 | ), 38 | --END assets_vulns -------------------------------------------------------------------------------- /Prebuilt Queries/baseline_scan_date.sql: -------------------------------------------------------------------------------- 1 | baseline_scan_date as ( 2 | SELECT 3 | av.asset_id, 4 | finished 5 | FROM assets_vulns av 6 | LEFT JOIN dim_scan ds ON ds.scan_id = av.baseline_scan 7 | GROUP BY av.asset_id, finished 8 | ), 9 | --END baseline_scan_date -------------------------------------------------------------------------------- /Prebuilt Queries/current_scan_date.sql: -------------------------------------------------------------------------------- 1 | current_scan_date as ( 2 | SELECT 3 | av.asset_id, 4 | finished 5 | FROM assets_vulns av 6 | LEFT JOIN dim_scan ds ON ds.scan_id = av.current_scan 7 | GROUP BY av.asset_id, finished 8 | ), 9 | --END current_scan_date -------------------------------------------------------------------------------- /Prebuilt Queries/hostname_IP_count-of-vuln.sql: -------------------------------------------------------------------------------- 1 | SELECT da.host_name AS Hostname, da.ip_address AS IP, fa.critical_vulnerabilities AS Critical, fa.severe_vulnerabilities AS Severe, fa.moderate_vulnerabilities AS Moderate 2 | 3 | FROM dim_asset da 4 | 5 | JOIN fact_asset fa USING (asset_id) 6 | 7 | ORDER BY da.host_name ASC -------------------------------------------------------------------------------- /Prebuilt Queries/new_vulns.sql: -------------------------------------------------------------------------------- 1 | new_vulns as ( 2 | SELECT 3 | av.asset_id, 4 | av.vulnerability_id, 5 | COUNT (av.vulnerability_id) AS new_vulns 6 | FROM 7 | assets_vulns AS av 8 | WHERE 9 | av.baseline = 'New' 10 | GROUP BY 11 | av.asset_id, 12 | av.vulnerability_id 13 | ), 14 | --END new_vulns -------------------------------------------------------------------------------- /Prebuilt Queries/rapid7-vulnerability_aging_dashboard_query.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | r7_aging AS ( 3 | SELECT asset_id 4 | vulnerability_id, 5 | age, 6 | age_in_days, 7 | first_discovered, 8 | most_recently_discovered 9 | FROM fact_asset_vulnerability_age 10 | ) 11 | SELECT asset_id, 12 | vulnerability_id, 13 | age_in_days, 14 | first_discovered 15 | FROM r7_aging 16 | JOIN dim_vulnerability USING (vulnerability_id) 17 | WHERE nexpose_id = 'php-cve-2008-3658' 18 | ORDER BY age_in_days DESC; 19 | -------------------------------------------------------------------------------- /Prebuilt Queries/remediated_vulns.sql: -------------------------------------------------------------------------------- 1 | remediated_vulns AS ( 2 | SELECT 3 | av.asset_id, 4 | av.vulnerability_id, 5 | COUNT (av.vulnerability_id) AS remediated_vulns 6 | FROM 7 | assets_vulns AS av 8 | WHERE 9 | av.baseline = 'Old' 10 | GROUP BY 11 | av.asset_id, 12 | av.vulnerability_id 13 | ), 14 | --END remediated_vulns -------------------------------------------------------------------------------- /Prebuilt Queries/vuln_exploit_count.sql: -------------------------------------------------------------------------------- 1 | vuln_exploit_count AS ( 2 | SELECT 3 | CASE WHEN ec1.vulnerability_id IS NOT NULL THEN ec1.vulnerability_id ELSE ec2.vulnerability_id END as vulnerability_id, metasploit, exploitdb 4 | FROM 5 | (SELECT 6 | av.vulnerability_id, 7 | COUNT(dve.source) as metasploit 8 | FROM assets_vulns av 9 | JOIN dim_vulnerability_exploit dve ON av.vulnerability_id = dve.vulnerability_id 10 | WHERE dve.source = 'Metasploit' 11 | GROUP BY 12 | av.vulnerability_id 13 | ) ec1 14 | FULL JOIN 15 | (SELECT 16 | av.vulnerability_id, 17 | COUNT(dve.source) as exploitdb 18 | FROM assets_vulns av 19 | JOIN dim_vulnerability_exploit dve ON av.vulnerability_id = dve.vulnerability_id 20 | WHERE dve.source = 'Exploit DB' 21 | GROUP BY 22 | av.vulnerability_id 23 | ) ec2 24 | ON ec2.vulnerability_id = ec1.vulnerability_id 25 | ) 26 | --END vuln_exploit_count -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/META-INF/MANIFEST.MF: -------------------------------------------------------------------------------- 1 | Manifest-Version: 1.0 2 | main-template-file: vulnerability-trends.jrxml 3 | resource-bundle-file: vulnerability-trends.properties 4 | report-engine-version: 1.0.0 5 | data-model-version: 2.2.0 6 | -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/critical.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/critical.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/exploit-vuln.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/exploit-vuln.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/malware-vuln.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/malware-vuln.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/moderate.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/moderate.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/severe.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/severe.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/total-assets.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/total-assets.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/images/total-vuln.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/images/total-vuln.png -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends.jasper: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/talltechy/InsightVM-SQL-Queries-Reports/cba76eae3a07a71f5109772be17fbf330c0b44ff/Prebuilt Queries/vulnerability-trends/vulnerability-trends.jasper -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends.properties: -------------------------------------------------------------------------------- 1 | title=Vulnerability Trends 2 | reportdate=Report date: 3 | trendperiod=Trend period: 4 | through=through 5 | nodatasection=Based on your scan results or configuration settings, there is no data to display. 6 | startdate=Start date: 7 | enddate=End date: 8 | trendbyassetstitle=Assets Scanned and Vulnerabilities Discovered 9 | vulnwithmalwareorexploittitle=Vulnerabilities with Malware or Exploit Exposures 10 | trendbyseveritytitle=Severity Levels 11 | vulnerabilities=Vulnerabilities 12 | assets=Assets 13 | totalvulnerabilites=Total Vulnerabilities 14 | totalassetsscanned=Total Assets Scanned 15 | increase=increase 16 | decrease=decrease 17 | was=was {0} 18 | trendbyseveriatytitle=Trend by Severity 19 | malwarevulnerabilities=Vulnerabilities with Malware Kits 20 | exploitablevulnerabilities=Vulnerabilities with Known Exploits 21 | trendbyvulnagetitle=Vulnerability Age 22 | NA=N/A 23 | critical=Critical Vulnerabilities 24 | severe=Severe Vulnerabilities 25 | moderate=Moderate Vulnerabilities 26 | start=Start: 27 | end=End: 28 | morethan90days=More than 90 days 29 | morethan60days=61 to 90 days 30 | morethan30days=31 to 60 days 31 | exploitableormalware=with malware kits 32 | knownexploits=or known exploits 33 | -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends_ja_JP.properties: -------------------------------------------------------------------------------- 1 | title=\u8106\u5F31\u6027\u30C8\u30EC\u30F3\u30C9 2 | reportdate=\u30EC\u30DD\u30FC\u30C8\u65E5\uFF1A 3 | trendperiod=\u30C8\u30EC\u30F3\u30C9\u671F\u9593\uFF1A 4 | through=through 5 | nodatasection=\u30B9\u30AD\u30E3\u30F3\u7D50\u679C\u307E\u305F\u306F\u69CB\u6210\u8A2D\u5B9A\u306B\u57FA\u3065\u304D\u3001\u8868\u793A\u3059\u308B\u30C7\u30FC\u30BF\u304C\u3042\u308A\u307E\u305B\u3093\u3002 6 | startdate=\u958B\u59CB\u65E5\uFF1A 7 | enddate=\u7D42\u4E86\u65E5: 8 | trendbyassetstitle=\u30B9\u30AD\u30E3\u30F3\u3055\u308C\u305F\u30A2\u30BB\u30C3\u30C8\u304A\u3088\u3073\u767A\u898B\u3055\u308C\u305F\u8106\u5F31\u6027 9 | vulnwithmalwareorexploittitle=\u30DE\u30EB\u30A6\u30A7\u30A2\u307E\u305F\u306F\u30A8\u30AF\u30B9\u30D7\u30ED\u30A4\u30C8\u306B\u3055\u3089\u3055\u308C\u305F\u8106\u5F31\u6027 10 | trendbyseveritytitle=\u6DF1\u523B\u5EA6\u30EC\u30D9\u30EB 11 | vulnerabilities=\u8106\u5F31\u6027 12 | assets=\u30A2\u30BB\u30C3\u30C8 13 | totalvulnerabilites=\u8106\u5F31\u6027\u5408\u8A08 14 | totalassetsscanned=\u30B9\u30AD\u30E3\u30F3\u3055\u308C\u305F\u30A2\u30BB\u30C3\u30C8\u5408\u8A08 15 | increase=\u5897 16 | decrease=\u6E1B 17 | was=\u4EE5\u524D\u306F{0} 18 | trendbyseveriatytitle=\u6DF1\u523B\u5EA6\u5225\u306E\u30C8\u30EC\u30F3\u30C9 19 | malwarevulnerabilities=\u30DE\u30EB\u30A6\u30A7\u30A2\u30AD\u30C3\u30C8\u3042\u308A\u306E\u8106\u5F31\u6027 20 | exploitablevulnerabilities=\u65E2\u77E5\u306E\u30A8\u30AF\u30B9\u30D7\u30ED\u30A4\u30C8\u3042\u308A\u306E\u8106\u5F31\u6027 21 | trendbyvulnagetitle=Vulnerability Age 22 | NA=N/A 23 | critical=\u5371\u6A5F\u7684\u306A\u8106\u5F31\u6027 24 | severe=\u6DF1\u523B\u306A\u8106\u5F31\u6027 25 | moderate=\u4E2D\u5EA6\u306A\u8106\u5F31\u6027 26 | start=\u958B\u59CB\uFF1A 27 | end=\u7D42\u4E86\uFF1A 28 | morethan90days=90\u65E5\u4EE5\u4E0A 29 | morethan60days=61\uFF5E90\u65E5 30 | morethan30days=31\uFF5E60\u65E5 31 | exploitableormalware=\u30DE\u30EB\u30A6\u30A7\u30A2\u30AD\u30C3\u30C8\u3042\u308A 32 | knownexploits=\u307E\u305F\u306F\u65E2\u77E5\u306E\u30A8\u30AF\u30B9\u30D7\u30ED\u30A4\u30C8 -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends_ko_KR.properties: -------------------------------------------------------------------------------- 1 | title=\uCDE8\uC57D\uC131 \uCD94\uC138 2 | reportdate=\uBCF4\uACE0\uC11C \uB0A0\uC9DC: 3 | trendperiod=\uCD94\uC138 \uAE30\uAC04: 4 | through=through 5 | nodatasection=\uC2A4\uCE94 \uACB0\uACFC \uB610\uB294 \uAD6C\uC131 \uC124\uC815\uC744 \uACE0\uB824\uD560 \uB54C, \uD45C\uC2DC\uD560 \uB370\uC774\uD130\uAC00 \uC5C6\uC2B5\uB2C8\uB2E4. 6 | startdate=\uC2DC\uC791 \uB0A0\uC9DC: 7 | enddate=\uC885\uB8CC \uB0A0\uC9DC: 8 | trendbyassetstitle=\uAC80\uC0C9\uB41C \uC790\uC0B0 \uBC0F \uCDE8\uC57D\uC810 9 | vulnwithmalwareorexploittitle=\uBA40\uC6E8\uC5B4 \uB610\uB294 \uC775\uC2A4\uD50C\uB85C\uC774\uD2B8 \uB178\uCD9C \uAD00\uB828 \uCDE8\uC57D\uC810 10 | trendbyseveritytitle=\uC2EC\uAC01\uB3C4 \uC218\uC900 11 | vulnerabilities=\uCDE8\uC57D\uC810 12 | assets=\uC790\uC0B0 13 | totalvulnerabilites=\uC804\uCCB4 \uCDE8\uC57D\uC810 14 | totalassetsscanned=\uAC80\uC0C9\uB41C \uCD1D \uC790\uC0B0 15 | increase=\uC99D\uAC00 16 | decrease=\uAC10\uC18C 17 | was={0} \uC774\uC5C8\uC74C 18 | trendbyseveriatytitle=\uC2EC\uAC01\uB3C4\uC5D0 \uB530\uB978 \uCD94\uC138 19 | malwarevulnerabilities=\uBA40\uC6E8\uC5B4 \uD0A4\uD2B8 \uAD00\uB828 \uCDE8\uC57D\uC810 20 | exploitablevulnerabilities=\uC54C\uB824\uC9C4 \uC775\uC2A4\uD50C\uB85C\uC774\uD2B8 \uAD00\uB828 \uCDE8\uC57D\uC810 21 | trendbyvulnagetitle=Vulnerability Age 22 | NA=\uD574\uB2F9 \uC5C6\uC74C 23 | critical=\uCDE8\uC57D\uC810 \uC0C1 24 | severe=\uCDE8\uC57D\uC810 \uC911 25 | moderate=\uCDE8\uC57D\uC810 \uD558 26 | start=\uC2DC\uC791: 27 | end=\uC885\uB8CC: 28 | morethan90days=90\uC77C \uCD08\uACFC 29 | morethan60days=61~90\uC77C 30 | morethan30days=31~60 \uC77C 31 | exploitableormalware=\uBA40\uC6E8\uC5B4 \uD0A4\uD2B8 32 | knownexploits=\uB610\uB294 \uC54C\uB824\uC9C4 \uC775\uC2A4\uD50C\uB85C\uC774\uD2B8 -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends_zh_CN.properties: -------------------------------------------------------------------------------- 1 | title=\u6F0F\u6D1E\u8D8B\u52BF 2 | reportdate=\u62A5\u544A\u65E5\u671F\uFF1A 3 | trendperiod=\u8D8B\u52BF\u65F6\u95F4\uFF1A 4 | through=through 5 | nodatasection=\u6839\u636E\u60A8\u7684\u626B\u63CF\u7ED3\u679C\u6216\u914D\u7F6E\u8BBE\u7F6E\uFF0C\u65E0\u6570\u636E\u663E\u793A\u3002 6 | startdate=\u5F00\u59CB\u65E5\u671F\uFF1A 7 | enddate=\u7ED3\u675F\u65E5\u671F\uFF1A 8 | trendbyassetstitle=\u5DF2\u626B\u63CF\u7684\u8D44\u4EA7\u548C\u5DF2\u53D1\u73B0\u7684\u6F0F\u6D1E 9 | vulnwithmalwareorexploittitle=\u5177\u6709\u6076\u610F\u8F6F\u4EF6\u6216\u5229\u7528\u62AB\u9732\u7684\u6F0F\u6D1E 10 | trendbyseveritytitle=\u4E25\u91CD\u6027\u7EA7\u522B 11 | vulnerabilities=\u6F0F\u6D1E 12 | assets=\u8D44\u4EA7 13 | totalvulnerabilites=\u6F0F\u6D1E\u603B\u6570 14 | totalassetsscanned=\u5DF2\u626B\u63CF\u7684\u603B\u8D44\u4EA7 15 | increase=\u589E\u52A0 16 | decrease=\u51CF\u5C11 17 | was=\u662F {0} 18 | trendbyseveriatytitle=\u6309\u4E25\u91CD\u6027\u5212\u5206\u7684\u8D8B\u52BF 19 | malwarevulnerabilities=\u5177\u6709\u6076\u610F\u8F6F\u4EF6\u5957\u4EF6\u7684\u6F0F\u6D1E 20 | exploitablevulnerabilities=\u5177\u6709\u5DF2\u77E5\u5229\u7528\u7684\u6F0F\u6D1E 21 | trendbyvulnagetitle=\u6F0F\u6D1E\u5B58\u5728\u6642\u9593 22 | NA=\u4E0D\u9002\u7528 23 | critical=\u5173\u952E\u6F0F\u6D1E 24 | severe=\u4E25\u91CD\u6F0F\u6D1E 25 | moderate=\u4E2D\u7B49\u6F0F\u6D1E 26 | start=\u5F00\u59CB\uFF1A 27 | end=\u7ED3\u675F\uFF1A 28 | morethan90days=\u8D85\u8FC7 90 \u5929 29 | morethan60days=61 \u81F3 90 \u5929 30 | morethan30days=31 \u81F3 60 \u5929 31 | exploitableormalware=\u5177\u6709\u6076\u610F\u8F6F\u4EF6\u5957\u4EF6 32 | knownexploits=\u6216\u5DF2\u77E5\u5229\u7528 -------------------------------------------------------------------------------- /Prebuilt Queries/vulnerability-trends/vulnerability-trends_zh_HK.properties: -------------------------------------------------------------------------------- 1 | #Fri Nov 28 05:53:20 PST 2014 2 | decrease=\u6E1B\u5C11 3 | morethan30days=31 \u81F3 60 \u5929 4 | NA=N/A 5 | end=\u7D50\u675F\uFF1A 6 | trendperiod=\u8DA8\u52E2\u671F\u9593\uFF1A 7 | totalassetsscanned=\u5DF2\u6383\u63CF\u7684\u8CC7\u7522\u7E3D\u6578 8 | trendbyvulnagetitle=\u6F0F\u6D1E\u5B58\u5728\u6642\u9593 9 | start=\u958B\u59CB\uFF1A 10 | vulnwithmalwareorexploittitle=\u5177\u6709\u60E1\u610F\u8EDF\u9AD4\u6216\u5229\u7528\u6F0F\u6D1E\u653B\u64CA\u66B4\u9732\u7684\u6F0F\u6D1E 11 | moderate=\u4E2D\u7B49\u6F0F\u6D1E 12 | trendbyassetstitle=\u5DF2\u6383\u63CF\u7684\u8CC7\u7522\u548C\u5DF2\u767C\u73FE\u7684\u6F0F\u6D1E 13 | was=\u662F {0} 14 | increase=\u589E\u52A0 15 | reportdate=\u5831\u544A\u65E5\u671F\uFF1A 16 | knownexploits=\u6216\u5DF2\u77E5\u653B\u64CA 17 | morethan60days=61 \u81F3 90 \u5929 18 | severe=\u56B4\u91CD\u7684\u6F0F\u6D1E 19 | nodatasection=\u6839\u64DA\u6383\u63CF\u7D50\u679C\u6216\u8A2D\u5B9A\uFF0C\u6C92\u6709\u8981\u986F\u793A\u7684\u8CC7\u6599\u3002 20 | enddate=\u7D50\u675F\u65E5\u671F\uFF1A 21 | malwarevulnerabilities=\u5177\u6709\u60E1\u610F\u8EDF\u9AD4\u5DE5\u5177\u5305\u7684\u6F0F\u6D1E 22 | trendbyseveritytitle=\u56B4\u91CD\u6027\u7D1A\u5225 23 | critical=\u95DC\u9375\u7684\u6F0F\u6D1E 24 | through=\u900F\u904E 25 | assets=\u8CC7\u7522 26 | exploitablevulnerabilities=\u5177\u6709\u5DF2\u77E5\u653B\u64CA\u7684\u6F0F\u6D1E 27 | morethan90days=\u8D85\u51FA 90 \u5929 28 | startdate=\u958B\u59CB\u65E5\u671F\uFF1A 29 | vulnerabilities=\u6F0F\u6D1E 30 | exploitableormalware=\u5177\u6709\u60E1\u610F\u8EDF\u9AD4\u5DE5\u5177\u5305 31 | trendbyseveriatytitle=\u4F9D\u56B4\u91CD\u6027\u5217\u51FA\u7684\u8DA8\u52E2 32 | totalvulnerabilites=\u6F0F\u6D1E\u7E3D\u6578 33 | title=\u6F0F\u6D1E\u8DA8\u52E2 -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # Various SQL Queries, Reports and Documentation for InsightVM Console SQL and Data Warehouse 2 | 3 | ## Data Model Information 4 | 5 | * [Understanding the reporting data model: Facts](https://insightvm.help.rapid7.com/docs/understanding-the-reporting-data-model-facts) 6 | * [Understanding the reporting data model: Dimensions](https://insightvm.help.rapid7.com/docs/understanding-the-reporting-data-model-dimensions) 7 | * [Understanding the reporting data model: Functions](https://insightvm.help.rapid7.com/docs/understanding-the-reporting-data-model-functions) 8 | 9 | *** 10 | 11 | ## Warehousing and Databases 12 | 13 | * [Warehouse Schema](https://help.rapid7.com/nexpose/en-us/warehouse/warehouse-schema.html) 14 | * [Configuring data warehousing settings](https://insightvm.help.rapid7.com/docs/configuring-data-warehousing-settings) 15 | 16 | *** 17 | 18 | ## Report Building 19 | 20 | * [Creating reports based on SQL queries](https://insightvm.help.rapid7.com/docs/creating-reports-based-on-sql-queries) 21 | * [For ASVs: Consolidating three report templates into one custom template](https://insightvm.help.rapid7.com/docs/for-asvs-consolidating-three-report-templates-into-one-custom-template) 22 | * [Configuring custom report templates](https://insightvm.help.rapid7.com/docs/configuring-custom-report-templates) 23 | * [Working with report formats](https://insightvm.help.rapid7.com/docs/working-with-report-formats) 24 | * [Understanding report content](https://insightvm.help.rapid7.com/docs/understanding-report-content) 25 | * [Distributing, sharing, and exporting reports](https://insightvm.help.rapid7.com/docs/distributing-sharing-and-exporting-reports) 26 | -------------------------------------------------------------------------------- /Reports/All Vulnerabilities per asset (Filter via console).sql: -------------------------------------------------------------------------------- 1 | WITH 2 | vulnerability_raw AS ( 3 | SELECT 4 | favi.asset_id, 5 | favi.vulnerability_id 6 | FROM fact_asset_vulnerability_instance favi 7 | ), 8 | asset_metadata AS ( 9 | SELECT 10 | da.asset_id, 11 | da.ip_address, 12 | da.host_name 13 | FROM dim_asset da 14 | ) 15 | SELECT 16 | vfa.asset_id, 17 | am.ip_address, 18 | UPPER(regexp_replace(am.host_name, '([\.][\w\.]+)', '', 'g')) AS hostname, 19 | vfa.vulnerability_id, 20 | vfa.nexpose_id, 21 | vfa.vulnerability_title, 22 | vfa.severity, 23 | round(vfa.riskscore::numeric, 0) AS risk, 24 | vfa.exploits, 25 | vfa.malware_kits 26 | FROM ( 27 | SELECT 28 | vraw.asset_id, 29 | vraw.vulnerability_id, 30 | dv.nexpose_id, 31 | dv.title AS vulnerability_title, 32 | dv.severity, 33 | dv.riskscore, 34 | dv.exploits, 35 | dv.malware_kits 36 | FROM vulnerability_raw vraw 37 | JOIN dim_vulnerability dv ON dv.vulnerability_id = vraw.vulnerability_id 38 | ) vfa 39 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 40 | WHERE 1=1 -- No filtering is being done in this query 41 | ORDER BY vfa.asset_id, vfa.vulnerability_title; 42 | -------------------------------------------------------------------------------- /Reports/Executive_Report_v5.sql: -------------------------------------------------------------------------------- 1 | WITH 2 | -- Created by Matt Wyen 3 | asset_metadata AS ( 4 | SELECT fa.asset_id 5 | ,da.ip_address 6 | -- UPPER wraps the Regex and formats as uppercase 7 | -- regexp_replace takes the hostname and removes all the DNS extras such as .exampledomain.tld and leaves only regular asset names 8 | ,UPPER(regexp_replace(da.host_name, '([\.][\w\.]+)', '', 'g')) AS hostname 9 | ,da.mac_address 10 | ,dos.description 11 | ,fa.critical_vulnerabilities AS total_critical 12 | ,fa.severe_vulnerabilities AS total_severe 13 | ,fa.moderate_vulnerabilities AS total_moderate 14 | ,fa.vulnerabilities AS total_vulnerabilities 15 | ,da.last_assessed_for_vulnerabilities AS last_assessed 16 | -- This is an aggregate of all sites this asset belongs to, dont be surprised if you see more than what you filtered on via the console 17 | ,da.sites 18 | FROM fact_asset fa 19 | LEFT JOIN dim_asset da ON fa.asset_id = da.asset_id 20 | LEFT JOIN dim_operating_system dos ON dos.operating_system_id = da.operating_system_id 21 | ) 22 | SELECT vfa.asset_id 23 | -- Reference of the all sites aggregate from asset metadata 24 | ,am.sites AS "All Sites" 25 | ,am.ip_address 26 | ,am.hostname 27 | -- This calls the already formatted hostname from asset_metadata and runs a CASE statement to replace blank values with the word blank for formatting/sorting purposes 28 | ,CASE 29 | WHEN am.hostname = ' ' THEN vfa.asset_id::TEXT 30 | WHEN am.hostname IS NULL THEN vfa.asset_id::TEXT 31 | WHEN am.hostname IS NOT NULL THEN am.hostname 32 | ELSE vfa.asset_id::TEXT 33 | END as "Hostname Replace Blank" 34 | ,am.mac_address AS "MAC" 35 | ,am.description AS "Operating System" 36 | ,am.last_assessed AS "Last Assessed" 37 | ,am.total_critical AS "Critical" 38 | ,am.total_severe AS "Severe" 39 | ,am.total_moderate AS "Moderate" 40 | ,am.total_vulnerabilities AS "Total" 41 | ,vfa.vulnerability_title 42 | -- Preformated severity 43 | ,vfa.severity 44 | -- Legible riskscore 45 | ,vfa.risk 46 | ,vfa.exploits 47 | ,vfa.malware_kits 48 | FROM ( 49 | -- List the age of vuln findings in scope, along with their title, site/asset information, and instance count 50 | SELECT avd.asset_id 51 | ,dv.title AS vulnerability_title 52 | -- Preformated severity 53 | ,dv.severity 54 | -- This makes the risk score legible and gets rid of extra decimal places 55 | ,round(dv.riskscore::numeric, 0) AS risk 56 | ,dv.exploits 57 | ,dv.malware_kits 58 | FROM ( 59 | SELECT favf.asset_id 60 | ,favf.vulnerability_id 61 | FROM fact_asset_vulnerability_finding favf 62 | GROUP BY favf.asset_id 63 | ,favf.vulnerability_id 64 | -- ,ava.age 65 | ) avd 66 | JOIN dim_vulnerability dv ON dv.vulnerability_id = avd.vulnerability_id 67 | ) vfa 68 | JOIN asset_metadata am ON vfa.asset_id = am.asset_id 69 | -- Note there is no WHERE clause on purpose, you have to filter assets via the InsightVM console SQL report - You select an Asset, Site or Asset Group 70 | ORDER BY asset_id 71 | ,vulnerability_title -------------------------------------------------------------------------------- /Reports/Vulnerability Exceptions/Vulnerability_Exceptions_by_asset(limit-to-CVE).sql: -------------------------------------------------------------------------------- 1 | SELECT da.ip_address as "IP Address", 2 | da.host_name as "Host Name", 3 | dv.nexpose_id, 4 | dv.title as "Vulnerability", 5 | descope.description as "Scope", 6 | dve.additional_comments as "Comments", 7 | dest.description as "Exception Type", 8 | dve.submitted_by "Submitted by", 9 | dve.reviewed_by as "Reviewed by", 10 | dve.review_comment as "Reviewer's Comment", 11 | dve.expiration_date as "Exception Expiration Date" 12 | -- We often get compliments for Nexpose Exceptions Workflow which allows you to "ignore" vulnerabilities based on compensating controls or say acceptable use or risk. 13 | -- You can change the following to look at the information from different perspectives: 14 | -- dve.reason_id = 'F' 15 | -- False Positive = 'F' 16 | -- Compensating Control = 'C' 17 | -- Acceptable Use = 'U' 18 | -- Acceptable Risk = 'R' 19 | -- Other = 'O' 20 | FROM dim_asset da 21 | JOIN dim_vulnerability_exception dve using (asset_id) 22 | JOIN dim_vulnerability dv using (vulnerability_id) 23 | JOIN dim_exception_scope descope using (scope_id) 24 | JOIN dim_exception_status dest using (status_id) 25 | WHERE dv.nexpose_id = 'msft-cve-2019-0613' 26 | GROUP BY da.ip_address, 27 | dv.nexpose_id, 28 | dv.title, 29 | da.host_name, 30 | descope.description, 31 | dve.additional_comments, 32 | dest.description, 33 | dve.reason_id, 34 | dve.submitted_by, 35 | dve.reviewed_by, 36 | dve.review_comment, 37 | dve.expiration_date 38 | ORDER BY da.ip_address DESC -------------------------------------------------------------------------------- /Reports/Vulnerability Exceptions/Vulnerability_Exceptions_by_asset(limit-to-reason_id).sql: -------------------------------------------------------------------------------- 1 | SELECT da.ip_address as "IP Address", 2 | da.host_name as "Host Name", 3 | dv.title as "Vulnerability", 4 | descope.description as "Scope", 5 | dve.additional_comments as "Comments", 6 | dest.description as "Exception Type", 7 | dve.submitted_by "Submitted by", 8 | dve.reviewed_by as "Reviewed by", 9 | dve.review_comment as "Reviewer's Comment", 10 | dve.expiration_date as "Exception Expiration Date" 11 | -- We often get compliments for Nexpose Exceptions Workflow which allows you to "ignore" vulnerabilities based on compensating controls or say acceptable use or risk. 12 | -- You can change the following to look at the information from different perspectives: 13 | -- dve.reason_id = 'F' 14 | -- False Positive = 'F' 15 | -- Compensating Control = 'C' 16 | -- Acceptable Use = 'U' 17 | -- Acceptable Risk = 'R' 18 | -- Other = 'O' 19 | FROM dim_asset da 20 | JOIN dim_vulnerability_exception dve using (asset_id) 21 | JOIN dim_vulnerability dv using (vulnerability_id) 22 | JOIN dim_exception_scope descope using (scope_id) 23 | JOIN dim_exception_status dest using (status_id) 24 | WHERE dve.reason_id = 'F' 25 | GROUP BY da.ip_address, 26 | dv.title, 27 | da.host_name, 28 | descope.description, 29 | dve.additional_comments, 30 | dest.description, 31 | dve.reason_id, 32 | dve.submitted_by, 33 | dve.reviewed_by, 34 | dve.review_comment, 35 | dve.expiration_date 36 | ORDER BY da.ip_address DESC -------------------------------------------------------------------------------- /Reports/Vulnerability Exceptions/Vulnerability_Exceptions_by_asset(not-limited).sql: -------------------------------------------------------------------------------- 1 | SELECT da.ip_address as "IP Address", 2 | da.host_name as "Host Name", 3 | dv.nexpose_id, 4 | dv.title as "Vulnerability", 5 | descope.description as "Scope", 6 | dve.additional_comments as "Comments", 7 | dest.description as "Exception Type", 8 | dve.submitted_by "Submitted by", 9 | dve.reviewed_by as "Reviewed by", 10 | dve.review_comment as "Reviewer's Comment", 11 | dve.expiration_date as "Exception Expiration Date" 12 | -- We often get compliments for Nexpose Exceptions Workflow which allows you to "ignore" vulnerabilities based on compensating controls or say acceptable use or risk. 13 | -- You can change the following to look at the information from different perspectives: 14 | -- dve.reason_id = 'F' 15 | -- False Positive = 'F' 16 | -- Compensating Control = 'C' 17 | -- Acceptable Use = 'U' 18 | -- Acceptable Risk = 'R' 19 | -- Other = 'O' 20 | FROM dim_asset da 21 | JOIN dim_vulnerability_exception dve using (asset_id) 22 | JOIN dim_vulnerability dv using (vulnerability_id) 23 | JOIN dim_exception_scope descope using (scope_id) 24 | JOIN dim_exception_status dest using (status_id) 25 | GROUP BY da.ip_address, 26 | dv.nexpose_id, 27 | dv.title, 28 | da.host_name, 29 | descope.description, 30 | dve.additional_comments, 31 | dest.description, 32 | dve.reason_id, 33 | dve.submitted_by, 34 | dve.reviewed_by, 35 | dve.review_comment, 36 | dve.expiration_date 37 | ORDER BY da.ip_address DESC --------------------------------------------------------------------------------