~sircmpwn/lists.sr.ht

b316f9457cd9d7e279cc548364338aa4c1c31278 — Adnan Maolood 1 year, 6 months ago 1cb00ed 0.57.6
schema: Rename SQL indexes to PostgreSQL-style

References: https://todo.sr.ht/~sircmpwn/sr.ht/306
M api/graph/schema.resolvers.go => api/graph/schema.resolvers.go +4 -4
@@ 578,7 578,7 @@ func (r *mutationResolver) CreateMailingList(ctx context.Context, name string, d
			&list.DefaultAccess); err != nil {
			if err, ok := err.(*pq.Error); ok &&
				err.Code == "23505" && // unique_violation
				err.Constraint == "uq_list_owner_id_name" {
				err.Constraint == "list_owner_id_name_key" {
				return fmt.Errorf("A mailing list with this name already exists.")
			}
			return err


@@ 713,7 713,7 @@ func (r *mutationResolver) UpdateUserACL(ctx context.Context, listID int, userID
				(SELECT id FROM list WHERE id = $1 AND owner_id = $4),
				$2, $3
			)
			ON CONFLICT ON CONSTRAINT uq_access_list_id_user_id
			ON CONFLICT ON CONSTRAINT access_list_id_user_id_key
			DO UPDATE SET
				updated = NOW() at time zone 'utc',
				permissions = $3


@@ 758,7 758,7 @@ func (r *mutationResolver) UpdateSenderACL(ctx context.Context, listID int, addr
				(SELECT id FROM list WHERE id = $1 AND owner_id = $4),
				$2, $3
			)
			ON CONFLICT ON CONSTRAINT uq_access_list_id_email
			ON CONFLICT ON CONSTRAINT access_list_id_email_key
			DO UPDATE SET
				updated = NOW() at time zone 'utc',
				permissions = $3


@@ 987,7 987,7 @@ func (r *mutationResolver) MailingListSubscribe(ctx context.Context, listID int)
				NOW() at time zone 'utc',
				$1, (SELECT id FROM list)
			)
			ON CONFLICT ON CONSTRAINT subscription_list_id_user_id_unique
			ON CONFLICT ON CONSTRAINT subscription_list_id_user_id_key
			DO UPDATE SET updated = NOW() at time zone 'utc'
			RETURNING id, created, user_id, list_id;`,
			auth.ForContext(ctx).UserID, listID, model.ACCESS_BROWSE)

A listssrht/alembic/versions/2a4319aa8d00_rename_sql_indexes_to_postgresql_style.py => listssrht/alembic/versions/2a4319aa8d00_rename_sql_indexes_to_postgresql_style.py +43 -0
@@ 0,0 1,43 @@
"""Rename SQL indexes to PostgreSQL-style

Revision ID: 2a4319aa8d00
Revises: 7faa55b46247
Create Date: 2023-03-13 21:55:24.211402

"""

# revision identifiers, used by Alembic.
revision = '2a4319aa8d00'
down_revision = '7faa55b46247'

from alembic import op
import sqlalchemy as sa


def upgrade():
    op.execute("""
    ALTER TABLE "user" RENAME CONSTRAINT user_username_unique TO user_username_key;
    ALTER TABLE list RENAME CONSTRAINT uq_list_owner_id_name TO list_owner_id_name_key;
    ALTER TABLE access RENAME CONSTRAINT uq_access_list_id_email TO access_list_id_email_key;
    ALTER TABLE access RENAME CONSTRAINT uq_access_list_id_user_id TO access_list_id_user_id_key;
    ALTER TABLE email RENAME CONSTRAINT uq_email_list_message_id TO email_list_id_message_id_key;
	ALTER TABLE subscription RENAME CONSTRAINT subscription_list_id_email_unique TO subscription_list_id_email_key;
	ALTER TABLE subscription RENAME CONSTRAINT subscription_list_id_user_id_unique TO subscription_list_id_user_id_key;

    DROP INDEX ix_user_username;
    ALTER INDEX ix_patchset_tool_key RENAME TO patchset_tool_key_idx;
    """)

def downgrade():
    op.execute("""
    ALTER TABLE "user" RENAME CONSTRAINT user_username_key TO user_username_unique;
    ALTER TABLE list RENAME CONSTRAINT list_owner_id_name_key TO uq_list_owner_id_name;
    ALTER TABLE access RENAME CONSTRAINT access_list_id_email_key TO uq_access_list_id_email;
    ALTER TABLE access RENAME CONSTRAINT access_list_id_user_id_key TO uq_access_list_id_user_id;
    ALTER TABLE email RENAME CONSTRAINT email_list_id_message_id_key TO uq_email_list_message_id;
	ALTER TABLE subscription RENAME CONSTRAINT subscription_list_id_email_key TO subscription_list_id_email_unique;
	ALTER TABLE subscription RENAME CONSTRAINT subscription_list_id_user_id_key TO subscription_list_id_user_id_unique;

    CREATE INDEX ix_user_username ON "user" USING btree (username);
    ALTER INDEX patchset_tool_key_idx RENAME TO ix_patchset_tool_key;
    """)

M listssrht/types/subscription.py => listssrht/types/subscription.py +0 -9
@@ 5,15 5,6 @@ import os

class Subscription(Base):
    __tablename__ = 'subscription'
    __table_args__ = (
        sa.UniqueConstraint("list_id", "email",
            name="subscription_list_id_email_unique"),
        sa.UniqueConstraint("list_id", "user_id",
            name="subscription_list_id_user_id_unique"),
        sa.CheckConstraint("(email IS NULL OR user_id IS NULL) " +
                "AND (email IS NOT NULL OR user_id IS NOT NULL)",
            name="subscription_email_xor_user_id"),
    )

    id = sa.Column(sa.Integer, primary_key=True)
    created = sa.Column(sa.DateTime, nullable=False)

M schema.sql => schema.sql +9 -12
@@ 29,7 29,7 @@ CREATE TYPE webhook_event AS ENUM (

CREATE TABLE "user" (
	id serial PRIMARY KEY,
	username character varying(256),
	username character varying(256) UNIQUE,
	created timestamp without time zone NOT NULL,
	updated timestamp without time zone NOT NULL,
	session character varying(128),


@@ 42,12 42,9 @@ CREATE TABLE "user" (
	location character varying(256),
	bio character varying(4096),
	oauth_revocation_token character varying(256),
	suspension_notice character varying(4096),
	CONSTRAINT user_username_unique UNIQUE (username)
	suspension_notice character varying(4096)
);

CREATE INDEX ix_user_username ON "user" USING btree (username);

CREATE TABLE list (
	id serial PRIMARY KEY,
	created timestamp without time zone NOT NULL,


@@ 61,7 58,7 @@ CREATE TABLE list (
	reject_mimetypes character varying DEFAULT 'text/html'::character varying NOT NULL,
	import_in_progress boolean DEFAULT false NOT NULL,
	visibility visibility NOT NULL,
	CONSTRAINT uq_list_owner_id_name UNIQUE (owner_id, name)
	UNIQUE (owner_id, name)
);

CREATE TABLE access (


@@ 72,8 69,8 @@ CREATE TABLE access (
	user_id integer REFERENCES "user"(id) ON DELETE CASCADE,
	list_id integer NOT NULL REFERENCES list(id) ON DELETE CASCADE,
	permissions integer DEFAULT 7 NOT NULL,
	CONSTRAINT uq_access_list_id_email UNIQUE (list_id, email),
	CONSTRAINT uq_access_list_id_user_id UNIQUE (list_id, user_id)
	UNIQUE (list_id, email),
	UNIQUE (list_id, user_id)
);

CREATE TABLE email (


@@ 107,7 104,7 @@ CREATE TABLE email (
	patch_subject character varying,
	superseded_by_id integer REFERENCES email(id) ON DELETE SET NULL,

	CONSTRAINT uq_email_list_message_id UNIQUE (list_id, message_id)
	UNIQUE (list_id, message_id)
);

-- TODO: Remove me


@@ 154,7 151,7 @@ CREATE TABLE patchset_tool (
	key character varying(128) NOT NULL
);

CREATE INDEX ix_patchset_tool_key ON patchset_tool USING btree (key);
CREATE INDEX patchset_tool_key_idx ON patchset_tool USING btree (key);

CREATE TABLE subscription (
	id serial PRIMARY KEY,


@@ 165,8 162,8 @@ CREATE TABLE subscription (
	user_id integer REFERENCES "user"(id) ON DELETE CASCADE,
	CONSTRAINT subscription_email_xor_user_id
		CHECK ((((email IS NULL) OR (user_id IS NULL)) AND ((email IS NOT NULL) OR (user_id IS NOT NULL)))),
	CONSTRAINT subscription_list_id_email_unique UNIQUE (list_id, email),
	CONSTRAINT subscription_list_id_user_id_unique UNIQUE (list_id, user_id)
	UNIQUE (list_id, email),
	UNIQUE (list_id, user_id)
);

-- GraphQL webhooks