Cleaning up your WooCommerce database

Glasses sitting in front of computer screens displaying code

There’s lots you can do to improve database (DB) performance, but each change comes with risks. Always thoroughly test changes in a development environment first before making permanent database changes in production.

Growth in data requires a growth in hosting to handle the scale of database size and queries.

There’s only so much you can clean-up practically. When you reach this point, hosting with solid managed hosting like Pantheon.io or custom cloud infrastructure like AWS can offer a great deal of scale, costing on the magnitude of $5k/mo in huge DB servers if it becomes too important to have all the historic data while keeping things fast. Those costs are out of reach for most of us, so minding your DB health is critical as you grow so you don’t have to spend huge on hosting before it’s truly necessary to do so.

There may even come a point where it makes sense to shard the data (i.e. move historic quarters or years data over to backup environments for archival usage).

The best solution will depend on each client’s unique needs.

Here’s my practical tips in this area:

1) Ensure you’re using InnoDB tables.

To generate update queries:

SELECT CONCAT( 'ALTER TABLE ', TABLE_NAME, ' ENGINE=InnoDB;' ) 
FROM INFORMATION_SCHEMA.TABLES
WHERE ENGINE = 'MyISAM'
AND table_schema = 'database-name-here';

2) Use WP Optimize plugin.

This can clear out orphaned records, old drafts, etc.

3) Use my Prune Orders plugin.

This can trash all old failed, pending, cancelled orders by selected status to a specified date. If you’re working faster or prefer to use SQL here’s a useful query to select then pivot to a deletion query.

SELECT * FROM wp_posts
WHERE post_type = 'shop_order'
AND post_status IN( 'wc-cancelled', 'wc-completed', 'wc-failed', 'wc-pending' )
AND post_date < CURDATE() - INTERVAL 100 DAY
ORDER BY ID DESC;

4) Delete legacy post types, post meta, and user meta data.

For example: old order metadata, Google analytics meta, address fields, etc. To see these in order of size:

SELECT post_type, count( post_type )
FROM wp_posts
GROUP BY post_type
ORDER BY count( post_type ) DESC
LIMIT 50;

SELECT meta_key, count( meta_key )
FROM wp_postmeta
GROUP BY `meta_key`
ORDER BY count( meta_key ) DESC
LIMIT 50;

SELECT meta_key, length( meta_value )
FROM wp_postmeta
ORDER BY length( meta_value ) DESC
LIMIT 50;

SELECT meta_key, count( meta_key )
FROM wp_usermeta
GROUP BY meta_key
ORDER BY count( meta_key ) DESC
LIMIT 50;

5) Examine wp_options table health.

Remove old plugin cruft. To see how many MB are loading with each page request from wp_options run this to see which rows are hogging up the most space and decide which can be removed:

SELECT
	'Autoload KB' as name, ROUND( SUM( LENGTH( option_value ) ) / 1024 ) as size, null as autoload
	FROM wp_options
	WHERE autoload = 'yes'
UNION
	SELECT 'Autoload count', count( * ), null as autoload
	FROM wp_options
	WHERE autoload = 'yes'
UNION (
	SELECT option_name, length( option_value ), autoload
	FROM wp_options
	WHERE autoload = 'yes'
	ORDER BY length( option_value ) DESC
	LIMIT 20
)
UNION (
	SELECT option_name, length( option_value ), autoload
	FROM wp_options
	WHERE autoload = 'no'
	ORDER BY length( option_value ) DESC
	LIMIT 20
);

6) Run through Query Monitor plugin or New Relic APM.

Use available application performance monitoring tools to analyze your staging or production environments. The best screens to test are listing and editing orders as well as all front-end pages.