Skip to content

Conversation

@beautifulentropy
Copy link
Member

Add a composite index on the paused table to speed up CheckIdentifiersPaused() and GetPausedIdentifiers(). Use (registrationID, unpausedAt, identifierType, identifierValue) so the planner can apply an index condition on registrationID and unpausedAt IS NULL and return identifierType and identifierValue from the same covering index. For a table with a few hundred thousand rows, the size of this new index is projected to be ~50 MB.

Note

I am not a DBA; the following change is based on my best understanding of how the query planner is behaving. It is intended to address queries observed in CI runs with log_queries_not_using_indexes enabled. I cannot guarantee that this change is strictly optimal but I have provided some rationale, the relevant EXPLAINS, and directions for reproducing these results yourself. I would greatly appreciate feedback from someone with deeper database expertise.

I have injected fake data on the order of 100s of 1000s of rows, with pretty poor cardinality. This means that the provided results may not be reflective of how the query planner will behave on a larger machine with a larger and more varied dataset.

docker compose exec -it bmysql mysql -uroot
use boulder_sa_integration;

Add 300,000 rows to the paused table for testing purposes:

SET max_recursive_iterations = 1000000;

INSERT INTO paused (registrationID, identifierType, identifierValue, pausedAt, unpausedAt)
WITH RECURSIVE seq(n) AS (
  SELECT 0
  UNION ALL
  SELECT n+1 FROM seq WHERE n < 299999
)
SELECT
  CASE WHEN n < 200000 THEN 12345 ELSE 20000 + (n % 1000) END AS registrationID,
  (n % 2) AS identifierType,
  CONCAT('foo-', n, '.bar') AS identifierValue,
  NOW() - INTERVAL (n % 86400) SECOND AS pausedAt,
  CASE
    WHEN n < 200000 AND (n % 20) = 0 THEN NULL
    ELSE NOW() - INTERVAL (n % 86400) SECOND
  END AS unpausedAt
FROM seq;

Run an EXPLAIN on our query before adding the index:

EXPLAIN FORMAT=JSON
SELECT identifierType, identifierValue
FROM paused
WHERE registrationID = 12345
  AND unpausedAt IS NULL
LIMIT 15;
{
  "query_block": {
    "select_id": 1,
    "nested_loop": [
      {
        "table": {
          "table_name": "paused",
          "access_type": "ref",
          "possible_keys": ["PRIMARY"],
          "key": "PRIMARY",
          "key_length": "8",
          "used_key_parts": ["registrationID"],
          "ref": ["const"],
          "rows": 144626,
          "filtered": 100,
          "attached_condition": "paused.unpausedAt is null"
        }
      }
    ]
  }
}

Add the new composite index:

ALTER TABLE paused
  ADD INDEX paused_regID_unpausedAt_identifierType_identifierValue_idx
    (registrationID, unpausedAt, identifierType, identifierValue);

Running a new EXPLAIN shows the query using the new index:

{
  "query_block": {
    "select_id": 1,
    "nested_loop": [
      {
        "table": {
          "table_name": "paused",
          "access_type": "ref",
          "possible_keys": [
            "PRIMARY",
            "paused_regID_unpausedAt_identifierType_identifierValue_idx"
          ],
          "key": "paused_regID_unpausedAt_identifierType_identifierValue_idx",
          "key_length": "14",
          "used_key_parts": ["registrationID", "unpausedAt"],
          "ref": ["const", "const"],
          "rows": 20688,
          "filtered": 100,
          "attached_condition": "paused.unpausedAt is null",
          "using_index": true
        }
      }
    ]
  }
}

@beautifulentropy beautifulentropy marked this pull request as ready for review October 22, 2025 21:04
@beautifulentropy beautifulentropy requested a review from a team as a code owner October 22, 2025 21:04
@github-actions
Copy link
Contributor

@beautifulentropy, this PR appears to contain configuration and/or SQL schema changes. Please ensure that a corresponding deployment ticket has been filed with the new values.

@jprenken jprenken requested review from a team and jsha and removed request for a team October 22, 2025 21:32
@jsha
Copy link
Contributor

jsha commented Oct 27, 2025

The existing index is this:

  PRIMARY KEY (`registrationID`, `identifierValue`, `identifierType`)

I would expect most queries to use WHERE clauses matching this index. They also use unpausedAt, but we expect that in the typical case any given (regID, ident, identtype) tuple has a very small number of paused/unpaused events, so we don't care that the index doesn't cover unpausedAt.

Also, as a side note, if you're including a datetime in an index, usually it should be the last item, because it tends to be high cardinality and usually you are doing a <, >, or sort based on it, with all other fields known.

Looking at your repro query:

EXPLAIN FORMAT=JSON
SELECT identifierType, identifierValue
FROM paused
WHERE registrationID = 12345
  AND unpausedAt IS NULL
LIMIT 15;

This is different from the real query because it does not set any conditions on identifier. Here's an example of a more realistic query:

boulder/sa/saro.go

Lines 1125 to 1130 in ab2eb93

// SELECT identifierType, identifierValue
// FROM paused WHERE registrationID = ? AND
// unpausedAt IS NULL AND
// ((identifierType = ? AND identifierValue IN (?, ?, ?)) OR
// (identifierType = ? AND identifierValue IN (?)))
// LIMIT 15

Since that one specifies identifier type and value, it should in theory hit the index.

I suspect this is a false positive, but if it turns out we're not hitting the index in prod that's definitely something we should address.

@jsha
Copy link
Contributor

jsha commented Oct 27, 2025

BTW I thought of a simpler way to describe it: For this query, we expect that the database will fetch all rows for a given regID, identifier, and identifier type, then filter in memory on unpausedAt. We expect it to be okay to do that because the list of all rows for that tuple should always be at most one, due to the code in PauseIdentifiers that updates a row if one already exists.

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment

Labels

None yet

Projects

None yet

Development

Successfully merging this pull request may close these issues.

4 participants