BLACKHOLE
The BLACKHOLE
storage engine accepts data but does not store it and always returns an empty result.
A table using the BLACKHOLE
storage engine consists of a single .frm table format file, but no associated data or index files.
This storage engine can be useful, for example, if you want to run complex filtering rules on a slave without incurring any overhead on a master. The master can run a BLACKHOLE
storage engine, with the data replicated to the slave for processing.
Contents
Installing the Plugin
Although the plugin's shared library is distributed with MariaDB by default, the plugin is not actually installed by MariaDB by default. There are two methods that can be used to install the plugin with MariaDB.
The first method can be used to install the plugin without restarting the server. You can install the plugin dynamically by executing INSTALL SONAME or INSTALL PLUGIN. For example:
INSTALL SONAME 'ha_blackhole';
The second method can be used to tell the server to load the plugin when it starts up. The plugin can be installed this way by providing the --plugin-load or the --plugin-load-add options. This can be specified as a command-line argument to mysqld or it can be specified in a relevant server option group in an option file. For example:
[mariadb] ... plugin_load_add = ha_blackhole
Uninstalling the Plugin
You can uninstall the plugin dynamically by executing UNINSTALL SONAME or UNINSTALL PLUGIN. For example:
UNINSTALL SONAME 'ha_blackhole';
If you installed the plugin by providing the --plugin-load or the --plugin-load-add options in a relevant server option group in an option file, then those options should be removed to prevent the plugin from being loaded the next time the server is restarted.
Using the BLACKHOLE Storage Engine
Using with DML
INSERT, UPDATE, and DELETE statements all work with the BLACKHOLE
storage engine. However, no data changes are actually applied.
Using with Replication
If the binary log is enabled, all SQL statements will be logged as usual, and replicated to any slave servers. However, since rows are not stored, it is important to use statement-based rather than the row or mixed format, as UPDATE and DELETE statements are neither logged nor replicated. See Binary Log Formats.
Using with Triggers
Some triggers work with the BLACKHOLE
storage engine.
BEFORE
triggers for INSERT statements are still activated.
Triggers for UPDATE and DELETE statements are not activated.
Triggers with the FOR EACH ROW
clause do not apply, since the tables have no rows.
Using with Foreign Keys
Foreign keys are not supported. If you convert an InnoDB table to BLACKHOLE
, then the foreign keys will disappear. If you convert the same table back to InnoDB, then you will have to recreate them.
Using with Virtual Columns
If you convert an InnoDB table which contains virtual columns to BLACKHOLE
, then it produces an error.
Using with AUTO_INCREMENT
Because a BLACKHOLE table does not store data, it will not maintain the AUTO_INCREMENT value. If you are replicating to a table that can handle AUTO_INCREMENT
columns, and are not explicitly setting the primary key auto-increment value in the INSERT query, or using the SET INSERT_ID statement, inserts will fail on the slave due to duplicate keys.
Limits
The maximum key size is:
- 3500 bytes (>= MariaDB 10.1.48, MariaDB 10.2.35, MariaDB 10.3.26, MariaDB 10.4.16 and MariaDB 10.5.7)
- 1000 bytes (<= MariaDB 10.1.47, MariaDB 10.2.34, MariaDB 10.3.25, MariaDB 10.4.15 and MariaDB 10.5.6).
Examples
CREATE TABLE table_name ( id int unsigned primary key not null, v varchar(30) ) ENGINE=BLACKHOLE; insert into table_name values (1, 'bob'),(2, 'jane'); Query OK, 2 rows affected (0.001 sec) Records: 2 Duplicates: 0 Warnings: 0 select * from table_name; Empty set (0.001 sec)