Skip to content

Commit

Permalink
Feature: Statistics changes (#749)
Browse files Browse the repository at this point in the history
Updates to statistics calculated for stig_asset_map.
More granular tallies. Pre-calculated totals for all resultIds and StatusIds for each Asset/STIG assignment; subtotal for those that have "resultEngine" data.
Includes db migration, oas changes, newman test, and API changes.
No UI changes needed for this issue.
Maintains current functionality.
Resolves: #699
  • Loading branch information
cd-rite authored Aug 29, 2022
1 parent b08d840 commit 276e87b
Show file tree
Hide file tree
Showing 6 changed files with 550 additions and 92 deletions.
8 changes: 4 additions & 4 deletions api/source/service/mysql/AssetService.js
Original file line number Diff line number Diff line change
Expand Up @@ -47,10 +47,10 @@ exports.queryAssets = async function (inProjection = [], inPredicates = {}, elev
'stigCount', COUNT(sa.benchmarkId),
'stigAssignedCount', COUNT(distinct usa.saId),
'ruleCount', SUM(cr.ruleCount),
'acceptedCount', SUM(sa.acceptedManual) + SUM(sa.acceptedAuto),
'rejectedCount', SUM(sa.rejectedManual) + SUM(sa.rejectedAuto),
'submittedCount', SUM(submittedManual) + SUM(submittedAuto),
'savedCount', SUM(savedManual) + SUM(savedAuto),
'acceptedCount', SUM(sa.accepted),
'rejectedCount', SUM(sa.rejected),
'submittedCount', SUM(sa.submitted),
'savedCount', SUM(sa.saved),
'minTs', DATE_FORMAT(LEAST(MIN(minTs), MIN(maxTs)),'%Y-%m-%dT%H:%i:%sZ'),
'maxTs', DATE_FORMAT(GREATEST(MAX(minTs), MAX(maxTs)),'%Y-%m-%dT%H:%i:%sZ')
) as "statusStats"`)
Expand Down
62 changes: 47 additions & 15 deletions api/source/service/mysql/CollectionService.js
Original file line number Diff line number Diff line change
Expand Up @@ -383,25 +383,57 @@ exports.queryStatus = async function (inPredicates = {}, userObject) {
) as rules`,
'sa.minTs',
'sa.maxTs',

`json_object(
'low', sa.lowCount,
'medium', sa.mediumCount,
'high', sa.highCount
'medium', sa.mediumCount,
'high', sa.highCount
) as findings`,

`json_object(
'saved', json_object(
'total', sa.savedManual + sa.savedAuto,
'auto', sa.savedAuto),
'total', sa.saved,
'resultEngine', sa.savedResultEngine),
'submitted', json_object(
'total', sa.submittedManual + sa.submittedAuto,
'auto', sa.submittedAuto),
'total', sa.submitted,
'resultEngine', sa.submittedResultEngine),
'rejected', json_object(
'total', sa.rejectedManual + sa.rejectedAuto,
'auto', sa.rejectedAuto),
'total', sa.rejected,
'resultEngine', sa.rejectedResultEngine),
'accepted', json_object(
'total', sa.acceptedManual + sa.acceptedAuto,
'auto', sa.acceptedAuto)
) as status`
'total', sa.accepted,
'resultEngine', sa.acceptedResultEngine)
) as status`,

`json_object(
'notchecked', json_object(
'total', sa.notchecked ,
'resultEngine', sa.notcheckedResultEngine),
'notapplicable', json_object(
'total', sa.notapplicable ,
'resultEngine', sa.notapplicableResultEngine),
'pass', json_object(
'total', sa.pass,
'resultEngine', sa.passResultEngine),
'fail', json_object(
'total', sa.fail,
'resultEngine', sa.failResultEngine),
'unknown', json_object(
'total', sa.unknown,
'resultEngine', sa.unknownResultEngine),
'error', json_object(
'total', sa.error ,
'resultEngine', sa.errorResultEngine),
'notselected', json_object(
'total', sa.notselected,
'resultEngine', sa.notselectedResultEngine),
'informational', json_object(
'total', sa.informational,
'resultEngine', sa.informationalResultEngine),
'fixed', json_object(
'total', sa.fixed ,
'resultEngine', sa.fixedResultEngine)
) as result`
]
let joins = [
'collection c',
Expand Down Expand Up @@ -856,10 +888,10 @@ exports.getStigsByCollection = async function( collectionId, labelIds, elevate,
'st.title',
'cr.ruleCount',
'COUNT(a.assetId) as assetCount',
'CAST(SUM(sa.acceptedManual) + SUM(sa.acceptedAuto) AS SIGNED) as acceptedCount',
'CAST(SUM(sa.rejectedManual) + SUM(sa.rejectedAuto) AS SIGNED) as rejectedCount',
'CAST(SUM(sa.submittedManual) + SUM(sa.submittedAuto) AS SIGNED) as submittedCount',
'CAST(SUM(sa.savedManual) + SUM(sa.savedAuto) AS SIGNED) as savedCount',
'SUM(sa.accepted) as acceptedCount',
'SUM(sa.rejected) as rejectedCount',
'SUM(sa.submitted) as submittedCount',
'SUM(sa.saved) as savedCount',
`LEAST(MIN(minTs), MIN(maxTs)) as minTs`,
`GREATEST(MAX(minTs), MAX(maxTs)) as maxTs`
]
Expand Down
166 changes: 166 additions & 0 deletions api/source/service/mysql/migrations/0016.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,166 @@
const MigrationHandler = require('./lib/MigrationHandler')

const upMigration = [
`
ALTER TABLE stig_asset_map
RENAME COLUMN savedManual TO saved,
RENAME COLUMN savedAuto TO savedResultEngine,
RENAME COLUMN submittedManual TO submitted,
RENAME COLUMN submittedAuto TO submittedResultEngine,
RENAME COLUMN rejectedManual to rejected,
RENAME COLUMN rejectedAuto TO rejectedResultEngine,
RENAME COLUMN acceptedManual TO accepted,
RENAME COLUMN acceptedAuto TO acceptedResultEngine,
ADD COLUMN notchecked int,
ADD COLUMN notcheckedResultEngine int,
ADD COLUMN notapplicable int,
ADD COLUMN notapplicableResultEngine int,
ADD COLUMN pass int,
ADD COLUMN passResultEngine int,
ADD COLUMN fail int,
ADD COLUMN failResultEngine int,
ADD COLUMN unknown int,
ADD COLUMN unknownResultEngine int,
ADD COLUMN error int,
ADD COLUMN errorResultEngine int,
ADD COLUMN notselected int,
ADD COLUMN notselectedResultEngine int,
ADD COLUMN informational int,
ADD COLUMN informationalResultEngine int,
ADD COLUMN fixed int,
ADD COLUMN fixedResultEngine int
`,

`
with source as
( select
sa.assetId,
sa.benchmarkId,
min(review.ts) as minTs,
max(review.ts) as maxTs,
sum(CASE WHEN review.statusId = 0 THEN 1 ELSE 0 END) as saved,
sum(CASE WHEN review.resultEngine is not null and review.statusId = 0 THEN 1 ELSE 0 END) as savedResultEngine,
sum(CASE WHEN review.statusId = 1 THEN 1 ELSE 0 END) as submitted,
sum(CASE WHEN review.resultEngine is not null and review.statusId = 1 THEN 1 ELSE 0 END) as submittedResultEngine,
sum(CASE WHEN review.statusId = 2 THEN 1 ELSE 0 END) as rejected,
sum(CASE WHEN review.resultEngine is not null and review.statusId = 2 THEN 1 ELSE 0 END) as rejectedResultEngine,
sum(CASE WHEN review.statusId = 3 THEN 1 ELSE 0 END) as accepted,
sum(CASE WHEN review.resultEngine is not null and review.statusId = 3 THEN 1 ELSE 0 END) as acceptedResultEngine,
sum(CASE WHEN review.resultId=4 and r.severity='high' THEN 1 ELSE 0 END) as highCount,
sum(CASE WHEN review.resultId=4 and r.severity='medium' THEN 1 ELSE 0 END) as mediumCount,
sum(CASE WHEN review.resultId=4 and r.severity='low' THEN 1 ELSE 0 END) as lowCount,
sum(CASE WHEN review.resultId = 1 THEN 1 ELSE 0 END) as notchecked,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 1 THEN 1 ELSE 0 END) as notcheckedResultEngine,
sum(CASE WHEN review.resultId = 2 THEN 1 ELSE 0 END) as notapplicable,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 2 THEN 1 ELSE 0 END) as notapplicableResultEngine,
sum(CASE WHEN review.resultId = 3 THEN 1 ELSE 0 END) as pass,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 3 THEN 1 ELSE 0 END) as passResultEngine,
sum(CASE WHEN review.resultId = 4 THEN 1 ELSE 0 END) as fail,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 4 THEN 1 ELSE 0 END) as failResultEngine,
sum(CASE WHEN review.resultId = 5 THEN 1 ELSE 0 END) as unknown,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 5 THEN 1 ELSE 0 END) as unknownResultEngine,
sum(CASE WHEN review.resultId = 6 THEN 1 ELSE 0 END) as error,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 6 THEN 1 ELSE 0 END) as errorResultEngine,
sum(CASE WHEN review.resultId = 7 THEN 1 ELSE 0 END) as notselected,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 7 THEN 1 ELSE 0 END) as notselectedResultEngine,
sum(CASE WHEN review.resultId = 8 THEN 1 ELSE 0 END) as informational,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 8 THEN 1 ELSE 0 END) as informationalResultEngine,
sum(CASE WHEN review.resultId = 9 THEN 1 ELSE 0 END) as fixed,
sum(CASE WHEN review.resultEngine is not null and review.resultId = 9 THEN 1 ELSE 0 END) as fixedResultEngine
from
asset a
left join stig_asset_map sa using (assetId)
left join current_group_rule cgr using (benchmarkId)
left join rule r using (ruleId)
left join review on (r.ruleId=review.ruleId and review.assetId=sa.assetId)
group by
sa.assetId,
sa.benchmarkId
)
update stig_asset_map sam
inner join source on sam.assetId = source.assetId and source.benchmarkId = sam.benchmarkId
set sam.minTs = source.minTs,
sam.maxTs = source.maxTs,
sam.saved = source.saved,
sam.savedResultEngine = source.savedResultEngine,
sam.submitted = source.submitted,
sam.submittedResultEngine = source.submittedResultEngine,
sam.rejected = source.rejected,
sam.rejectedResultEngine = source.rejectedResultEngine,
sam.accepted = source.accepted,
sam.acceptedResultEngine = source.acceptedResultEngine,
sam.highCount = source.highCount,
sam.mediumCount = source.mediumCount,
sam.lowCount = source.lowCount,
sam.notchecked = source.notchecked,
sam.notcheckedResultEngine = source.notcheckedResultEngine,
sam.notapplicable = source.notapplicable,
sam.notapplicableResultEngine = source.notapplicableResultEngine,
sam.pass = source.pass,
sam.passResultEngine = source.passResultEngine,
sam.fail = source.fail,
sam.failResultEngine = source.failResultEngine,
sam.unknown = source.unknown,
sam.unknownResultEngine = source.unknownResultEngine,
sam.error = source.error,
sam.errorResultEngine = source.errorResultEngine,
sam.notselected = source.notselected,
sam.notselectedResultEngine = source.notselectedResultEngine,
sam.informational = source.informational,
sam.informationalResultEngine = source.informationalResultEngine,
sam.fixed = source.fixed,
sam.fixedResultEngine = source.fixedResultEngine
`

]



const downMigration = [
`
ALTER TABLE stig_asset_map
RENAME COLUMN saved TO savedManual,
RENAME COLUMN savedResultEngine TO savedAuto,
RENAME COLUMN submitted TO submittedManual,
RENAME COLUMN submittedResultEngine TO submittedAuto,
RENAME COLUMN rejected to rejectedManual,
RENAME COLUMN rejectedResultEngine TO rejectedAuto,
RENAME COLUMN accepted TO acceptedManual,
RENAME COLUMN acceptedResultEngine TO acceptedAuto,
DROP COLUMN notchecked ,
DROP COLUMN notcheckedResultEngine ,
DROP COLUMN notapplicable ,
DROP COLUMN notapplicableResultEngine ,
DROP COLUMN pass ,
DROP COLUMN passResultEngine ,
DROP COLUMN fail ,
DROP COLUMN failResultEngine ,
DROP COLUMN unknown ,
DROP COLUMN unknownResultEngine ,
DROP COLUMN error ,
DROP COLUMN errorResultEngine ,
DROP COLUMN notselected ,
DROP COLUMN notselectedResultEngine ,
DROP COLUMN informational ,
DROP COLUMN informationalResultEngine ,
DROP COLUMN fixed ,
DROP COLUMN fixedResultEngine
`

]

const migrationHandler = new MigrationHandler(upMigration, downMigration)
module.exports = {
up: async (pool) => {
await migrationHandler.up(pool, __filename)
},
down: async (pool) => {
await migrationHandler.down(pool, __filename)
}
}
Loading

0 comments on commit 276e87b

Please sign in to comment.