WordPress wp_options table autoload micro-optimization

Photo of author
Written By Jan Reilink

Windows Server system administrator & enthusiast.

Learn how to add an index and optimize WordPress’ wp_options table for faster database results. This probably isn’t a big issue, but today I noticed a slow MySQL query coming from a WordPress database (WordPress wp_options table). This made me investigate and to optimize the WordPress wp_options table “autoload” feature. The autoload feature loads and caches all autoloaded options, if available, or all options. The default option is to autoload, and over time when the wp_options table grows, this degrades performance.

How to identify a slow WordPress query on wp_options

Even though our MySQL servers are heavily InnoDB optimized, I noticed and identified the following slow query in our log. It’s related to the WordPress wp_options table:

# Time: 140502 12:17:44 # User@Host: db-name[db-name] @ webserver.example.com [1.1.1.11] # Query_time: 3.491801 Lock_time: 0.000049 Rows_sent: 1337 Rows_examined: 33927 SET timestamp=1399025864; SELECT option_name, option_value FROM wp_options WHERE autoload = 'yes';
Code language: PHP (php)

So that is almost 3.5 seconds to examine 33927 and send 1337 rows…

The wp_options table description is as follows:

mysql> desc wp_options; +--------------+---------------------+------+-----+---------+----------------+ | Field | Type | Null | Key | Default | Extra | +--------------+---------------------+------+-----+---------+----------------+ | option_id | bigint(20) unsigned | NO | PRI | NULL | auto_increment | | option_name | varchar(64) | NO | UNI | | | | option_value | longtext | NO | | NULL | | | autoload | varchar(20) | NO | MUL | yes | | +--------------+---------------------+------+-----+---------+----------------+ 4 rows in set (0.00 sec)
Code language: PHP (php)

The only values for autoload are ‘yes‘ and ‘no‘, so why a varchar(20) field type? Oh well, that’s a whole other issue…

Examining the slow autoload query in WordPress

You can use MySQL’s EXPLAIN to examine queries and their structure. MySQL EXPLAIN is used to obtain a query execution plan (that is, an explanation of how MySQL would execute a query).

While examining the autoload-query, you’ll notice that there is no index present on the autoload column:

mysql> explain SELECT option_name, option_value FROM wp_options WHERE autoload = 'yes'; +----+-------------+------------+------+---------------+------+---------+------+-------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+------------+------+---------------+------+---------+------+-------+-------------+ | 1 | SIMPLE | wp_options | ALL | NULL | NULL | NULL | NULL | 33927 | Using where | +----+-------------+------------+------+---------------+------+---------+------+-------+-------------+ 1 row in set (0.00 sec)
Code language: PHP (php)

Again the 33927 rows.

Optimize wp_options with an autoload index

You can optimize the WordPress wp_options table simply by adding an index:

mysql> ALTER TABLE `wp_options` ADD INDEX (`autoload`); Query OK, 33927 rows affected (0.70 sec) Records: 33927 Duplicates: 0 Warnings: 0
Code language: JavaScript (javascript)

and we examine the same query again:

mysql> explain SELECT option_name, option_value FROM wp_options WHERE autoload = 'yes'; +----+-------------+------------+------+---------------+----------+---------+-------+------+-------------+ | id | select_type | table | type | possible_keys | key | key_len | ref | rows | Extra | +----+-------------+------------+------+---------------+----------+---------+-------+------+-------------+ | 1 | SIMPLE | wp_options | ref | autoload | autoload | 62 | const | 1508 | Using where | +----+-------------+------------+------+---------------+----------+---------+-------+------+-------------+ 1 row in set (0.00 sec)
Code language: JavaScript (javascript)

Now there are only 1508 rows left!

It’s important to optimize MySQL with indices, and how to improve InnoDB performance in MySQL.

On Make WordPress Core Trac, multiple tickets exist requesting this index to be added in WordPress Core:

Update 2019-10-15: the wp_options.autoload index is finally added to WordPress Core. Thanks!


Did you like: WordPress wp_options table autoload micro-optimization

Then please, take a second to support Sysadmins of the North and donate!

Your generosity helps pay for the ongoing costs associated with running this website like coffee, hosting services, library mirrors, domain renewals, time for article research, and coffee, just to name a few.



4 thoughts on “WordPress wp_options table autoload micro-optimization”

  1. I got this query repeating itself in mysql-slow.log and I cannot figure out what it is (cannot find much on it on the web either):
    UPDATE `wp_options` SET `option_value` = ‘150’ WHERE `option_name` = ‘thumbnail_size_w’;
    # Query_time: 10.893515 Lock_time: 0.000031 Rows_sent: 0 Rows_examined: 1

    It keeps repeating itself obscuring anything else and slowing down the mysql server.

    Any ideas on how to fix this?

    Thanks!

    Reply

Hi! Join the discussion, leave a reply!

%d bloggers like this: