Managing Plancache Memory and Disk Usage
On this page
Compiled query plan images, sometimes referred to as 'modules' or 'code modules', are stored in a plancache for later use.
Compiled query plan images may be removed from the in-memory plancache through expiration or eviction.
Whether a plan expires or is evicted from the in-memory plancache, that plan remains in the on-disk plancache and is loaded back into memory the next time the query is run.
Query plans are not recompiled after a plan is evicted or expires from the in-memory plancache or after a node restarts.
Query plans expire from the on-disk plancache as described in Set Plan Expiration Limits.
Set Plan Expiration Limits
Plancache expiration policy can be set through the plan_
, disk_
, and enable_
engine variables.
Plans will expire from the on-disk plancache if both the enable_
is on and the time limit specified by disk_
is reached (assuming the plan has not been read from disk during that time).
Note
As engine variables are scoped at the node level (and not across the cluster), if you update any of these plan expiration variables, you must update the values across all nodes in your cluster.
The following example shows how to set these variables to change the in-memory expiration limit to eight hours and set the on-disk expiration to one week.
SHOW VARIABLES LIKE '%plan_expiration%';
+------------------------------+-------+
| Variable_name | Value |
+------------------------------+-------+
| disk_plan_expiration_minutes | 20160 |
| enable_disk_plan_expiration | OFF |
| plan_expiration_minutes | 720 |
+------------------------------+-------+
3 rows in set (0.08 sec)
SET GLOBAL plan_expiration_minutes = 480;
Query OK, 0 rows affected (0.07 sec)
SET GLOBAL disk_plan_expiration_minutes = 10080;
Query OK, 0 rows affected (0.09 sec)
SET GLOBAL enable_disk_plan_expiration = true;
Query OK, 0 rows affected (0.08 sec)
SHOW VARIABLES LIKE '%plan_expiration%';
+------------------------------+-------+
| Variable_name | Value |
+------------------------------+-------+
| disk_plan_expiration_minutes | 10080 |
| enable_disk_plan_expiration | ON |
| plan_expiration_minutes | 480 |
+------------------------------+-------+
3 rows in set (0.07 sec)
Manage Eviction of Compiled Query Plans
Compiled query plan images (sometimes referred to as 'modules' or 'code modules') are evicted using LRU (least-recently used) when the in-memory plancache reaches a set memory limit.compiled_
and compiled_
variables are used to specify the memory limit available for caching query plan images.enable_
engine variable is set to ON
, which is the default setting.
If the compiled_
and compiled_
variables are not set or are set to 0
, compiled_
will be set as a percentage of maximum_
as shown in the following table.
|
|
In-memory Plancache Memory Limit |
---|---|---|
0-1 |
Prohibited ( |
|
1-64 |
|
10% of |
64+ |
|
5% of |
If the compiled_
or compiled_
variables are set, the memory limit for the in-memory plancache is derived at runtime as shown in the following table.
The notation _
denotes compiled_
and _
denotes compiled_
.
_ |
_ |
In-memory Plancache Memory Limit |
---|---|---|
0. |
0 |
The value is derived in accordance with the default allocation rule specified in the table above. |
0. |
> 0 |
If |
> 0. |
Any value |
The value of |
If the compiled_
variable is set to a value other than 0.compiled_
is ignored.
Note
Changes to maximum_
may result in changes in the module cache limit, in accordance with the rules specified above.
Drop a plan from the in-memory plancache
In addition to setting a retention policy for in-memory and on-disk plans, you may also choose to drop plans from the plancache to either compile a new query plan or reduce memory usage.
DROP ALL FROM PLANCACHE
purges all previously compiled plans, both in-memory and on-disk, and generates fresh query plans for any new queries.
Successful completion of a new ALTER TABLE
will invalidate the plancache for all queries that operate on the affected table, requiring their recompilation
ANALYZE
invalidates stale plans from both the in-memory and the on-disk plancache, including plans which are on-disk but not in-memory.
Note
The ANALYZE
command invalidates plans by marking them as invalid so they won’t be used in the future, but it does not actually delete all the files in the on-disk plancache.disk_
), manually delete the files from the plancache directory.DROP ALL FROM PLANCACHE
command.
Delete Plancache Files
Warning
The manual deletion of plancache files on disk is an offline operation and should be performed with caution.enable_
and disk_
to set shorter expiration times if you frequently run out of disk space due to the size of your on-disk plancache.
To delete the physical plancache files stored on disk, perform the following actions:
-
Stop each node using the
sdb-admin stop-node
command.The following example shows how to shut down a single node; however, you can use the option --all
to shut down the whole cluster.sdb-admin stop-node --memsql-id <MemSQL_ID> -
Delete the contents of the
plancache
directory on each node.The default location is /var/lib/memsql/<ROLE>-<PORT>-<ID>/plancache/
.sudo rm -rf /path/to/plancache/* -
Start the nodes back up using the
sdb-admin start-node
command.The following example shows how to start up a single node; however, you can use the option --all
to start all nodes.sdb-admin start-node --memsql-id <MemSQL_ID>
The on-disk plancache should be cleared from the node as well as the in-memory plancache because of the node restart operation.
Change the plancache
Directory
Each node in the cluster has a plancache
directory which contains compiled plans used for code generation.plancache
directory is /var/lib/memsql/<node_
.
To change the plancache
directory on one or more nodes, perform the following steps on each target node separately.
-
Obtain a list of your cluster nodes by running the following command on the host where Toolbox is installed.
Make a note of the node ID of the target node(s) and the IP address of the target host(s). sdb-admin list-nodes+------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+ | MemSQL ID | Role | Host | Port | Process State | Connectable? | Version | Recovery State | Availability Group | Bind Address | +------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+ | C0EE1AEC3B | Master | ec2-54-234-59-65.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | | 0.0.0.0 | | 6AF9490486 | Aggregator | ec2-34-229-205-7.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | | 0.0.0.0 | | 2CDAC53371 | Leaf | ec2-54-160-159-22.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | 1 | 0.0.0.0 | | EF13284492 | Leaf | ec2-54-242-64-33.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | 1 | 0.0.0.0 | +------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+
-
Locate the node(s) on which
plancache
directory must be changed.Verify the location of the plancache
directory on each node by running the following command.sdb-admin describe-node --memsql-id <node_ID>+--------------------+---------------------------------------------------------------------------------+ | memsqlId | EF13284492F0FDF0B35EC95B11523B9437B589B7 | | host | ec2-54-242-64-33.compute-1.amazonaws.com | | role | Leaf | | port | 3306 | | bindAddress | 0.0.0.0 | | processState | Running | | version | 7.6.6 | | memsqlConfig | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/memsql.cnf | | datadir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/data | | plancachedir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/plancache | | tracelogsdir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/tracelogs | | auditlogsdir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/auditlogs | | memsqld | /opt/memsql-server-7.6.6-63e226ba05/memsqld | | nodeID | 3 | | pid | 6967 | | dpid | 6974 | | autoRestartEnabled | true | | isConnectable | true | | recoveryState | Online | | availabilityGroup | 1 | | config | Omitted from table view. Use 'sdb-admin describe-node ... --property config' | | variables | Omitted from table view. Use 'sdb-admin describe-node ... --property variables' | +--------------------+---------------------------------------------------------------------------------+
-
Using the
sdb-admin stop-node
command, stop each target node.Optionally, you can use the --all
option to shut down the whole cluster.sdb-admin stop-node --memsql-id <node_ID>When prompted, choose to create a snapshot or skip it.
Continue to stop the node(s) without taking a database snapshot? Select 'Y' to stop the node(s) without taking a database snapshot. Select 'N' to take a snapshot of all databases and then stop the node(s). Taking a database snapshot will reduce the time it takes for the node(s) to recover after being restarted, but may increase the time it takes for the node(s) to stop. [Y/n]: Y Toolbox is about to perform the following actions on host ec2-54-242-64-33.compute-1.amazonaws.com: · Run 'memsqlctl stop-node --memsql-id EF13284492' Would you like to continue? [y/N]: y ✓ Stopped node on ec2-54-242-64-33.compute-1.amazonaws.com Operation completed successfully
-
After the node is stopped, log in to the target node’s host and copy the
plancache
directory recursively to the new path using the following command.The -p
option preserves the directory’s attributes including mode, ownership, and timestamp.sudo cp -R -p </path/to/source/directory> </path/to/destination/directory>In this example, the
plancache
directory needs to be moved from/var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/plancache
to/var/lib/plancache_
.data So the command will become: sudo cp -R -p /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/plancache /var/lib/plancacheImportant
-
SingleStore recommends to make a note of the directory’s permissions, user, and group prior to copying the files.
-
Make sure that the
plancache
directory’s permissions and ownership are intact.The default memsql
user should be able to access the newplancache
directory.
-
-
On the host where Toolbox is installed, run the following command to update the new
plancache
directory path for the required node(s).sdb-admin update-config --memsql-id <node_ID> --key plancachedir --value /new/path/to/directoryWhen prompted, confirm the update.
Toolbox is about to run 'memsqlctl update-config --key plancachedir --value /var/lib/plancache' on the following nodes: - On host ec2-54-242-64-33.compute-1.amazonaws.com: + EF13284492 Would you like to continue? [y/N]: y ✓ Updated configuration on ec2-54-242-64-33.compute-1.amazonaws.com Operation completed successfully
-
Verify the changes by running the following command.
sdb-admin describe-node --memsql-id <node_ID>+--------------------+------------------------------------------------------------------------------+ | memsqlId | EF13284492F0FDF0B35EC95B11523B9437B589B7 | | host | ec2-54-242-64-33.compute-1.amazonaws.com | | role | Leaf | | port | 3306 | | bindAddress | 0.0.0.0 | | processState | Stopped | | version | 7.6.6 | | memsqlConfig | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/memsql.cnf | | datadir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/data | | plancachedir | /var/lib/plancache | | tracelogsdir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/tracelogs | | auditlogsdir | /var/lib/memsql/aae1e686-42ab-432c-88bc-1086d894204a/auditlogs | | memsqld | /opt/memsql-server-7.6.6-63e226ba05/memsqld | | nodeID | -- | | pid | -- | | dpid | -- | | autoRestartEnabled | -- | | isConnectable | -- | | recoveryState | -- | | availabilityGroup | -- | | config | Omitted from table view. Use 'sdb-admin describe-node ... --property config' | | variables | -- | +--------------------+------------------------------------------------------------------------------+
-
Start the node(s) for which the
plancache
directory has been updated.Optionally, you can use the --all
option to start the entire cluster.sdb-admin start-node --memsql-id <node_ID>When prompted, confirm the operation.
Toolbox is about to perform the following actions on host ec2-54-242-64-33.compute-1.amazonaws.com:· Run 'memsqlctl start-node --memsql-id EF13284492'Would you like to continue? [y/N]: y✓ Started nodes on ec2-54-242-64-33.compute-1.amazonaws.com (1/1)✓ Successfully started nodes on 1 host✓ Successfully connected to nodeOperation completed successfully -
Verify the status of the updated nodes by running the
sdb-admin list-nodes
command.+------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+| MemSQL ID | Role | Host | Port | Process State | Connectable? | Version | Recovery State | Availability Group | Bind Address |+------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+| C0EE1AEC3B | Master | ec2-54-234-59-65.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | | 0.0.0.0 || 6AF9490486 | Aggregator | ec2-34-229-205-7.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | | 0.0.0.0 || 2CDAC53371 | Leaf | ec2-54-160-159-22.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | 1 | 0.0.0.0 || EF13284492 | Leaf | ec2-54-242-64-33.compute-1.amazonaws.com | 3306 | Running | True | 7.6.6 | Online | 1 | 0.0.0.0 |+------------+------------+-------------------------------------------+------+---------------+--------------+---------+----------------+--------------------+--------------+ -
To safely remove your old
plancache
directory, create a backup of the directory and all its contents and then delete it.To perform these actions, run the following commands on the target host. sudo cp -R -p <path/to/source/directory> <path/to/backup/directory>sudo rm -r dirname
Last modified: November 13, 2024