Skip to content
Snippets Groups Projects
Commit b18d465c authored by Jan Mach's avatar Jan Mach
Browse files

Moved metadata database cluster commands from migration script to documentation.

To be consistent with the rest of the system. SQLAlchemy ORM model does not allow to specify ALTER TABLE commands for models. Therefore it would be necessary to run migrations after clean installation, which could cause chaos and troubles with schema versions and stamping. I have moved the cluster commands to database optimization documentation, which is where they belong. (Redmine issue: #6096)
parent ae5916be
No related branches found
No related tags found
No related merge requests found
......@@ -198,6 +198,8 @@ Regular VACUUM and ANALYZE
.. code-block:: sql
psql mentat_events
ALTER TABLE events SET (autovacuum_vacuum_threshold=10000);
ALTER TABLE events SET (autovacuum_vacuum_scale_factor=0.0);
ALTER TABLE events_json SET (autovacuum_vacuum_threshold=10000);
......@@ -207,6 +209,8 @@ Regular VACUUM and ANALYZE
.. code-block:: sql
psql mentat_events
ALTER TABLE events SET (autovacuum_analyze_threshold=20000);
ALTER TABLE events SET (autovacuum_analyze_scale_factor=0.0);
ALTER TABLE events_json SET (autovacuum_analyze_threshold=20000);
......@@ -225,6 +229,26 @@ Regular VACUUM and ANALYZE
* These settings limit the automatic ``VACUUM`` operation, when the cost limit is reached (same scale as other costs), the operation is postponed for the length of delay. Default values of cost 200 and delay 20 ms are aimed at very low additional load to be generated by this background task to affect normal operation. As this is mostly CPU bound and runs in single thread, we can allow for more aggressive values in our use case. For large tables such as events, this allows the autovacuum to finish in a few minutes instead of tens of minutes with default values. The risk of cancelling background ``VACUUM`` due to conflicting operation is therefore lowered and the reclamation of invalidated rows is performed much more promptly what reduces the index and table bloat considerably. The chosen value of delay still enables brief autovacuum process sleeps during the run, what is aimed at preventing disk subsystem overload as ``VACUUM`` tends to be an IO heavy operation.
CLUSTERing
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
.. code-block:: sql
psql mentat_main
ALTER TABLE users CLUSTER ON users_pkey;
ALTER TABLE groups CLUSTER ON groups_pkey;
ALTER TABLE networks CLUSTER ON networks_pkey;
ALTER TABLE filters CLUSTER ON filters_pkey;
ALTER TABLE reports_events CLUSTER ON reports_events_pkey;
ALTER TABLE statistics_events CLUSTER ON statistics_events_pkey;
ALTER TABLE changelog_items CLUSTER ON changelog_items_pkey;
ALTER TABLE settings_reporting CLUSTER ON settings_reporting_pkey;
ALTER TABLE asoc_group_managers CLUSTER ON asoc_group_managers_pkey;
ALTER TABLE asoc_group_members CLUSTER ON asoc_group_members_pkey;
ALTER TABLE asoc_group_members_wanted CLUSTER ON asoc_group_members_wanted_pkey;
Current database schema
--------------------------------------------------------------------------------
......@@ -249,6 +273,8 @@ IDEA event database
.. code-block:: sql
psql mentat_events
#
# IDEA event metadata storage.
#
......@@ -306,6 +332,20 @@ IDEA event database
PRIMARY KEY(eventid, keyid)
);
#
# Enumeration tables.
#
CREATE TABLE IF NOT EXISTS enum_category (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_protocol (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_node_name (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_node_type (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_source_type (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_target_type (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_cesnet_resolvedabuses (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_cesnet_eventclass (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_cesnet_eventseverity (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE TABLE IF NOT EXISTS enum_cesnet_inspectionerrors (data text UNIQUE NOT NULL, last_seen TIMESTAMP WITHOUT TIME ZONE NOT NULL)
CREATE INDEX IF NOT EXISTS events_detecttime_idx ON events USING BTREE (detecttime);
CREATE INDEX IF NOT EXISTS events_cesnet_storagetime_idx ON events USING BTREE (cesnet_storagetime);
CREATE INDEX IF NOT EXISTS events_cesnet_eventseverity_idx ON events USING BTREE (cesnet_eventseverity) WHERE cesnet_eventseverity IS NOT NULL;
......@@ -318,6 +358,17 @@ IDEA event database
CREATE INDEX IF NOT EXISTS events_thresholded_combined_idx ON events_thresholded USING BTREE (groupname, eventseverity);
CREATE INDEX IF NOT EXISTS events_thresholded_createtime_idx ON events_thresholded USING BTREE (createtime);
CREATE INDEX IF NOT EXISTS enum_category_lastseen_idx ON enum_category USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_protocol_lastseen_idx ON enum_protocol USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_node_name_lastseen_idx ON enum_node_name USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_node_type_lastseen_idx ON enum_node_type USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_source_type_lastseen_idx ON enum_source_type USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_target_type_lastseen_idx ON enum_target_type USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_cesnet_resolvedabuses_lastseen_idx ON enum_cesnet_resolvedabuses USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_cesnet_eventclass_lastseen_idx ON enum_cesnet_eventclass USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_cesnet_eventseverity_lastseen_idx ON enum_cesnet_eventseverity USING BTREE (last_seen)
CREATE INDEX IF NOT EXISTS enum_cesnet_inspectionerrors_lastseen_idx ON cesnet_inspectionerrors USING BTREE (last_seen)
Usefull maintenance queries
--------------------------------------------------------------------------------
......
"""Enable CLUSTER
Revision ID: 3da0b2119f35
Revises: 29c1e46e89c7
Create Date: 2020-01-14 09:57:20.597127
"""
from alembic import op
import sqlalchemy as sa
# revision identifiers, used by Alembic.
revision = '3da0b2119f35' # pylint: disable=locally-disabled,invalid-name
down_revision = '29c1e46e89c7' # pylint: disable=locally-disabled,invalid-name
branch_labels = None # pylint: disable=locally-disabled,invalid-name
depends_on = None # pylint: disable=locally-disabled,invalid-name
def upgrade(): # pylint: disable=locally-disabled,missing-docstring
op.execute("ALTER TABLE users CLUSTER ON users_pkey")
op.execute("ALTER TABLE groups CLUSTER ON groups_pkey")
op.execute("ALTER TABLE networks CLUSTER ON networks_pkey")
op.execute("ALTER TABLE filters CLUSTER ON filters_pkey")
op.execute("ALTER TABLE reports_events CLUSTER ON reports_events_pkey")
op.execute("ALTER TABLE statistics_events CLUSTER ON statistics_events_pkey")
op.execute("ALTER TABLE changelog_items CLUSTER ON changelog_items_pkey")
op.execute("ALTER TABLE settings_reporting CLUSTER ON settings_reporting_pkey")
op.execute("ALTER TABLE asoc_group_managers CLUSTER ON asoc_group_managers_pkey")
op.execute("ALTER TABLE asoc_group_members CLUSTER ON asoc_group_members_pkey")
op.execute("ALTER TABLE asoc_group_members_wanted CLUSTER ON asoc_group_members_wanted_pkey")
def downgrade(): # pylint: disable=locally-disabled,missing-docstring
op.execute("ALTER TABLE users SET WITHOUT CLUSTER")
op.execute("ALTER TABLE groups SET WITHOUT CLUSTER")
op.execute("ALTER TABLE networks SET WITHOUT CLUSTER")
op.execute("ALTER TABLE filters SET WITHOUT CLUSTER")
op.execute("ALTER TABLE reports_events SET WITHOUT CLUSTER")
op.execute("ALTER TABLE statistics_events SET WITHOUT CLUSTER")
op.execute("ALTER TABLE changelog_items SET WITHOUT CLUSTER")
op.execute("ALTER TABLE settings_reporting SET WITHOUT CLUSTER")
op.execute("ALTER TABLE asoc_group_managers SET WITHOUT CLUSTER")
op.execute("ALTER TABLE asoc_group_members SET WITHOUT CLUSTER")
op.execute("ALTER TABLE asoc_group_members_wanted SET WITHOUT CLUSTER")
......@@ -20,4 +20,4 @@ open-source project.
__author__ = "Jan Mach <jan.mach@cesnet.cz>"
__credits__ = "Pavel Kácha <pavel.kacha@cesnet.cz>, Andrea Kropáčová <andrea.kropacova@cesnet.cz>"
__version__ = "2.5.23"
__version__ = "2.5.24"
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment