Module: NexposeTicketing::Queries

Defined in:
lib/nexpose_ticketing/queries.rb

Overview

This class serves as repository of SQL queries to be executed by the SQL Repository Exporter for Nexpose.

Copyright

Copyright © 2014 Rapid7, LLC.

Class Method Summary collapse

Class Method Details

.all_new_vulns(options = {}) ⇒ Object

Gets all delta vulns for all sites sorted by IP.

  • Returns : -Returns |asset_id| |ip_address| |current_scan| |vulnerability_id||solution_id| |nexpose_id|

    |url| |summary| |fix|
    


66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
# File 'lib/nexpose_ticketing/queries.rb', line 66

def self.all_new_vulns(options = {})
  "SELECT DISTINCT on (da.ip_address, subs.vulnerability_id) subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
   string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                       '|Nexpose ID: ' || ds.nexpose_id ||
                       '|Fix: ' || coalesce(proofAsText(ds.fix), 'None') ||
                       '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
   fa.riskscore, dv.cvss_score,
   string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
    fasva.first_discovered, fasva.most_recently_discovered
    FROM (SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
          FROM dim_asset #{createAssetString(options)}) s
          ON s.asset_id = fasv.asset_id AND (fasv.scan_id = s.baseline_scan OR fasv.scan_id = s.current_scan)
          GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan, fasv.scan_id
          HAVING NOT baselineComparison(fasv.scan_id, current_scan) = 'Old'
      ) subs
      JOIN dim_vulnerability dv USING (vulnerability_id)
      LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
      JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
      JOIN fact_asset_vulnerability_age fasva ON subs.vulnerability_id = fasva.vulnerability_id AND subs.asset_id = fasva.asset_id
      JOIN dim_solution ds USING (solution_id)
      JOIN dim_asset da ON subs.asset_id = da.asset_id
      JOIN fact_asset fa ON fa.asset_id = da.asset_id
      #{createRiskString( options[:riskScore])}
      GROUP BY subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
             fa.riskscore, dv.cvss_score, fasva.first_discovered, fasva.most_recently_discovered
      ORDER BY da.ip_address, subs.vulnerability_id"
end

.all_new_vulns_by_vuln_id(options = {}) ⇒ Object

Gets all delta vulns for all sites sorted by vuln ID.

  • Returns : -Returns |asset_id| |ip_address| |current_scan| |vulnerability_id||solution_id| |nexpose_id|

    |url| |summary| |fix|
    


104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
# File 'lib/nexpose_ticketing/queries.rb', line 104

