stacker.news/prisma/migrations/20240426144110_email_hash/migration.sql

44 lines
1.7 KiB
MySQL
Raw Normal View History

Store hashed and salted email addresses (#1111) * first pass of hashing user emails * use salt * add a salt to .env.development (prod salt needs to be kept a secret) * move `hashEmail` util to a new util module * trigger a one-time job to migrate existing emails via the worker so we can use the salt from an env var * move newsletter signup move newsletter signup to prisma adapter create user with email code path so we can still auto-enroll email accounts without having to persist the email address in plaintext * remove `email` from api key session lookup query * drop user email index before dropping column * restore email column, just null values instead * fix function name * fix salt and hash raw sql statement * update auth methods email type in typedefs from str to bool * remove todo comment * lowercase email before hashing during migration * check for emailHash and email to accommodate migration window update our lookups to check for a matching emailHash, and then a matching email, in that order, to accommodate the case that a user tries to login via email while the migration is running, and their account has not yet been migrated also update sndev to have a command `./sndev email` to launch the mailhog inbox in your browser also update `./sndev login` to hash the generated email address and insert it into the db record * update sndev help * update awards.csv * update the hack in next-auth to re-use the email supplied on input to `getUserByEmail` * consolidate console.error logs * create generic open command --------- Co-authored-by: Keyan <34140557+huumn@users.noreply.github.com> Co-authored-by: keyan <keyan.kousha+huumn@gmail.com>
2024-05-04 23:06:15 +00:00
/*
Warnings:
- A unique constraint covering the columns `[emailHash]` on the table `users` will be added. If there are existing duplicate values, this will fail.
*/
-- AlterTable
ALTER TABLE "users" ADD COLUMN "emailHash" TEXT;
-- CreateIndex
CREATE UNIQUE INDEX "users.email_hash_unique" ON "users"("emailHash");
-- hack ... prisma doesn't know about our other schemas (e.g. pgboss)
-- and this is only really a problem on their "shadow database"
-- so we catch the exception it throws and ignore it
CREATE OR REPLACE FUNCTION submit_migrate_existing_user_emails_job() RETURNS void AS $$
BEGIN
-- Submit a job to salt and hash emails after the updated worker has spun-up
INSERT INTO pgboss.job (name, data, priority, startafter, expirein)
SELECT 'saltAndHashEmails', jsonb_build_object(), -100, now() + interval '10 minutes', interval '1 day';
EXCEPTION WHEN OTHERS THEN
-- catch the exception for prisma dev execution, but do nothing with it
END;
$$ LANGUAGE plpgsql;
-- execute the function once to submit the one-time job
SELECT submit_migrate_existing_user_emails_job();
-- then drop it since we don't need it anymore
DROP FUNCTION submit_migrate_existing_user_emails_job();
-- function that accepts a salt and migrates all existing emails using the salt then hashing the salted email
CREATE OR REPLACE FUNCTION migrate_existing_user_emails(salt TEXT) RETURNS void AS $$
BEGIN
UPDATE "users"
SET "emailHash" = encode(digest(LOWER("email") || salt, 'sha256'), 'hex')
WHERE "email" IS NOT NULL;
-- then wipe the email values
UPDATE "users"
SET email = NULL;
END;
$$ LANGUAGE plpgsql;