Skip to content

datastore: gc enrichments #1528

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Open
wants to merge 1 commit into
base: main
Choose a base branch
from
Open

datastore: gc enrichments #1528

wants to merge 1 commit into from

Conversation

RTann
Copy link
Contributor

@RTann RTann commented Apr 24, 2025

I have StackRox installed using Scanner V4, which is based on Claircore. Here's the EXPLAIN ANALYZE for the deletion queries:

# EXPLAIN ANALYZE DELETE FROM vuln v1 USING
vuln v2
LEFT JOIN uo_vuln uvl
ON v2.id = uvl.vuln
WHERE uvl.vuln IS NULL
AND v2.updater = 'rhel-vex'
AND v1.id = v2.id;
                                                                      QUERY PLAN                                                                       
-------------------------------------------------------------------------------------------------------------------------------------------------------
 Delete on vuln v1  (cost=1068367.20..1887805.36 rows=0 width=0) (actual time=18785.634..18785.638 rows=0 loops=1)
   ->  Hash Join  (cost=1068367.20..1887805.36 rows=407282 width=18) (actual time=18785.631..18785.635 rows=0 loops=1)
         Hash Cond: (v1.id = v2.id)
         ->  Seq Scan on vuln v1  (cost=0.00..795983.61 rows=5168461 width=14) (actual time=0.035..0.036 rows=1 loops=1)
         ->  Hash  (cost=1063276.18..1063276.18 rows=407282 width=20) (actual time=18784.195..18784.198 rows=0 loops=1)
               Buckets: 524288  Batches: 1  Memory Usage: 4096kB
               ->  Hash Anti Join  (cost=200433.67..1063276.18 rows=407282 width=20) (actual time=18784.194..18784.196 rows=0 loops=1)
                     Hash Cond: (v2.id = uvl.vuln)
                     ->  Seq Scan on vuln v2  (cost=0.00..808904.76 rows=1395657 width=14) (actual time=535.456..13101.478 rows=1387909 loops=1)
                           Filter: (updater = 'rhel-vex'::text)
                           Rows Removed by Filter: 3771885
                     ->  Hash  (cost=101633.63..101633.63 rows=5683763 width=14) (actual time=1862.736..1862.737 rows=6723341 loops=1)
                           Buckets: 1048576  Batches: 16  Memory Usage: 27863kB
                           ->  Seq Scan on uo_vuln uvl  (cost=0.00..101633.63 rows=5683763 width=14) (actual time=0.055..721.353 rows=6723341 loops=1)
 Planning Time: 2.595 ms
 Execution Time: 18785.752 ms
(16 rows)

# EXPLAIN ANALYZE DELETE FROM enrichment e1 USING
enrichment e2
LEFT JOIN uo_enrich uen
ON e2.id = uen.enrich
WHERE uen.enrich IS NULL
AND e2.updater = 'nvd'
AND e1.id = e2.id;
                                                                  QUERY PLAN                                                                   
-----------------------------------------------------------------------------------------------------------------------------------------------
 Delete on enrichment e1  (cost=24746.16..88408.00 rows=0 width=0) (actual time=1076.427..1076.434 rows=0 loops=1)
   ->  Nested Loop  (cost=24746.16..88408.00 rows=19071 width=18) (actual time=1076.423..1076.430 rows=0 loops=1)
         ->  Hash Anti Join  (cost=24745.74..68030.52 rows=19071 width=20) (actual time=1076.421..1076.427 rows=0 loops=1)
               Hash Cond: (e2.id = uen.enrich)
               ->  Seq Scan on enrichment e2  (cost=0.00..36912.85 rows=204714 width=14) (actual time=0.962..640.351 rows=196623 loops=1)
                     Filter: (updater = 'nvd'::text)
                     Rows Removed by Filter: 291609
               ->  Hash  (cost=12517.55..12517.55 rows=703455 width=14) (actual time=274.576..274.578 rows=700355 loops=1)
                     Buckets: 1048576  Batches: 2  Memory Usage: 24600kB
                     ->  Seq Scan on uo_enrich uen  (cost=0.00..12517.55 rows=703455 width=14) (actual time=0.018..89.865 rows=700355 loops=1)
         ->  Index Scan using enrichment_pkey on enrichment e1  (cost=0.42..1.07 rows=1 width=14) (never executed)
               Index Cond: (id = e2.id)
 Planning Time: 0.452 ms
 Execution Time: 1079.150 ms
(14 rows)

Tested on a local installation with nothing else running, and it took 6 - 8 minutes (sorry I forget). I had someone run this in an active cluster, and it took 7 minutes. All of these were on SSD. I ran it again on an inactive installation (ie one with no other activity happening) and it took 50 minutes on HDD.

@RTann RTann force-pushed the gc-enrichments branch 3 times, most recently from 6be4a42 to cdaae49 Compare May 9, 2025 17:26
@RTann RTann force-pushed the gc-enrichments branch from cdaae49 to 2281b3d Compare May 15, 2025 23:05
@RTann RTann force-pushed the gc-enrichments branch from 2281b3d to b44c560 Compare May 23, 2025 00:13
@RTann RTann marked this pull request as ready for review May 23, 2025 00:13
@RTann RTann requested a review from a team as a code owner May 23, 2025 00:13
@RTann RTann requested review from crozzy and hdonnay and removed request for a team May 23, 2025 00:13
@RTann RTann requested a review from crozzy May 29, 2025 00:22
crozzy
crozzy previously approved these changes May 29, 2025
@RTann
Copy link
Contributor Author

RTann commented May 31, 2025

@crozzy thanks for the approval. I want to do one more test prior to merge:

Deploy an older database with >25 million rows in the enrichment table, hit Indexer/Matcher with a bunch of scan requests, and then update to a version with the changes from this PR so I can see how long it takes to delete everything while under load. If that goes well, I'll merge

@RTann
Copy link
Contributor Author

RTann commented Jun 3, 2025

@crozzy I ran a test where I installed StackRox Scanner V4 DB with CPU limit of 2 and memory limit of 4GiB. I then gave it almost 2000 images to scan (15 at a time), and I found that the deletion took 1 hour and 24 minutes. That is a very long time, though no failures was nice, and I did put a lot of load on the DB. This also made the table go from

# SELECT updater, COUNT(*) FROM enrichment GROUP BY updater;
      updater       |  count   
--------------------+----------
 clair.epss         | 25722723
 nvd                |  1327981
 stackrox.rhel-csaf |    16034
(3 rows)

to

# SELECT updater, COUNT(*) FROM enrichment GROUP BY updater;
      updater       | count  
--------------------+--------
 clair.epss         | 561597
 nvd                | 201570
 stackrox.rhel-csaf |  15910
(3 rows)

I also realized vuln has another index:

"vuln_updater_idx" btree (updater)

I believe this may also help the deletion query, as one of the conditions looks for matching updater. I'm going to add this index to enrichment and retest it

Signed-off-by: RTann <[email protected]>

rh-pre-commit.version: 2.3.2
rh-pre-commit.check-secrets: ENABLED
@RTann RTann force-pushed the gc-enrichments branch from 0465e61 to 4730f6d Compare June 3, 2025 06:27
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Development

Successfully merging this pull request may close these issues.

None yet

2 participants