Skip to content

Commit

Permalink
user table schema
Browse files Browse the repository at this point in the history
  • Loading branch information
pvighi committed Feb 3, 2025
1 parent 73f9278 commit 4e61044
Showing 1 changed file with 43 additions and 0 deletions.
43 changes: 43 additions & 0 deletions db/migrations/V2025020311210__db_users_schema.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
-- hash combination of private id with salt to generate unique external id
CREATE FUNCTION gu_generate_identifier_with_salt(private_uuid UUID, salt VARCHAR) RETURNS VARCHAR
LANGUAGE SQL
IMMUTABLE
RETURNS NULL ON NULL INPUT
RETURN encode(sha256((private_uuid || salt)::bytea), 'hex');

CREATE FUNCTION gu_google_tag_id(private_uuid UUID) RETURNS VARCHAR
LANGUAGE SQL
IMMUTABLE
RETURNS NULL ON NULL INPUT
-- the salts are not secrets, they are used to avoid sharing the private id with third parties
RETURN gu_generate_identifier_with_salt(private_uuid, 'c16a3672d5404771baa2e10668cc1285');

CREATE TABLE users (
id VARCHAR PRIMARY KEY,
okta_id VARCHAR UNIQUE NOT NULL,
username VARCHAR UNIQUE,
braze_uuid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(),
private_uuid UUID UNIQUE NOT NULL DEFAULT gen_random_uuid(),
google_tag_id VARCHAR UNIQUE NOT NULL
);

COMMENT ON COLUMN users.private_uuid IS 'private id used to generate external ids';
COMMENT ON COLUMN users.google_tag_id IS 'generated by the gu_before_insert_user_tr "before insert" trigger, do not provide manually';

CREATE OR REPLACE FUNCTION gu_before_insert_user_fn()
RETURNS TRIGGER
LANGUAGE PLPGSQL
AS
$$
BEGIN
NEW.google_tag_id = gu_google_tag_id(NEW.private_uuid);
RETURN NEW;
END;
$$;

CREATE TRIGGER gu_before_insert_user_tr
BEFORE INSERT
ON users
FOR EACH ROW
EXECUTE FUNCTION gu_before_insert_user_fn();

0 comments on commit 4e61044

Please sign in to comment.