def self.all_new_vulns_by_vuln_id(options = {})
    "SELECT DISTINCT on (subs.vulnerability_id) subs.vulnerability_id, dv.title, MAX(dv.cvss_score) as cvss_score,
               string_agg(DISTINCT subs.asset_id ||
                 '|' || da.ip_address ||
                 '|' || coalesce(da.host_name, '')  ||
                 '|' || fa.riskscore, '~') as assets,
             
               string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                 '|Nexpose ID: ' || ds.nexpose_id ||
                 '|Fix: ' || coalesce(proofAsText(ds.fix)) ||
                 '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
     string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references
      FROM (SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan
        FROM fact_asset_scan_vulnerability_finding fasv
        JOIN
        (
          SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
            FROM dim_asset #{createAssetString(options)}) s
            ON s.asset_id = fasv.asset_id AND (fasv.scan_id = s.baseline_scan OR fasv.scan_id = s.current_scan)
            GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan, fasv.scan_id
            HAVING NOT baselineComparison(fasv.scan_id, current_scan) = 'Old'
        ) subs
      JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
      LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
      JOIN dim_solution ds USING (solution_id)
      JOIN dim_asset da ON subs.asset_id = da.asset_id
      JOIN dim_vulnerability dv ON subs.vulnerability_id = dv.vulnerability_id
      JOIN fact_asset fa ON fa.asset_id = da.asset_id
      JOIN fact_asset_vulnerability_age fasva ON subs.vulnerability_id = fasva.vulnerability_id AND subs.asset_id = fasva.asset_id
      #{createRiskString(options[:riskScore])}
      
      GROUP BY subs.vulnerability_id, dv.title
      ORDER BY subs.vulnerability_id"
end

.all_vulns_by_vuln_id_since_scan(options = {}) ⇒ Object

Gets all vulnerabilities happening after a reported scan id. Sorted by vuln ID. This result set also includes the baseline comparision (“Old”, “New”, or “Same”) allowing for vulnerability-based ticket updating.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |solution_id| |nexpose_id| |url| |summary| |fix| |comparison|



346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
# File 'lib/nexpose_ticketing/queries.rb', line 346

def self.all_vulns_by_vuln_id_since_scan(options = {})
  "SELECT DISTINCT on (subs.vulnerability_id, subs.comparison) subs.vulnerability_id, dv.title, MAX(dv.cvss_score) as cvss_score,
               string_agg(DISTINCT subs.asset_id ||
                 '|' || da.ip_address ||
                 '|' || coalesce(da.host_name, '')  ||
                 '|' || fa.riskscore, '~') as assets,
             
               string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                 '|Nexpose ID: ' || ds.nexpose_id ||
                 '|Fix: ' || coalesce(proofAsText(ds.fix)) ||
                 '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
               string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
               subs.comparison
    FROM (
      SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) = 'Old'
    ) subs
    JOIN dim_vulnerability dv USING (vulnerability_id)
    LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
    JOIN dim_vulnerability_solution dvs USING (vulnerability_id)
    JOIN dim_solution ds USING (solution_id)
    JOIN dim_asset da ON subs.asset_id = da.asset_id
    JOIN fact_asset fa ON fa.asset_id = subs.asset_id
     #{createRiskString(options[:riskScore])}
    AND subs.current_scan > #{options[:scan_id]}
    GROUP BY subs.vulnerability_id, dv.title, subs.comparison

    UNION

    SELECT DISTINCT on (subs.vulnerability_id, subs.comparison) subs.vulnerability_id, dv.title, MAX(dv.cvss_score) as cvss_score,
               string_agg(DISTINCT subs.asset_id ||
                 '|' || da.ip_address ||
                 '|' || coalesce(da.host_name, '')  ||
                 '|' || fa.riskscore, '~') as assets,
             
               string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                 '|Nexpose ID: ' || ds.nexpose_id ||
                 '|Fix: ' || coalesce(proofAsText(ds.fix)) ||
                 '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
               string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
               subs.comparison
    FROM 
    (
      SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id,lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) IN ('Same','New')
    ) subs
    JOIN dim_vulnerability dv USING (vulnerability_id)
    LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
    JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
    JOIN dim_solution ds USING (solution_id)
    JOIN dim_asset da ON subs.asset_id = da.asset_id
    JOIN fact_asset fa ON fa.asset_id = subs.asset_id
    #{createRiskString(options[:riskScore])}
    AND subs.current_scan > #{options[:scan_id]}
    GROUP BY subs.vulnerability_id, dv.title, subs.comparison

    ORDER BY vulnerability_id, comparison"
end

.all_vulns_since_scan(options = {}) ⇒ Object

Gets all vulnerabilities happening after a reported scan id. This result set also includes the baseline comparision (“Old”, “New”, or “Same”) allowing for IP-based ticket updating.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |solution_id| |nexpose_id| |url| |summary| |fix| |comparison|



269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
# File 'lib/nexpose_ticketing/queries.rb', line 269

