From 7772f1925fb664c8d8b37ce6cc730b211a06f700 Mon Sep 17 00:00:00 2001 From: ivis-miyachi Date: Fri, 13 Feb 2026 11:19:11 +0900 Subject: [PATCH] Modify audit log database to partition table --- modules/weko-logging/setup.py | 3 + modules/weko-logging/weko_logging/cli.py | 51 ++++++++++ modules/weko-logging/weko_logging/models.py | 100 ++++++++++++++++---- postgresql/ddl/W2025-29.sql | 79 +++++++++++++++- scripts/populate-instance.sh | 2 + 5 files changed, 213 insertions(+), 22 deletions(-) create mode 100644 modules/weko-logging/weko_logging/cli.py diff --git a/modules/weko-logging/setup.py b/modules/weko-logging/setup.py index c940418706..4826869753 100644 --- a/modules/weko-logging/setup.py +++ b/modules/weko-logging/setup.py @@ -65,6 +65,9 @@ include_package_data=True, platforms="any", entry_points={ + "flask.commands": [ + "logging = weko_logging.cli:logging", + ], "invenio_base.apps": [ "weko_logging_fs = weko_logging.fs:WekoLoggingFS", "weko_logging_user_activity = weko_logging.audit:WekoLoggingUserActivity", diff --git a/modules/weko-logging/weko_logging/cli.py b/modules/weko-logging/weko_logging/cli.py new file mode 100644 index 0000000000..fdfea45d2f --- /dev/null +++ b/modules/weko-logging/weko_logging/cli.py @@ -0,0 +1,51 @@ + +import click +from datetime import datetime +from flask.cli import with_appcontext +from invenio_db import db + +@click.group() +def logging(): + """Logging CLI group.""" + pass + +@logging.group() +def partition(): + """Partition management commands.""" + pass + +@partition.command('create') +@click.argument('year', nargs=1,type=int) +@click.argument('month', default=0,type=int) +@with_appcontext +def _partition_create(year, month): + """Create partition table for user activity logs. + + YEAR: Year of the partition table. + MONTH: Month of the partition table. If 0, create for all months in the year. + """ + from weko_logging.models import make_user_activity_logs_partition_table,\ + get_user_activity_logs_partition_tables + + (sm, em) = (1, 12) if month==0 else (month, month) + + try: + d = datetime(year, sm, 1) + except Exception as e: + click.secho(e, fg='red') + return + + try: + tables = get_user_activity_logs_partition_tables() + + for m in range(sm, em+1): + tablename = make_user_activity_logs_partition_table(year, m) + if tablename in tables: + click.secho('Table {} is already exist.'.format(tablename), fg='yellow') + else: + click.secho('Creating partitioning table {}.'.format(tablename), fg='green') + db.metadata.tables[tablename].create(bind=db.engine, checkfirst=True) + db.session.commit() + except Exception as e: + db.session.rollback() + click.secho(str(e), fg='red') \ No newline at end of file diff --git a/modules/weko-logging/weko_logging/models.py b/modules/weko-logging/weko_logging/models.py index 719136d8b7..58e2d5c749 100644 --- a/modules/weko-logging/weko_logging/models.py +++ b/modules/weko-logging/weko_logging/models.py @@ -9,9 +9,12 @@ from datetime import datetime, timezone -from sqlalchemy import Sequence +from dateutil.relativedelta import relativedelta +from sqlalchemy import Sequence, event from sqlalchemy.dialects import mysql, postgresql from sqlalchemy_utils.types import JSONType +from sqlalchemy.ext.declarative import declared_attr +from sqlalchemy.sql.ddl import DDL from invenio_accounts.models import User from invenio_communities.models import Community @@ -19,7 +22,7 @@ group_id_seq = Sequence('user_activity_log_group_id_seq', metadata=db.metadata) -class UserActivityLog(db.Model): +class _UserActivityLogBase(db.Model): """User activity log model.""" __tablename__ = 'user_activity_logs' @@ -35,29 +38,34 @@ class UserActivityLog(db.Model): db.DateTime().with_variant(mysql.DATETIME(fsp=6), 'mysql'), nullable=False, default=lambda: datetime.now(timezone.utc), + primary_key=True ) """Date and time of the log entry.""" - user_id = db.Column( - db.Integer(), - db.ForeignKey( - User.id, - name='fk_user_activity_active_user_id', - ondelete='SET NULL' - ), - nullable=True - ) + @declared_attr + def user_id(cls): + return db.Column( + db.Integer(), + db.ForeignKey( + User.id, + name='fk_user_activity_active_user_id', + ondelete='SET NULL' + ), + nullable=True + ) """User ID of the user who performed the action.""" - community_id = db.Column( - db.String(100), - db.ForeignKey( - Community.id, - name='fk_user_activity_community_id', - ondelete='SET NULL' - ), - nullable=True - ) + @declared_attr + def community_id(cls): + return db.Column( + db.String(100), + db.ForeignKey( + Community.id, + name='fk_user_activity_community_id', + ondelete='SET NULL' + ), + nullable=True + ) """Community ID of the community where the action was performed.""" log_group_id = db.Column( @@ -117,3 +125,55 @@ def get_log_group_sequence(cls, session): session = db.session next_id = session.execute(group_id_seq) return next_id + +class UserActivityLog(db.Model,_UserActivityLogBase): + """User activity log model.""" + + __tablename__ = 'user_activity_logs' + __table_args__ = ( + db.UniqueConstraint('date', name='uq_date'), + { "postgresql_partition_by": 'RANGE (date)' } + ) + +def get_user_activity_logs_partition_tables(): + """Get the partition table for the user_activity_logs table + + Returns: + list: List of partition table names. + """ + + query = "select tablename from pg_tables where tablename like 'user_activity_logs_partition_%'" + tables = db.session.execute(query).fetchall() + + return [a[0] for a in tables] + +def make_user_activity_logs_partition_table(year, month): + """Create a new partition table for user_activity_logs for a specific year and month. + + Args: + year (int): The year for the partition. + month (int): The month for the partition. + Returns: + str: The name of the created partition table. + """ + start_date = datetime(year, month, 1, 0, 0, 0) + end_date = start_date + relativedelta(months=1) + suffix = '_' + start_date.strftime('%Y%m') + tablename = UserActivityLog.__tablename__ + suffix + + NewPartitionTable = type('UserActivityLogPartition' + suffix, + (db.Model,_UserActivityLogBase), + {"__tablename__": tablename}) + NewPartitionTable.__table__.add_is_dependent_on(UserActivityLog.__table__) + + alter_table = \ + "ALTER TABLE " + UserActivityLog.__tablename__ + " ATTACH PARTITION " + \ + tablename + \ + " FOR VALUES FROM ('{}') TO ('{}');".format(start_date.strftime('%Y-%m-%d'), + end_date.strftime('%Y-%m-%d')) + + event.listen(NewPartitionTable.__table__, + "after_create", + DDL(alter_table)) + + return tablename diff --git a/postgresql/ddl/W2025-29.sql b/postgresql/ddl/W2025-29.sql index e22310865e..2895bf317f 100644 --- a/postgresql/ddl/W2025-29.sql +++ b/postgresql/ddl/W2025-29.sql @@ -161,13 +161,88 @@ CREATE TABLE IF NOT EXISTS user_activity_logs ( log_group_id INTEGER, log JSONB NOT NULL, remarks TEXT, - CONSTRAINT pk_user_activity_logs PRIMARY KEY (id), + CONSTRAINT pk_user_activity_logs PRIMARY KEY (id, date), + CONSTRAINT uq_date UNIQUE (date), CONSTRAINT fk_user_activity_active_user_id FOREIGN KEY (user_id) REFERENCES accounts_user(id) ON DELETE SET NULL, CONSTRAINT fk_user_activity_community_id FOREIGN KEY (community_id) REFERENCES communities_community(id) ON DELETE SET NULL -); +) PARTITION BY RANGE (date); CREATE SEQUENCE IF NOT EXISTS user_activity_log_group_id_seq; +-- 2026-01~2026-12 +CREATE TABLE user_activity_logs_202601 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202601 FOR VALUES FROM ('2026-01-01') TO ('2026-02-01'); + +CREATE TABLE user_activity_logs_202602 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202602 FOR VALUES FROM ('2026-02-01') TO ('2026-03-01'); + +CREATE TABLE user_activity_logs_202603 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202603 FOR VALUES FROM ('2026-03-01') TO ('2026-04-01'); + +CREATE TABLE user_activity_logs_202604 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202604 FOR VALUES FROM ('2026-04-01') TO ('2026-05-01'); + +CREATE TABLE user_activity_logs_202605 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202605 FOR VALUES FROM ('2026-05-01') TO ('2026-06-01'); + +CREATE TABLE user_activity_logs_202606 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202606 FOR VALUES FROM ('2026-06-01') TO ('2026-07-01'); + +CREATE TABLE user_activity_logs_202607 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202607 FOR VALUES FROM ('2026-07-01') TO ('2026-08-01'); + +CREATE TABLE user_activity_logs_202608 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202608 FOR VALUES FROM ('2026-08-01') TO ('2026-09-01'); + +CREATE TABLE user_activity_logs_202609 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202609 FOR VALUES FROM ('2026-09-01') TO ('2026-10-01'); + +CREATE TABLE user_activity_logs_202610 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202610 FOR VALUES FROM ('2026-10-01') TO ('2026-11-01'); + +CREATE TABLE user_activity_logs_202611 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202611 FOR VALUES FROM ('2026-11-01') TO ('2026-12-01'); + +CREATE TABLE user_activity_logs_202612 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202612 FOR VALUES FROM ('2026-12-01') TO ('2027-01-01'); + +-- 2027-01~2027-12 +CREATE TABLE user_activity_logs_202701 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202701 FOR VALUES FROM ('2027-01-01') TO ('2027-02-01'); + +CREATE TABLE user_activity_logs_202702 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202702 FOR VALUES FROM ('2027-02-01') TO ('2027-03-01'); + +CREATE TABLE user_activity_logs_202703 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202703 FOR VALUES FROM ('2027-03-01') TO ('2027-04-01'); + +CREATE TABLE user_activity_logs_202704 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202704 FOR VALUES FROM ('2027-04-01') TO ('2027-05-01'); + +CREATE TABLE user_activity_logs_202705 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202705 FOR VALUES FROM ('2027-05-01') TO ('2027-06-01'); + +CREATE TABLE user_activity_logs_202706 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202706 FOR VALUES FROM ('2027-06-01') TO ('2027-07-01'); + +CREATE TABLE user_activity_logs_202707 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202707 FOR VALUES FROM ('2027-07-01') TO ('2027-08-01'); + +CREATE TABLE user_activity_logs_202708 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202708 FOR VALUES FROM ('2027-08-01') TO ('2027-09-01'); + +CREATE TABLE user_activity_logs_202709 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202709 FOR VALUES FROM ('2027-09-01') TO ('2027-10-01'); + +CREATE TABLE user_activity_logs_202710 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202710 FOR VALUES FROM ('2027-10-01') TO ('2027-11-01'); + +CREATE TABLE user_activity_logs_202711 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202711 FOR VALUES FROM ('2027-11-01') TO ('2027-12-01'); + +CREATE TABLE user_activity_logs_202712 (LIKE user_activity_logs INCLUDING ALL); +ALTER TABLE user_activity_logs ATTACH PARTITION user_activity_logs_202712 FOR VALUES FROM ('2027-12-01') TO ('2028-01-01'); + -- modules/weko-notifications RAISE NOTICE 'Migration for module weko-notifications'; diff --git a/scripts/populate-instance.sh b/scripts/populate-instance.sh index 37c5619be7..d73f54e8fa 100755 --- a/scripts/populate-instance.sh +++ b/scripts/populate-instance.sh @@ -127,6 +127,8 @@ ${INVENIO_WEB_INSTANCE} db init ${INVENIO_WEB_INSTANCE} db create -v ${INVENIO_WEB_INSTANCE} stats partition create $(date +%Y) ${INVENIO_WEB_INSTANCE} stats partition create $(date -d 'year' +%Y) +${INVENIO_WEB_INSTANCE} logging partition create $(date +%Y) +${INVENIO_WEB_INSTANCE} logging partition create $(date -d 'year' +%Y) # sphinxdoc-create-database-end # sphinxdoc-index-initialisation-begin