Browse Source

Extend topic indexes for keyset pagination

The "keyset"-style pagination that Tildes uses for topic listings uses
WHERE and ORDER BY clauses that involve multiple columns to keep a
deterministic ordering even when the values in the main sort column are
equal. For example, when sorting by number of votes, you're actually
ordering by num_votes DESC, topic_id DESC. The previous single-column
indexes were a little inefficient for this and couldn't always be used
well.

This commit extends all of the relevant indexes to composite ones that
contain topic_id as well, and drops all of the original ones. This
should be more efficient, and should probably be done to indexes on the
comments table as well.
merge-requests/88/head
Deimos 5 years ago
parent
commit
47657c988e
  1. 76
      tildes/alembic/versions/f4e1ef359307_extend_topic_indexes_for_keyset_.py
  2. 35
      tildes/tildes/models/topic/topic.py

76
tildes/alembic/versions/f4e1ef359307_extend_topic_indexes_for_keyset_.py

@ -0,0 +1,76 @@
"""Extend topic indexes for keyset pagination
Revision ID: f4e1ef359307
Revises: 4e101aae77cd
Create Date: 2020-01-15 20:52:23.380355
"""
from alembic import op
import sqlalchemy as sa
# revision identifiers, used by Alembic.
revision = "f4e1ef359307"
down_revision = "4e101aae77cd"
branch_labels = None
depends_on = None
def upgrade():
op.create_index(
"ix_topics_created_time_keyset",
"topics",
[sa.text("created_time DESC"), sa.text("topic_id DESC")],
unique=False,
)
op.create_index(
"ix_topics_last_activity_time_keyset",
"topics",
[sa.text("last_activity_time DESC"), sa.text("topic_id DESC")],
unique=False,
)
op.create_index(
"ix_topics_last_interesting_activity_time_keyset",
"topics",
[sa.text("last_interesting_activity_time DESC"), sa.text("topic_id DESC")],
unique=False,
)
op.create_index(
"ix_topics_num_comments_keyset",
"topics",
[sa.text("num_comments DESC"), sa.text("topic_id DESC")],
unique=False,
)
op.create_index(
"ix_topics_num_votes_keyset",
"topics",
[sa.text("num_votes DESC"), sa.text("topic_id DESC")],
unique=False,
)
op.drop_index("ix_topics_created_time", table_name="topics")
op.drop_index("ix_topics_last_activity_time", table_name="topics")
op.drop_index("ix_topics_last_interesting_activity_time", table_name="topics")
op.drop_index("ix_topics_num_comments", table_name="topics")
op.drop_index("ix_topics_num_votes", table_name="topics")
def downgrade():
op.create_index("ix_topics_num_votes", "topics", ["num_votes"], unique=False)
op.create_index("ix_topics_num_comments", "topics", ["num_comments"], unique=False)
op.create_index(
"ix_topics_last_interesting_activity_time",
"topics",
["last_interesting_activity_time"],
unique=False,
)
op.create_index(
"ix_topics_last_activity_time", "topics", ["last_activity_time"], unique=False
)
op.create_index("ix_topics_created_time", "topics", ["created_time"], unique=False)
op.drop_index("ix_topics_num_votes_keyset", table_name="topics")
op.drop_index("ix_topics_num_comments_keyset", table_name="topics")
op.drop_index(
"ix_topics_last_interesting_activity_time_keyset", table_name="topics"
)
op.drop_index("ix_topics_last_activity_time_keyset", table_name="topics")
op.drop_index("ix_topics_created_time_keyset", table_name="topics")

35
tildes/tildes/models/topic/topic.py

@ -23,7 +23,7 @@ from sqlalchemy import (
from sqlalchemy.dialects.postgresql import ENUM, JSONB, TSVECTOR from sqlalchemy.dialects.postgresql import ENUM, JSONB, TSVECTOR
from sqlalchemy.ext.mutable import MutableDict from sqlalchemy.ext.mutable import MutableDict
from sqlalchemy.orm import deferred, relationship from sqlalchemy.orm import deferred, relationship
from sqlalchemy.sql.expression import text
from sqlalchemy.sql.expression import desc, text
from titlecase import titlecase from titlecase import titlecase
from tildes.enums import ContentMetadataFields, TopicContentType, TopicType from tildes.enums import ContentMetadataFields, TopicContentType, TopicType
@ -86,23 +86,14 @@ class Topic(DatabaseModel):
Integer, ForeignKey("topic_schedule.schedule_id"), index=True Integer, ForeignKey("topic_schedule.schedule_id"), index=True
) )
created_time: datetime = Column( created_time: datetime = Column(
TIMESTAMP(timezone=True),
nullable=False,
index=True,
server_default=text("NOW()"),
TIMESTAMP(timezone=True), nullable=False, server_default=text("NOW()"),
) )
last_edited_time: Optional[datetime] = Column(TIMESTAMP(timezone=True)) last_edited_time: Optional[datetime] = Column(TIMESTAMP(timezone=True))
last_activity_time: datetime = Column( last_activity_time: datetime = Column(
TIMESTAMP(timezone=True),
nullable=False,
index=True,
server_default=text("NOW()"),
TIMESTAMP(timezone=True), nullable=False, server_default=text("NOW()"),
) )
last_interesting_activity_time: datetime = Column( last_interesting_activity_time: datetime = Column(
TIMESTAMP(timezone=True),
nullable=False,
index=True,
server_default=text("NOW()"),
TIMESTAMP(timezone=True), nullable=False, server_default=text("NOW()"),
) )
is_deleted: bool = Column( is_deleted: bool = Column(
Boolean, nullable=False, server_default="false", index=True Boolean, nullable=False, server_default="false", index=True
@ -125,8 +116,8 @@ class Topic(DatabaseModel):
content_metadata: Dict[str, Any] = Column( content_metadata: Dict[str, Any] = Column(
MutableDict.as_mutable(JSONB(none_as_null=True)) MutableDict.as_mutable(JSONB(none_as_null=True))
) )
num_comments: int = Column(Integer, nullable=False, server_default="0", index=True)
num_votes: int = Column(Integer, nullable=False, server_default="0", index=True)
num_comments: int = Column(Integer, nullable=False, server_default="0")
num_votes: int = Column(Integer, nullable=False, server_default="0")
_is_voting_closed: bool = Column( _is_voting_closed: bool = Column(
"is_voting_closed", Boolean, nullable=False, server_default="false", index=True "is_voting_closed", Boolean, nullable=False, server_default="false", index=True
) )
@ -142,6 +133,20 @@ class Topic(DatabaseModel):
__table_args__ = ( __table_args__ = (
Index("ix_topics_tags_gist", tags, postgresql_using="gist"), Index("ix_topics_tags_gist", tags, postgresql_using="gist"),
Index("ix_topics_search_tsv_gin", "search_tsv", postgresql_using="gin"), Index("ix_topics_search_tsv_gin", "search_tsv", postgresql_using="gin"),
# Indexes for keyset pagination
Index("ix_topics_created_time_keyset", desc(created_time), desc(topic_id)),
Index(
"ix_topics_last_activity_time_keyset",
desc(last_activity_time),
desc(topic_id),
),
Index(
"ix_topics_last_interesting_activity_time_keyset",
desc(last_interesting_activity_time),
desc(topic_id),
),
Index("ix_topics_num_comments_keyset", desc(num_comments), desc(topic_id)),
Index("ix_topics_num_votes_keyset", desc(num_votes), desc(topic_id)),
) )
@hybrid_property # pylint: disable=used-before-assignment @hybrid_property # pylint: disable=used-before-assignment

Loading…
Cancel
Save