def self.all_vulns_since_scan(options = {})
  "SELECT DISTINCT on (da.ip_address, subs.vulnerability_id) subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
    string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                       '|Nexpose ID: ' || ds.nexpose_id ||
                       '|Fix: ' || coalesce(proofAsText(ds.fix), 'None') ||
                       '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions, 
    subs.comparison, fa.riskscore, dv.cvss_score, 
    string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
    null as first_discovered, null as most_recently_discovered
    FROM (
      SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) = 'Old'
    ) subs
    JOIN dim_vulnerability dv USING (vulnerability_id)
    LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
    JOIN dim_vulnerability_solution dvs USING (vulnerability_id)
    JOIN dim_solution ds USING (solution_id)
    JOIN dim_asset da ON subs.asset_id = da.asset_id
    JOIN fact_asset fa ON fa.asset_id = subs.asset_id
     #{createRiskString(options[:riskScore])}
    AND subs.current_scan > #{options[:scan_id]}
    GROUP BY subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
             fa.riskscore, dv.cvss_score, subs.comparison

    UNION

    SELECT DISTINCT on (da.ip_address, subs.vulnerability_id) subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id,
    string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                       '|Nexpose ID: ' || ds.nexpose_id ||
                       '|Fix: ' || coalesce(proofAsText(ds.fix), 'None') ||
                       '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions, 
    subs.comparison, fa.riskscore, dv.cvss_score, 
    string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
    fasva.first_discovered, fasva.most_recently_discovered
    FROM 
    (
      SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id,lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) IN ('Same','New')
    ) subs
    JOIN dim_vulnerability dv USING (vulnerability_id)
    LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
    JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
    JOIN fact_asset_vulnerability_age fasva ON subs.vulnerability_id = fasva.vulnerability_id AND subs.asset_id = fasva.asset_id
    JOIN dim_solution ds USING (solution_id)
    JOIN dim_asset da ON subs.asset_id = da.asset_id
    JOIN fact_asset fa ON fa.asset_id = subs.asset_id
    #{createRiskString(options[:riskScore])}
    AND subs.current_scan > #{options[:scan_id]}
    GROUP BY subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
             fa.riskscore, dv.cvss_score, fasva.first_discovered, fasva.most_recently_discovered, subs.comparison

    ORDER BY ip_address, comparison"
end

.createAssetString(options) ⇒ Object

  • Args :

    • options - User configured options for the ticketing service.

  • Returns :

    • Returns String - Formatted SQL string for inserting into queries.



34
35
36
37
38
39
40
41
# File 'lib/nexpose_ticketing/queries.rb', line 34

def self.createAssetString(options)
  if options[:tag_run] && options[:nexpose_item]
    assetString = "WHERE asset_id = #{options[:nexpose_item]}"
  else
    assetString = ""
  end
  return assetString
end

.createRiskString(riskScore) ⇒ Object

  • Args :

    • riskScore - riskscore for assets to match in results of query.

  • Returns :

    • Returns String - Formatted SQL string for inserting into queries.



16
17
18
19
20
21
22
23
# File 'lib/nexpose_ticketing/queries.rb', line 16

def self.createRiskString(riskScore)
  if riskScore.nil?
    riskString = ""
  else
    riskString = "WHERE fa.riskscore >= #{riskScore}"
  end
  return riskString
end

.last_scansObject

Gets all the latest scans for sites. Returns |site.id| |last_scan_id| |finished|



45
46
47
48
49
# File 'lib/nexpose_ticketing/queries.rb', line 45

def self.last_scans
  'SELECT ds.site_id, ds.last_scan_id, dsc.finished
    FROM dim_site ds
    JOIN dim_scan dsc ON ds.last_scan_id = dsc.scan_id'
end

.last_tag_scansObject

Gets all the latest scans for tags. Returns |tag.id| |asset.id| |last_scan_id| |finished|



53
54
55
56
57
58
# File 'lib/nexpose_ticketing/queries.rb', line 53

def self.last_tag_scans
'select dta.tag_id, dta.asset_id, fa.last_scan_id, fa.scan_finished
  from dim_tag_asset dta
  join fact_asset fa using (asset_id)
  order by dta.tag_id, dta.asset_id, fa.last_scan_id, fa.scan_finished'
end

.new_vulns_by_vuln_id_since_scan(options = {}) ⇒ Object

Gets all new vulnerabilities happening after a reported scan id. Sorted by vuln ID.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |solution_id| |nexpose_id| |url| |summary| |fix|



191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
# File 'lib/nexpose_ticketing/queries.rb', line 191

