-- An Identity is any object that can participate as an actor in the system. -- It can have groups, permissions, own other objects etc. CREATE TABLE "identity" ( "id" bigserial NOT NULL, "login" citext NULL, "passphrase" bytea NULL, "totp_secret" text NULL, "is_admin" boolean NOT NULL DEFAULT false, "is_disabled" boolean NOT NULL DEFAULT false, "created_at" timestamptz NOT NULL DEFAULT now(), PRIMARY KEY ("id") ); CREATE UNIQUE INDEX "identity_login_key" ON "identity" ("login"); -- A person is a human actor within the system, it is linked to exactly one -- identity. CREATE TABLE "person" ( "identity_id" bigint NOT NULL, "display_name" text NULL, "first_name" text NULL, "last_name" text NULL, "image_url" text NULL, "zoneinfo" text NULL, "locale" text NULL, FOREIGN KEY ("identity_id") REFERENCES "identity" ("id") ON DELETE CASCADE ON UPDATE RESTRICT, PRIMARY KEY ("identity_id") ); -- Email is an email address for an identity (most likely for a person), -- that may be verified. Zero or one email address assigned to the identity -- may be "primary", e.g. used for notifications or login. CREATE TABLE "email" ( "address" citext NOT NULL, "identity_id" bigint NOT NULL, "is_verified" boolean NOT NULL DEFAULT false, "is_primary" boolean NOT NULL DEFAULT false, "created_at" timestamptz NOT NULL DEFAULT now(), FOREIGN KEY ("identity_id") REFERENCES "identity" ("id") ON DELETE CASCADE ON UPDATE RESTRICT, PRIMARY KEY ("address") ); CREATE INDEX "email_is_verified_idx" ON "email" ("is_verified") WHERE "is_verified" = true; CREATE INDEX "email_identity_id_idx" ON "email" ("identity_id"); CREATE UNIQUE INDEX "email_is_primary_key" ON "email" ("identity_id", "is_primary") WHERE "is_primary" = true;