CREATE TABLE IF NOT EXISTS referral_codes ( code VARCHAR(255) NOT NULL, user_id BIGINT NOT NULL, is_active BOOLEAN NOT NULL DEFAULT TRUE, created_at bigint NOT NULL DEFAULT now_utc_micro_seconds(), PRIMARY KEY (code) ); --- Ensure that only one active referral code is allowed per user CREATE UNIQUE INDEX ON referral_codes (user_id, is_active) WHERE (referral_codes.is_active = TRUE); CREATE TABLE IF NOT EXISTS referral_tracking ( invitor_id bigint NOT NULL, invitee_id bigint NOT NULL, plan_type text NOT NULL check ( plan_type in ('10_GB_ON_UPGRADE')), invitee_on_paid_plan bool default false, created_at bigint NOT NULL DEFAULT now_utc_micro_seconds() ); --- Add unique index on invitor_id and invitee_id column in referral_tracking table to ensure only -- one entry per invitee is allowed CREATE UNIQUE INDEX IF NOT EXISTS referral_tracking_invitee_id_idx ON referral_tracking (invitee_id); CREATE TABLE IF NOT EXISTS storage_bonus ( --- bonus_id is a unique identifier for each storage bonus. It is generated by the application layer. --- The format of the bonus_id will depend on the type of bonus. --- For example, if the type is 'REFERRAL', the bonus_id can be (REFERRAL-inviteeId). This will ensure that there's -- only one bonus for a given invitee. Similarly for other types, the application layer decide bonus_id format.\ bonus_id text primary key NOT NULL, type text NOT NULL CHECK (type IN ('REFERRAL', 'SIGN_UP', 'ANNIVERSARY')), user_id bigint NOT NULL, storage bigint NOT NULL, valid_till bigint NOT NULL DEFAULT 0, revoke_reason text, is_revoked boolean NOT NULL DEFAULT FALSE, created_at bigint NOT NULL DEFAULT now_utc_micro_seconds(), updated_at bigint NOT NULL DEFAULT now_utc_micro_seconds() ); CREATE INDEX IF NOT EXISTS storage_bonus_user_id_idx ON storage_bonus (user_id);