def self.new_vulns_by_vuln_id_since_scan(options = {})
  "SELECT DISTINCT on (subs.vulnerability_id) subs.vulnerability_id, dv.title, MAX(dv.cvss_score) as cvss_score,
               string_agg(DISTINCT subs.asset_id ||
                 '|' || da.ip_address ||
                 '|' || coalesce(da.host_name, '')  ||
                 '|' || fa.riskscore, '~') as assets,
             
               string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                 '|Nexpose ID: ' || ds.nexpose_id ||
                 '|Fix: ' || coalesce(proofAsText(ds.fix)) ||
                 '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
     string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references
    FROM (SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
          FROM dim_asset #{createAssetString(options)}) s
          ON s.asset_id = fasv.asset_id AND (fasv.scan_id >=  #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
          GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
          HAVING baselineComparison(fasv.scan_id, current_scan) = 'New'
      ) subs
  JOIN dim_vulnerability dv USING (vulnerability_id)
  LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
  JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
  JOIN fact_asset_vulnerability_age fasva ON subs.vulnerability_id = fasva.vulnerability_id AND subs.asset_id = fasva.asset_id
  JOIN dim_solution ds USING (solution_id)
  JOIN dim_asset da ON subs.asset_id = da.asset_id
  AND subs.current_scan > #{options[:scan_id]}
  JOIN fact_asset fa ON fa.asset_id = da.asset_id
  #{createRiskString(options[:riskScore])}
  GROUP BY subs.vulnerability_id, dv.title
  ORDER BY vulnerability_id"
end

.new_vulns_since_scan(options = {}) ⇒ Object

Gets all new vulnerabilities happening after a reported scan id.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |solution_id| |nexpose_id| |url| |summary| |fix|



148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
# File 'lib/nexpose_ticketing/queries.rb', line 148

def self.new_vulns_since_scan(options = {})
  "SELECT DISTINCT on (da.ip_address, subs.vulnerability_id) subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
   string_agg(DISTINCT 'Summary: ' || coalesce(ds.summary, 'None') ||
                       '|Nexpose ID: ' || ds.nexpose_id ||
                       '|Fix: ' || coalesce(proofAsText(ds.fix), 'None') ||
                       '|URL: ' || coalesce(ds.url, 'None'), '~') as solutions,
   fa.riskscore, dv.cvss_score,
   string_agg(DISTINCT dvr.source || ': ' || dvr.reference, ', ') as references,
   fasva.first_discovered, fasva.most_recently_discovered
    FROM (SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
          FROM dim_asset #{createAssetString(options)}) s
          ON s.asset_id = fasv.asset_id AND (fasv.scan_id >=  #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
          GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
          HAVING baselineComparison(fasv.scan_id, current_scan) = 'New'
      ) subs
  JOIN dim_vulnerability dv USING (vulnerability_id)
  LEFT JOIN dim_vulnerability_reference dvr USING (vulnerability_id)
  JOIN dim_asset_vulnerability_solution davs USING (vulnerability_id)
  JOIN fact_asset_vulnerability_age fasva ON subs.vulnerability_id = fasva.vulnerability_id AND subs.asset_id = fasva.asset_id
  JOIN dim_solution ds USING (solution_id)
  JOIN dim_asset da ON subs.asset_id = da.asset_id
  AND subs.current_scan > #{options[:scan_id]}
  JOIN fact_asset fa ON fa.asset_id = da.asset_id
  #{createRiskString(options[:riskScore])}
  GROUP BY subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, 
             fa.riskscore, dv.cvss_score, fasva.first_discovered, fasva.most_recently_discovered
  ORDER BY da.ip_address, subs.vulnerability_id"
end

.old_tickets_by_ip(options = {}) ⇒ Object

Gets all IP addresses that have only old vulnerabilities i.e. any open tickets can be closed.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |comparison|



427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
# File 'lib/nexpose_ticketing/queries.rb', line 427

def self.old_tickets_by_ip(options = {})
  "SELECT DISTINCT on(subs.ip_address) subs.asset_id, subs.ip_address, subs.current_scan, subs.vulnerability_id, subs.comparison
    FROM (
      SELECT fasv.asset_id,  s.ip_address, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN (
        SELECT asset_id, ip_address, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.ip_address, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) = 'Old'
    ) AS subs
    WHERE subs.ip_address NOT IN (

      SELECT s.ip_address
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT asset_id, ip_address, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY s.ip_address, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) IN ('Same','New')
    )
    AND subs.current_scan > #{options[:scan_id]}
    ORDER BY subs.ip_address"
end

.old_tickets_by_vuln_id(options = {}) ⇒ Object

Gets all old vulns that have no active IPs i.e. any open tickets in vuln mode (‘V’) can be closed.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |comparison|



464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
# File 'lib/nexpose_ticketing/queries.rb', line 464

def self.old_tickets_by_vuln_id(options = {})
  "SELECT subs.vulnerability_id, subs.asset_id, subs.ip_address, subs.current_scan, subs.comparison
    FROM (
      SELECT fasv.asset_id,  s.ip_address, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison, fa.riskscore
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN (
        SELECT asset_id, ip_address, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
  	  JOIN fact_asset fa ON fa.asset_id = fasv.asset_id
  	  #{createRiskString(options[:riskScore])}
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.ip_address, s.current_scan, fa.riskscore
      HAVING baselineComparison(fasv.scan_id, current_scan) = 'Old'
    ) AS subs
    WHERE subs.vulnerability_id NOT IN (

      SELECT fasv.vulnerability_id
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN
      (
        SELECT da.asset_id, da.ip_address, lastScan(da.asset_id) AS current_scan, fa.riskscore
        FROM dim_asset da #{createAssetString(options)}
  	    JOIN fact_asset fa ON fa.asset_id = da.asset_id
  	    #{createRiskString(options[:riskScore])}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.vulnerability_id, s.ip_address, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) IN ('Same','New')

    )
    AND subs.current_scan > #{options[:scan_id]}
    ORDER BY subs.vulnerability_id"
end

.old_vulns_since_scan(options = {}) ⇒ Object

Gets all old vulnerabilities happening after a reported scan id.

  • Args :

    • reported_scan - Last reported scan id.

  • Returns :

    • Returns |asset_id| |ip_address| |current_scan| |vulnerability_id| |solution_id| |nexpose_id| |url| |summary| |fix|



236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
# File 'lib/nexpose_ticketing/queries.rb', line 236

def self.old_vulns_since_scan(options = {})
  "SELECT DISTINCT on (da.ip_address, subs.vulnerability_id) subs.asset_id, da.ip_address, da.host_name, subs.current_scan, subs.vulnerability_id, dvs.solution_id, ds.nexpose_id, ds.url, 
    proofAsText(ds.summary) as summary, proofAsText(ds.fix) as fix, subs.comparison, fa.riskscore
    FROM (
      SELECT fasv.asset_id, fasv.vulnerability_id, s.current_scan, baselineComparison(fasv.scan_id, s.current_scan) as comparison 
      FROM fact_asset_scan_vulnerability_finding fasv
      JOIN (
        SELECT asset_id, previousScan(asset_id) AS baseline_scan, lastScan(asset_id) AS current_scan
        FROM dim_asset #{createAssetString(options)}
      ) s ON s.asset_id = fasv.asset_id AND (fasv.scan_id >= #{options[:scan_id]} OR fasv.scan_id = s.current_scan)
      GROUP BY fasv.asset_id, fasv.vulnerability_id, s.current_scan
      HAVING baselineComparison(fasv.scan_id, current_scan) = 'Old'
    ) subs
    JOIN dim_vulnerability_solution dvs USING (vulnerability_id)
    JOIN dim_solution ds USING (solution_id)
    JOIN dim_asset da ON subs.asset_id = da.asset_id
    AND subs.current_scan > #{options[:scan_id]}
  	JOIN fact_asset fa ON fa.asset_id = da.asset_id
  	#{createRiskString(options[:riskScore])}
    ORDER BY da.ip_address"
end