|
| 1 | +--! Previous: sha1:de60470eae2711674026eea0ced5e4917011e6ea |
| 2 | +--! Hash: sha1:9dea4fdd69d1299eefc0f9295f1ceea5face488e |
| 3 | +--! Message: users-and-auth |
| 4 | + |
| 5 | +--! split: 0001-jwt-token-type.sql |
| 6 | +DROP TYPE IF EXISTS app_public.jwt_token CASCADE; |
| 7 | +CREATE TYPE app_public.jwt_token AS |
| 8 | +( |
| 9 | + role text, |
| 10 | + user_id uuid, |
| 11 | + username text, |
| 12 | + exp bigint |
| 13 | +); |
| 14 | + |
| 15 | +--! split: 0002-viewer-id-function.sql |
| 16 | +CREATE OR REPLACE FUNCTION app_public.viewer_id() RETURNS uuid AS |
| 17 | +$$ |
| 18 | +SELECT nullif(current_setting('jwt.claims.user_id', TRUE), '')::uuid |
| 19 | +$$ LANGUAGE sql STABLE; |
| 20 | + |
| 21 | +COMMENT ON FUNCTION app_public.viewer_id() IS 'Gets the id of the viewer who was identified by our JWT.'; |
| 22 | + |
| 23 | +--! split: 0010-user-table.sql |
| 24 | +DROP TABLE IF EXISTS app_public.user CASCADE; |
| 25 | +CREATE TABLE app_public.user |
| 26 | +( |
| 27 | + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), |
| 28 | + username citext NOT NULL UNIQUE CHECK (length(username) >= 2 AND length(username) <= 24 AND |
| 29 | + username ~ '^[a-zA-Z]([_]?[a-zA-Z0-9])+$'), |
| 30 | + name text, |
| 31 | + avatar_url text CHECK (avatar_url ~ '^https?://[^/]+'), |
| 32 | + is_admin boolean NOT NULL DEFAULT FALSE, |
| 33 | + is_verified boolean NOT NULL DEFAULT FALSE, |
| 34 | + created_at timestamptz NOT NULL DEFAULT (NOW() AT TIME ZONE 'utc'), |
| 35 | + updated_at timestamptz NOT NULL DEFAULT (NOW() AT TIME ZONE 'utc') |
| 36 | +); |
| 37 | + |
| 38 | +ALTER TABLE app_public.user |
| 39 | + ENABLE ROW LEVEL SECURITY; |
| 40 | + |
| 41 | +-- Users are publicly visible, like on GitHub, Twitter, Facebook, Trello, etc. |
| 42 | +CREATE POLICY select_all ON app_public.user FOR SELECT USING (TRUE); |
| 43 | +-- You can only update yourself. |
| 44 | +CREATE POLICY update_self ON app_public.user FOR UPDATE USING (id = app_public.viewer_id()); |
| 45 | +GRANT SELECT ON app_public.user TO :DATABASE_VISITOR; |
| 46 | +-- NOTE: `insert` is not granted, because we'll handle that separately |
| 47 | +GRANT UPDATE (username, name, avatar_url) ON app_public.user TO :DATABASE_VISITOR; |
| 48 | +-- NOTE: `delete` is not granted, because we require confirmation via request_account_deletion/confirm_account_deletion |
| 49 | + |
| 50 | +COMMENT ON TABLE app_public.user IS |
| 51 | + E'A user who can log in to the application.'; |
| 52 | + |
| 53 | +COMMENT ON COLUMN app_public.user.id IS |
| 54 | + E'Unique identifier for the user.'; |
| 55 | +COMMENT ON COLUMN app_public.user.username IS |
| 56 | + E'Public-facing username (or ''handle'') of the user.'; |
| 57 | +COMMENT ON COLUMN app_public.user.name IS |
| 58 | + E'Public-facing name (or pseudonym) of the user.'; |
| 59 | +COMMENT ON COLUMN app_public.user.avatar_url IS |
| 60 | + E'Optional avatar URL.'; |
| 61 | +COMMENT ON COLUMN app_public.user.is_admin IS |
| 62 | + E'If true, the user has elevated privileges.'; |
| 63 | + |
| 64 | +CREATE TRIGGER _100_timestamps |
| 65 | + BEFORE INSERT OR UPDATE |
| 66 | + ON app_public.user |
| 67 | + FOR EACH ROW |
| 68 | +EXECUTE PROCEDURE app_private.tg__timestamps(); |
| 69 | + |
| 70 | +--! split: 0020-viewer-function.sql |
| 71 | +-- Returns the current user; this is a "custom query" function; see: |
| 72 | +-- https://www.graphile.org/postgraphile/custom-queries/ |
| 73 | +-- So this will be queryable via GraphQL as `{ viewer { ... } }` |
| 74 | +CREATE FUNCTION app_public.viewer() RETURNS app_public.user AS |
| 75 | +$$ |
| 76 | +SELECT * |
| 77 | +FROM app_public.user |
| 78 | +WHERE id = app_public.viewer_id(); |
| 79 | +$$ LANGUAGE sql STABLE; |
| 80 | + |
| 81 | +COMMENT ON FUNCTION app_public.viewer() IS |
| 82 | + E'The currently logged in user (or null if not logged in).'; |
| 83 | + |
| 84 | +--! split: 0030-user-secrets-table.sql |
| 85 | +-- The users table contains all the public information, but we need somewhere |
| 86 | +-- to store private information. In fact, this data is so private that we don't |
| 87 | +-- want the user themselves to be able to see it - things like the bcrypted |
| 88 | +-- password hash, timestamps of recent login attempts (to allow us to |
| 89 | +-- auto-protect user accounts that are under attack), etc. |
| 90 | +DROP TABLE IF EXISTS app_private.user_secrets CASCADE; |
| 91 | +CREATE TABLE app_private.user_secrets |
| 92 | +( |
| 93 | + user_id uuid NOT NULL PRIMARY KEY REFERENCES app_public.user ON DELETE CASCADE, |
| 94 | + password_hash text, |
| 95 | + last_login_at timestamptz NOT NULL DEFAULT now(), |
| 96 | + failed_password_attempts int NOT NULL DEFAULT 0, |
| 97 | + first_failed_password_attempt timestamptz, |
| 98 | + reset_password_token text, |
| 99 | + reset_password_token_generated timestamptz, |
| 100 | + failed_reset_password_attempts int NOT NULL DEFAULT 0, |
| 101 | + first_failed_reset_password_attempt timestamptz, |
| 102 | + delete_account_token text, |
| 103 | + delete_account_token_generated timestamptz |
| 104 | +); |
| 105 | + |
| 106 | +ALTER TABLE app_private.user_secrets |
| 107 | + ENABLE ROW LEVEL SECURITY; |
| 108 | + |
| 109 | +COMMENT ON TABLE app_private.user_secrets IS |
| 110 | + E'The contents of this table should never be visible to the user. Contains data mostly related to authentication.'; |
| 111 | + |
| 112 | +/* |
| 113 | + * When we insert into `users` we _always_ want there to be a matching |
| 114 | + * `user_secrets` entry, so we have a trigger to enforce this: |
| 115 | + */ |
| 116 | +CREATE OR REPLACE FUNCTION app_private.tg_user_secrets__insert_with_user() RETURNS trigger AS |
| 117 | +$$ |
| 118 | +BEGIN |
| 119 | + INSERT INTO app_private.user_secrets(user_id) VALUES (new.id); |
| 120 | + RETURN new; |
| 121 | +END; |
| 122 | +$$ LANGUAGE plpgsql VOLATILE SET search_path TO pg_catalog, public, pg_temp; |
| 123 | + |
| 124 | +CREATE TRIGGER _500_insert_secrets |
| 125 | + AFTER INSERT |
| 126 | + ON app_public.user |
| 127 | + FOR EACH ROW |
| 128 | +EXECUTE PROCEDURE app_private.tg_user_secrets__insert_with_user(); |
| 129 | + |
| 130 | +COMMENT ON FUNCTION app_private.tg_user_secrets__insert_with_user() IS |
| 131 | + E'Ensures that every user record has an associated user_secret record.'; |
| 132 | + |
| 133 | +--! split: 0040-user-has-password.sql |
| 134 | +/* |
| 135 | + * Because you can register with username/password or using OAuth (social |
| 136 | + * login), we need a way to tell the user whether or not they have a |
| 137 | + * password. This is to help the UI display the right interface: change |
| 138 | + * password or set password. |
| 139 | + */ |
| 140 | +CREATE FUNCTION app_public.users_has_password(u app_public.user) RETURNS boolean AS |
| 141 | +$$ |
| 142 | +SELECT (password_hash IS NOT NULL) |
| 143 | +FROM app_private.user_secrets |
| 144 | +WHERE user_secrets.user_id = u.id |
| 145 | + AND u.id = app_public.viewer_id(); |
| 146 | +$$ LANGUAGE sql STABLE SECURITY DEFINER SET search_path TO pg_catalog, public, pg_temp; |
| 147 | + |
| 148 | +--! split: 0050-user-emails.sql |
| 149 | +DROP TABLE IF EXISTS app_public.user_emails CASCADE; |
| 150 | +CREATE TABLE app_public.user_emails |
| 151 | +( |
| 152 | + id uuid PRIMARY KEY DEFAULT gen_random_uuid(), |
| 153 | + user_id uuid NOT NULL DEFAULT app_public.viewer_id() REFERENCES app_public.user ON DELETE CASCADE, |
| 154 | + email citext NOT NULL CHECK (email ~ '[^@]+@[^@]+\.[^@]+'), |
| 155 | + is_verified boolean NOT NULL DEFAULT FALSE, |
| 156 | + is_primary boolean NOT NULL DEFAULT FALSE, |
| 157 | + created_at timestamptz NOT NULL DEFAULT now(), |
| 158 | + updated_at timestamptz NOT NULL DEFAULT now(), |
| 159 | + -- Each user can only have an email once. |
| 160 | + CONSTRAINT user_emails_user_id_email_key UNIQUE (user_id, email), |
| 161 | + -- An unverified email cannot be set as the primary email. |
| 162 | + CONSTRAINT user_emails_must_be_verified_to_be_primary CHECK (is_primary IS FALSE OR is_verified IS TRUE) |
| 163 | +); |
| 164 | +ALTER TABLE app_public.user_emails |
| 165 | + ENABLE ROW LEVEL SECURITY; |
| 166 | + |
| 167 | +-- Once an email is verified, it may only be used by one user. (We can't |
| 168 | +-- enforce this before an email is verified otherwise it could be used to |
| 169 | +-- prevent a legitimate user from signing up.) |
| 170 | +CREATE UNIQUE INDEX uniq_user_emails_verified_email ON app_public.user_emails (email) WHERE (is_verified IS TRUE); |
| 171 | +-- Only one primary email per user. |
| 172 | +CREATE UNIQUE INDEX uniq_user_emails_primary_email ON app_public.user_emails (user_id) WHERE (is_primary IS TRUE); |
| 173 | +-- Allow efficient retrieval of all the emails owned by a particular user. |
| 174 | +CREATE INDEX idx_user_emails_user ON app_public.user_emails (user_id); |
| 175 | +-- For the user settings page sorting |
| 176 | +CREATE INDEX idx_user_emails_primary ON app_public.user_emails (is_primary, user_id); |
| 177 | + |
| 178 | +-- Keep created_at and updated_at up to date. |
| 179 | +CREATE TRIGGER _100_timestamps |
| 180 | + BEFORE INSERT OR UPDATE |
| 181 | + ON app_public.user_emails |
| 182 | + FOR EACH ROW |
| 183 | +EXECUTE PROCEDURE app_private.tg__timestamps(); |
| 184 | + |
| 185 | +--! split: 0060-authenticate-user.sql |
| 186 | +CREATE FUNCTION app_public.authenticate(username citext, |
| 187 | + password text) RETURNS app_public.jwt_token AS |
| 188 | +$$ |
| 189 | +DECLARE account app_private.user_secrets; |
| 190 | +BEGIN |
| 191 | + -- IF email |
| 192 | + IF username ~ '[^@]+@[^@]+\.[^@]+' |
| 193 | + THEN |
| 194 | + SELECT a.* |
| 195 | + INTO account |
| 196 | + FROM app_private.user_secrets AS a |
| 197 | + INNER JOIN app_public.user_emails ue ON ue.user_id = a.user_id |
| 198 | + WHERE ue.email = authenticate.username; |
| 199 | + ELSE |
| 200 | + SELECT a.* |
| 201 | + INTO account |
| 202 | + FROM app_private.user_secrets AS a |
| 203 | + INNER JOIN app_public.user u ON a.user_id = u.id |
| 204 | + WHERE u.username = authenticate.username; |
| 205 | + END IF; |
| 206 | + |
| 207 | + |
| 208 | +-- SELECT u.username INTO username FROM app_public.user u WHERE id = account.user_id; |
| 209 | + |
| 210 | + IF account.password_hash = crypt(password, account.password_hash) |
| 211 | + THEN |
| 212 | + RETURN (':DATABASE_VISITOR', account.user_id, username, |
| 213 | + extract(EPOCH FROM (now() + INTERVAL '2 days')))::app_public.jwt_token; |
| 214 | + ELSE |
| 215 | + RETURN NULL; |
| 216 | + END IF; |
| 217 | +END; |
| 218 | +$$ LANGUAGE plpgsql STRICT |
| 219 | + SECURITY DEFINER; |
| 220 | + |
| 221 | +COMMENT ON FUNCTION app_public.authenticate(citext, text) IS 'Creates a JWT token that will securely identify a user and give them certain permissions. This token expires in 2 days.'; |
| 222 | + |
| 223 | +--! split: 0070-register-user.sql |
| 224 | +CREATE OR REPLACE FUNCTION app_public.register_user(username citext, |
| 225 | + password text) RETURNS app_public.jwt_token AS |
| 226 | +$$ |
| 227 | +DECLARE u app_public.user; |
| 228 | +BEGIN |
| 229 | + INSERT INTO app_public.user (username) |
| 230 | + VALUES (username) |
| 231 | + RETURNING * INTO u; |
| 232 | + |
| 233 | + UPDATE app_private.user_secrets us |
| 234 | + SET password_hash = crypt(password, gen_salt('bf')) |
| 235 | + WHERE user_id = u.id; |
| 236 | + |
| 237 | + RETURN app_public.authenticate(u.username::citext, password); |
| 238 | +END; |
| 239 | +$$ LANGUAGE plpgsql STRICT |
| 240 | + SECURITY DEFINER; |
0 commit comments