boulder/sa/_db/migrations
Jacob Hoffman-Andrews a6597b9f12 Change pendingAuthorizations indexes for better performance. (#3775)
There are two main queries we do against pendingAuthorizations: counting pending authzs
for rate limiting, and looking up existing authorizations for reuse. Neither of these is served
perfectly by our current (regID, expires) index. The index works well in some conditions but
not others. This change adds two more specific indexes to replace the existing ones.

The below set of EXPLAINs demonstrates the new indexes in use. Note that in order to
get MariaDB to make proper use of the new index, I had to create a local account and
fill it with pending authzs using a modified chisel.py.

The `registrationID`, `status`, `expires` index is used for the case when an account creates
and then deactivates a lot of authzs, since deactivated authzs stay in the pending table
and create performance issues. Adding an index that includes status can fix those performance
issues. The last section of statements logs below, after I `UPDATE` all the pending authorizations
to be `deactivated`, demonstrates the speed difference in the count query (check the `rows` count).

```
mysql> SHOW CREATE TABLE pendingAuthorizations \G                                                                     *************************** 1. row ***************************
       Table: pendingAuthorizations
Create Table: CREATE TABLE `pendingAuthorizations` (
  `id` varchar(255) NOT NULL,
  `identifier` varchar(255) NOT NULL,
  `registrationID` bigint(20) NOT NULL,
  `status` varchar(255) NOT NULL,
  `expires` datetime DEFAULT NULL,
  `combinations` varchar(255) NOT NULL,
  `LockCol` bigint(20) NOT NULL,
  PRIMARY KEY (`id`),
  KEY `regId_expires_idx` (`registrationID`,`expires`),
  CONSTRAINT `regId_pending_authz` FOREIGN KEY (`registrationID`) REFERENCES `registrations` (`id`) ON DELETE NO ACTION ON UPDATE NO ACTION
) ENGINE=InnoDB DEFAULT CHARSET=utf8
1 row in set (0.00 sec)

mysql> EXPLAIN SELECT COUNT(*) FROM pendingAuthorizations WHERE status = 'pending' AND expires > NOW() \G             *************************** 1. row ***************************                                                                   id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: ALL
possible_keys: NULL
          key: NULL
      key_len: NULL
          ref: NULL
         rows: 270
        Extra: Using where
1 row in set (0.01 sec)

mysql> EXPLAIN SELECT COUNT(*) FROM pendingAuthorizations WHERE registrationID = 2003 AND status = 'pending' AND expires > NOW() \G
*************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: ref
possible_keys: regId_expires_idx
          key: regId_expires_idx
      key_len: 8
          ref: const
         rows: 150
        Extra: Using index condition; Using where
1 row in set (0.00 sec)

mysql> EXPLAIN SELECT id, identifier, registrationID, status, expires, combinations, LockCol FROM pendingAuthorizations WHERE registrationID = 2003 AND identifier = '{\"type\":\"dns\",\"value\":\"23.com\"}' AND status = 'pending' AND expires > NOW() ORDER BY expires ASC LIMIT 1 \G                                                                         *************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: ref
possible_keys: regId_expires_idx
          key: regId_expires_idx
      key_len: 8
          ref: const
         rows: 150
        Extra: Using index condition; Using where
1 row in set (0.00 sec)

mysql>
mysql> ALTER TABLE `pendingAuthorizations`
    ->   ADD INDEX `identifier_registrationID_status_expires_idx` (
    ->     `identifier`, `registrationID`, `status`, `expires`),
    ->   ADD INDEX `registrationID_status_expires_idx` (
    ->     `registrationID`, `status`, `expires`),
    ->   DROP INDEX `regId_expires_idx`;
Query OK, 0 rows affected (0.05 sec)
Records: 0  Duplicates: 0  Warnings: 0

mysql> EXPLAIN SELECT COUNT(*) FROM pendingAuthorizations WHERE registrationID = 2003 AND status = 'pending' AND expires > NOW() \G                                                                                                         *************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: range
possible_keys: registrationID_status_expires_idx
          key: registrationID_status_expires_idx
      key_len: 781
          ref: NULL
         rows: 150
        Extra: Using where; Using index
1 row in set (0.00 sec)

mysql> EXPLAIN SELECT id, identifier, registrationID, status, expires, combinations, LockCol FROM pendingAuthorizations WHERE registrationID = 2003 AND identifier = '{\"type\":\"dns\",\"value\":\"23.com\"}' AND status = 'pending' AND expires > NOW() ORDER BY expires ASC LIMIT 1 \G
*************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: range
possible_keys: identifier_registrationID_status_expires_idx,registrationID_status_expires_idx
          key: identifier_registrationID_status_expires_idx
      key_len: 1548
          ref: NULL
         rows: 1
        Extra: Using index condition
1 row in set (0.00 sec)

mysql> UPDATE pendingAuthorizations SET status = 'deactivated' WHERE registrationID = 2003;
Query OK, 150 rows affected (0.02 sec)
Rows matched: 150  Changed: 150  Warnings: 0

mysql> EXPLAIN SELECT COUNT(*) FROM pendingAuthorizations WHERE registrationID = 2003 AND status = 'pending' AND expires > NOW() \G                                                                                                         *************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: range
possible_keys: registrationID_status_expires_idx
          key: registrationID_status_expires_idx
      key_len: 781
          ref: NULL
         rows: 1
        Extra: Using where; Using index
1 row in set (0.01 sec)

mysql> 
mysql> ALTER TABLE `pendingAuthorizations`
    ->   DROP INDEX `identifier_registrationID_status_expires_idx`,
    ->   DROP INDEX `registrationID_status_expires_idx`,
    ->   ADD INDEX `regId_expires_idx` (`registrationID`,`expires`);
Query OK, 0 rows affected (0.04 sec)
Records: 0  Duplicates: 0  Warnings: 0

mysql> EXPLAIN SELECT COUNT(*) FROM pendingAuthorizations WHERE registrationID = 2003 AND status = 'pending' AND expires > NOW() \G
*************************** 1. row ***************************
           id: 1
  select_type: SIMPLE
        table: pendingAuthorizations
         type: ref
possible_keys: regId_expires_idx
          key: regId_expires_idx
      key_len: 8
          ref: const
         rows: 150
        Extra: Using index condition; Using where
1 row in set (0.00 sec)
```
2018-06-26 10:49:20 -07:00
..
20150818171317_InitialSchema.sql add forgotten drop of challenges table 2015-08-27 21:22:59 -07:00
20150826211856_AddChallengeAccountKey.sql Add account key to storage model and DB 2015-08-26 21:36:28 -04:00
20150827160921_AddAuthIDIndexToChallenges.sql add authenticationID index on challenges 2015-08-28 19:03:46 -07:00
20150827201311_DeleteSequenceFromAuthz.sql remove unused sequence from authz table 2015-08-27 21:21:47 -07:00
20150828005159_RegistrationsNotNullManyFields.sql disallow all null values in registrations table 2015-08-28 00:58:24 -07:00
20150828155940_AuthzNotNullManyFields.sql disallow all null values in authz table 2015-08-28 18:50:32 -07:00
20150828161056_DropStatusColumnOnCertificate.sql drop unused status column from certificates 2015-09-01 15:53:27 -07:00
20150828163255_RemoveChallengeURI.sql Make challenge URI a display-time property. 2015-09-09 16:23:45 -04:00
20150904105711_CertificateNotNullManyFields.sql disallow all null values in certificates table 2015-09-04 11:14:31 -07:00
20150904120119_AuthzExpiresMayBeNull.sql allow NULL expires in authz on validation failure 2015-09-04 12:14:24 -07:00
20150904121736_CertificateStatusNotNullManyFields.sql disallow null values in certificateStatus table 2015-09-04 12:24:48 -07:00
20150904132303_OCSPResponsesNotNullManyFields.sql disallow some null values in ocspResponses table 2015-09-04 13:25:26 -07:00
20150904143114_PendingAuthzNotNullManyFields.sql disallow some null values in pending_authz table 2015-09-04 14:36:57 -07:00
20150904144656_RenamePendingAuthz.sql rename pending_authz table to pendingAuthorizations 2015-09-04 14:51:52 -07:00
20150916173200_SCTReceipts.sql Submit all issued certificates to configured CT logs 2015-09-17 18:11:05 -07:00
20150922165824_UpdateSerialNumbersOfOldCerts.sql Make UpdateSerialNumbers migration safer. 2015-09-24 09:43:16 -07:00
20150925184726_AddNamesTable.sql Rename `issued` back to `notBefore`. 2015-10-01 15:59:30 -07:00
20150929135041_AddCertificateStatusLastOCSPUpdatedIndex.sql Daemonize the OCSP updater tool so we are constantly updating OCSP responses. 2015-10-01 16:36:51 -07:00
20151002162726_CorrectDefaultUTFCharset.sql correct charset for contact column 2015-10-05 15:00:09 -07:00
20151003141825_AddKeyAuthorization.sql Address @jcjones comments 2015-10-04 23:24:06 -04:00
20151008234926_AddInitialIPAndCreatedAt.sql Add rate limiting by registration IP. 2015-10-08 15:47:08 -07:00
20151009155300_MoveOCSPResponseToCertificateStatus.sql Add index on certificateStatus.status column 2015-10-09 16:14:31 -07:00
20151015112508_ReindexPendingAuthz.sql Expand index on pending authz to include expires. 2015-10-15 11:55:31 -07:00
20151025174914_AddLatestValidAuthzIndex.sql add index for querying for the latest valid authz 2015-11-05 14:27:55 -08:00
20151221212759_DropOldAuthzRegIDIndex.sql remove old authz index on regID 2015-12-21 21:31:52 -08:00
20160202135920_AddFQDNSetTable.sql Make fqdnSets index across setHash and issued 2016-02-29 10:52:03 -08:00
20160601135920_RemoveDeniedCSRs.sql Remove UpdateOCSP and DeniedCSRs (#1866) 2016-06-02 12:36:55 -07:00
20160602142227_AddCertificatesIssuedIndex.sql Add index to certificates table's issued field (#1876) 2016-06-02 14:28:37 -07:00
20160817143417_CertStatusOptimizations.sql `certificateStatus` table optimizations (Part One) (#2177) 2016-09-30 14:52:19 -04:00
20160818140745_AddRegStatus.sql Move two migrations from `sa/_db-next/ to `sa/_db/`. (#2588) 2017-02-27 10:41:50 -08:00
20160914105917_RemoveChallengesAcctKeyAndTLS.sql Move two migrations from `sa/_db-next/ to `sa/_db/`. (#2588) 2017-02-27 10:41:50 -08:00
20170718114448_DBCleanup.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20170731115209_AddOrders.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20171006131843_FinalizeOrder.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20171015225800_AddRenewalBit.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20171107160000_AddCertificateStatusIndexes.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20171214114506_AddOrderFQDNSets.sql Move db-next migrations into db. (#3379) 2018-01-18 15:13:21 -05:00
20180124141109_DropOrderStatusField.sql Ungate config-next for wfe2 and Wildcards. 2018-03-14 13:18:37 -07:00
20180228165129_AddOrderCreatedField.sql Ungate config-next for wfe2 and Wildcards. 2018-03-14 13:18:37 -07:00
20180626003200_AddPendingAuthzIndex.sql Change pendingAuthorizations indexes for better performance. (#3775) 2018-06-26 10:49:20 -07:00