Browse Source

Track latest topic for each schedule

This adds a new latest_topic_id column to topic_schedule and uses
triggers on the topics table to keep it correct.

This isn't really ideal, but it will simplify a few things related to
scheduled topics by quite a bit. For example, this commit also uses that
new data to much more easily populate the list of scheduled topics in a
group's sidebar, which previously required a subquery and windowing.
merge-requests/106/head
Deimos 4 years ago
parent
commit
a451b7fb03
  1. 103
      tildes/alembic/versions/468cf81f4a6b_topic_schedule_add_latest_topic_id.py
  2. 53
      tildes/sql/init/triggers/topics/topic_schedule.sql
  3. 5
      tildes/tildes/models/topic/topic.py
  4. 14
      tildes/tildes/models/topic/topic_schedule.py
  5. 21
      tildes/tildes/views/topic.py

103
tildes/alembic/versions/468cf81f4a6b_topic_schedule_add_latest_topic_id.py

@ -0,0 +1,103 @@
"""topic_schedule: add latest_topic_id
Revision ID: 468cf81f4a6b
Revises: 4d86b372a8db
Create Date: 2020-06-25 02:53:09.435947
"""
from alembic import op
import sqlalchemy as sa
# revision identifiers, used by Alembic.
revision = "468cf81f4a6b"
down_revision = "4d86b372a8db"
branch_labels = None
depends_on = None
def upgrade():
op.add_column(
"topic_schedule", sa.Column("latest_topic_id", sa.Integer(), nullable=True)
)
op.create_foreign_key(
op.f("fk_topic_schedule_latest_topic_id_topics"),
"topic_schedule",
"topics",
["latest_topic_id"],
["topic_id"],
)
op.execute(
"""
create or replace function update_topic_schedule_latest_topic_id() returns trigger as $$
begin
if (NEW.schedule_id is not null) then
update topic_schedule
set latest_topic_id = (
select topic_id
from topics
where schedule_id = NEW.schedule_id
and is_deleted = false
and is_removed = false
order by created_time desc limit 1)
where schedule_id = NEW.schedule_id;
end if;
-- if it was an update that changed schedule_id, need to update the old schedule's
-- latest_topic_id as well (this will probably be extremely uncommon)
if (TG_OP = 'UPDATE'
and OLD.schedule_id is not null
and OLD.schedule_id is distinct from NEW.schedule_id) then
update topic_schedule
set latest_topic_id = (
select topic_id
from topics
where schedule_id = OLD.schedule_id
and is_deleted = false
and is_removed = false
order by created_time desc limit 1)
where schedule_id = OLD.schedule_id;
end if;
return null;
end
$$ language plpgsql;
"""
)
op.execute(
"""
create trigger update_topic_schedule_latest_topic_id_insert
after insert on topics
for each row
when (NEW.schedule_id is not null)
execute procedure update_topic_schedule_latest_topic_id();
"""
)
op.execute(
"""
create trigger update_topic_schedule_latest_topic_id_update
after update on topics
for each row
when ((OLD.schedule_id is not null or NEW.schedule_id is not null)
and ((OLD.is_deleted is distinct from NEW.is_deleted)
or (OLD.is_removed is distinct from NEW.is_removed)
or (OLD.schedule_id is distinct from NEW.schedule_id)))
execute procedure update_topic_schedule_latest_topic_id();
"""
)
def downgrade():
op.execute("drop trigger update_topic_schedule_latest_topic_id_update on topics")
op.execute("drop trigger update_topic_schedule_latest_topic_id_insert on topics")
op.execute("drop function update_topic_schedule_latest_topic_id")
op.drop_constraint(
op.f("fk_topic_schedule_latest_topic_id_topics"),
"topic_schedule",
type_="foreignkey",
)
op.drop_column("topic_schedule", "latest_topic_id")

53
tildes/sql/init/triggers/topics/topic_schedule.sql

@ -0,0 +1,53 @@
-- Copyright (c) 2020 Tildes contributors <code@tildes.net>
-- SPDX-License-Identifier: AGPL-3.0-or-later
create or replace function update_topic_schedule_latest_topic_id() returns trigger as $$
begin
if (NEW.schedule_id is not null) then
update topic_schedule
set latest_topic_id = (
select topic_id
from topics
where schedule_id = NEW.schedule_id
and is_deleted = false
and is_removed = false
order by created_time desc limit 1)
where schedule_id = NEW.schedule_id;
end if;
-- if it was an update that changed schedule_id, need to update the old schedule's
-- latest_topic_id as well (this will probably be extremely uncommon)
if (TG_OP = 'UPDATE'
and OLD.schedule_id is not null
and OLD.schedule_id is distinct from NEW.schedule_id) then
update topic_schedule
set latest_topic_id = (
select topic_id
from topics
where schedule_id = OLD.schedule_id
and is_deleted = false
and is_removed = false
order by created_time desc limit 1)
where schedule_id = OLD.schedule_id;
end if;
return null;
end
$$ language plpgsql;
create trigger update_topic_schedule_latest_topic_id_insert
after insert on topics
for each row
when (NEW.schedule_id is not null)
execute procedure update_topic_schedule_latest_topic_id();
create trigger update_topic_schedule_latest_topic_id_update
after update on topics
for each row
when ((OLD.schedule_id is not null or NEW.schedule_id is not null)
and ((OLD.is_deleted is distinct from NEW.is_deleted)
or (OLD.is_removed is distinct from NEW.is_removed)
or (OLD.schedule_id is distinct from NEW.schedule_id)))
execute procedure update_topic_schedule_latest_topic_id();

5
tildes/tildes/models/topic/topic.py

