boulder/sa/_db
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
..
migrations Change pendingAuthorizations indexes for better performance. (#3775) 2018-06-26 10:49:20 -07:00
dbconf.yml Docker improvements. 2016-04-04 16:05:08 -07:00