@ -65,6 +65,9 @@ class Topic(DatabaseModel):
updates to is_deleted in comments. updates to is_deleted in comments.
- last_activity_time will be updated by insertions, deletions, and updates to - last_activity_time will be updated by insertions, deletions, and updates to
is_deleted in comments. is_deleted in comments.
Outgoing:
- Inserting rows or updating is_deleted/is_removed to change visibility will
update topic_schedule.latest_topic_id if the topic has a schedule_id.
Internal: Internal:
- deleted_time will be set when is_deleted is set to true - deleted_time will be set when is_deleted is set to true
""" """
@ -127,6 +130,8 @@ class Topic(DatabaseModel):
user: User = relationship("User", lazy=False, innerjoin=True) user: User = relationship("User", lazy=False, innerjoin=True)
group: Group = relationship("Group", innerjoin=True) group: Group = relationship("Group", innerjoin=True)
schedule = relationship("TopicSchedule", foreign_keys=[schedule_id])
# Create specialized indexes # Create specialized indexes
__table_args__ = ( __table_args__ = (
Index("ix_topics_tags_gist", tags, postgresql_using="gist"), Index("ix_topics_tags_gist", tags, postgresql_using="gist"),

14
tildes/tildes/models/topic/topic_schedule.py

@ -9,7 +9,7 @@ from typing import List, Optional
from dateutil.rrule import rrule from dateutil.rrule import rrule
from jinja2.sandbox import SandboxedEnvironment from jinja2.sandbox import SandboxedEnvironment
from sqlalchemy import CheckConstraint, Column, ForeignKey, Integer, Text, TIMESTAMP from sqlalchemy import CheckConstraint, Column, ForeignKey, Integer, Text, TIMESTAMP
from sqlalchemy.orm import backref, relationship
from sqlalchemy.orm import relationship
from sqlalchemy.orm.session import Session from sqlalchemy.orm.session import Session
from sqlalchemy.sql.expression import text from sqlalchemy.sql.expression import text
@ -23,7 +23,13 @@ from tildes.schemas.topic import TITLE_MAX_LENGTH
class TopicSchedule(DatabaseModel): class TopicSchedule(DatabaseModel):
"""Model for scheduled topics (auto-posted, often repeatedly on a schedule)."""
"""Model for scheduled topics (auto-posted, often repeatedly on a schedule).
Trigger behavior:
Incoming:
- latest_topic_id will be set when a new topic is inserted for the schedule,
and updated when a topic from the schedule is deleted or removed.
"""
__tablename__ = "topic_schedule" __tablename__ = "topic_schedule"
@ -46,11 +52,11 @@ class TopicSchedule(DatabaseModel):
TIMESTAMP(timezone=True), nullable=True, index=True TIMESTAMP(timezone=True), nullable=True, index=True
) )
recurrence_rule: Optional[rrule] = Column(RecurrenceRule, nullable=True) recurrence_rule: Optional[rrule] = Column(RecurrenceRule, nullable=True)
latest_topic_id: int = Column(Integer, ForeignKey("topics.topic_id"), nullable=True)
group: Group = relationship("Group", innerjoin=True) group: Group = relationship("Group", innerjoin=True)
user: Optional[User] = relationship("User") user: Optional[User] = relationship("User")
topics: List[Topic] = relationship(Topic, backref=backref("schedule"))
latest_topic: Topic = relationship("Topic", foreign_keys=[latest_topic_id])
def __init__( def __init__(
self, self,

21
tildes/tildes/views/topic.py

@ -15,7 +15,8 @@ from pyramid.request import Request
from pyramid.response import Response from pyramid.response import Response
from pyramid.view import view_config from pyramid.view import view_config
from sqlalchemy import cast from sqlalchemy import cast
from sqlalchemy.sql.expression import any_, desc, text
from sqlalchemy.orm import joinedload
from sqlalchemy.sql.expression import any_, desc
from sqlalchemy_utils import Ltree from sqlalchemy_utils import Ltree
from webargs.pyramidparser import use_kwargs from webargs.pyramidparser import use_kwargs
@ -249,25 +250,21 @@ def get_group_topics( # noqa
if isinstance(request.context, Group): if isinstance(request.context, Group):
# Get the most recent topic from each scheduled topic in this group # Get the most recent topic from each scheduled topic in this group
# I'm not even going to attempt to write this query in pure SQLAlchemy
topic_id_subquery = """
SELECT topic_id FROM (SELECT topic_id, schedule_id, row_number() OVER
(PARTITION BY schedule_id ORDER BY created_time DESC) AS rownum FROM topics)
AS t WHERE schedule_id IS NOT NULL AND rownum = 1
"""
most_recent_scheduled_topics = (
request.query(Topic)
.join(TopicSchedule)
group_schedules = (
request.query(TopicSchedule)
.options(joinedload(TopicSchedule.latest_topic))
.filter( .filter(
Topic.topic_id.in_(text(topic_id_subquery)), # type: ignore
TopicSchedule.group == request.context, TopicSchedule.group == request.context,
TopicSchedule.next_post_time != None, # noqa TopicSchedule.next_post_time != None, # noqa
) )
.order_by(TopicSchedule.next_post_time) .order_by(TopicSchedule.next_post_time)
.all() .all()
) )
most_recent_scheduled_topics = [
schedule.latest_topic for schedule in group_schedules
]
else: else:
most_recent_scheduled_topics = None
most_recent_scheduled_topics = []
if is_home_page: if is_home_page:
financial_data = get_financial_data(request.db_session) financial_data = get_financial_data(request.db_session)

Loading…
Cancel
Save