|
| 1 | +ALTER SYSTEM SET wal_level='logical'; |
| 2 | +ALTER SYSTEM SET max_wal_senders='10'; |
| 3 | +ALTER SYSTEM SET max_replication_slots='10'; |
| 4 | + |
| 5 | +-- Create the Replication publication |
| 6 | +CREATE PUBLICATION supabase_realtime FOR ALL TABLES; |
| 7 | + |
| 8 | +-- Create a second schema |
| 9 | +CREATE SCHEMA personal; |
| 10 | + |
| 11 | +-- USERS |
| 12 | +CREATE TYPE public.user_status AS ENUM ('ONLINE', 'OFFLINE'); |
| 13 | +CREATE TABLE public.users ( |
| 14 | + username text primary key, |
| 15 | + inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 16 | + updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 17 | + data jsonb DEFAULT null, |
| 18 | + age_range int4range DEFAULT null, |
| 19 | + status user_status DEFAULT 'ONLINE'::public.user_status, |
| 20 | + catchphrase tsvector DEFAULT null |
| 21 | +); |
| 22 | +ALTER TABLE public.users REPLICA IDENTITY FULL; -- Send "previous data" to supabase |
| 23 | +COMMENT ON COLUMN public.users.data IS 'For unstructured data and prototyping.'; |
| 24 | + |
| 25 | +-- CHANNELS |
| 26 | +CREATE TABLE public.channels ( |
| 27 | + id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, |
| 28 | + inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 29 | + updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 30 | + data jsonb DEFAULT null, |
| 31 | + slug text |
| 32 | +); |
| 33 | +ALTER TABLE public.users REPLICA IDENTITY FULL; -- Send "previous data" to supabase |
| 34 | +COMMENT ON COLUMN public.channels.data IS 'For unstructured data and prototyping.'; |
| 35 | + |
| 36 | +-- MESSAGES |
| 37 | +CREATE TABLE public.messages ( |
| 38 | + id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY, |
| 39 | + inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 40 | + updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 41 | + data jsonb DEFAULT null, |
| 42 | + message text, |
| 43 | + username text REFERENCES users NOT NULL, |
| 44 | + channel_id bigint REFERENCES channels NOT NULL |
| 45 | +); |
| 46 | +ALTER TABLE public.messages REPLICA IDENTITY FULL; -- Send "previous data" to supabase |
| 47 | +COMMENT ON COLUMN public.messages.data IS 'For unstructured data and prototyping.'; |
| 48 | + |
| 49 | +-- STORED FUNCTION |
| 50 | +CREATE FUNCTION public.get_status(name_param text) |
| 51 | +RETURNS user_status AS $$ |
| 52 | + SELECT status from users WHERE username=name_param; |
| 53 | +$$ LANGUAGE SQL IMMUTABLE; |
| 54 | + |
| 55 | +-- SECOND SCHEMA USERS |
| 56 | +CREATE TYPE personal.user_status AS ENUM ('ONLINE', 'OFFLINE'); |
| 57 | +CREATE TABLE personal.users( |
| 58 | + username text primary key, |
| 59 | + inserted_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 60 | + updated_at timestamp without time zone DEFAULT timezone('utc'::text, now()) NOT NULL, |
| 61 | + data jsonb DEFAULT null, |
| 62 | + age_range int4range DEFAULT null, |
| 63 | + status user_status DEFAULT 'ONLINE'::public.user_status |
| 64 | +); |
| 65 | + |
| 66 | +-- SECOND SCHEMA STORED FUNCTION |
| 67 | +CREATE FUNCTION personal.get_status(name_param text) |
| 68 | +RETURNS user_status AS $$ |
| 69 | + SELECT status from users WHERE username=name_param; |
| 70 | +$$ LANGUAGE SQL IMMUTABLE; |
| 71 | + |
| 72 | + |
| 73 | +CREATE SCHEMA IF NOT EXISTS auth AUTHORIZATION postgres; |
| 74 | +-- auth.users definition |
| 75 | +CREATE TABLE auth.users ( |
| 76 | + instance_id uuid NULL, |
| 77 | + id uuid NOT NULL, |
| 78 | + aud varchar(255) NULL, |
| 79 | + "role" varchar(255) NULL, |
| 80 | + email varchar(255) NULL, |
| 81 | + encrypted_password varchar(255) NULL, |
| 82 | + confirmed_at timestamptz NULL, |
| 83 | + invited_at timestamptz NULL, |
| 84 | + confirmation_token varchar(255) NULL, |
| 85 | + confirmation_sent_at timestamptz NULL, |
| 86 | + recovery_token varchar(255) NULL, |
| 87 | + recovery_sent_at timestamptz NULL, |
| 88 | + email_change_token varchar(255) NULL, |
| 89 | + email_change varchar(255) NULL, |
| 90 | + email_change_sent_at timestamptz NULL, |
| 91 | + last_sign_in_at timestamptz NULL, |
| 92 | + raw_app_meta_data jsonb NULL, |
| 93 | + raw_user_meta_data jsonb NULL, |
| 94 | + is_super_admin bool NULL, |
| 95 | + created_at timestamptz NULL, |
| 96 | + updated_at timestamptz NULL, |
| 97 | + CONSTRAINT users_pkey PRIMARY KEY (id) |
| 98 | +); |
| 99 | +CREATE INDEX users_instance_id_email_idx ON auth.users USING btree (instance_id, email); |
| 100 | +CREATE INDEX users_instance_id_idx ON auth.users USING btree (instance_id); |
| 101 | +-- auth.refresh_tokens definition |
| 102 | +CREATE TABLE auth.refresh_tokens ( |
| 103 | + instance_id uuid NULL, |
| 104 | + id bigserial NOT NULL, |
| 105 | + "token" varchar(255) NULL, |
| 106 | + user_id varchar(255) NULL, |
| 107 | + revoked bool NULL, |
| 108 | + created_at timestamptz NULL, |
| 109 | + updated_at timestamptz NULL, |
| 110 | + CONSTRAINT refresh_tokens_pkey PRIMARY KEY (id) |
| 111 | +); |
| 112 | +CREATE INDEX refresh_tokens_instance_id_idx ON auth.refresh_tokens USING btree (instance_id); |
| 113 | +CREATE INDEX refresh_tokens_instance_id_user_id_idx ON auth.refresh_tokens USING btree (instance_id, user_id); |
| 114 | +CREATE INDEX refresh_tokens_token_idx ON auth.refresh_tokens USING btree (token); |
| 115 | +-- auth.instances definition |
| 116 | +CREATE TABLE auth.instances ( |
| 117 | + id uuid NOT NULL, |
| 118 | + uuid uuid NULL, |
| 119 | + raw_base_config text NULL, |
| 120 | + created_at timestamptz NULL, |
| 121 | + updated_at timestamptz NULL, |
| 122 | + CONSTRAINT instances_pkey PRIMARY KEY (id) |
| 123 | +); |
| 124 | +-- auth.audit_log_entries definition |
| 125 | +CREATE TABLE auth.audit_log_entries ( |
| 126 | + instance_id uuid NULL, |
| 127 | + id uuid NOT NULL, |
| 128 | + payload json NULL, |
| 129 | + created_at timestamptz NULL, |
| 130 | + CONSTRAINT audit_log_entries_pkey PRIMARY KEY (id) |
| 131 | +); |
| 132 | +CREATE INDEX audit_logs_instance_id_idx ON auth.audit_log_entries USING btree (instance_id); |
| 133 | +-- auth.schema_migrations definition |
| 134 | +CREATE TABLE auth.schema_migrations ( |
| 135 | + "version" varchar(255) NOT NULL, |
| 136 | + CONSTRAINT schema_migrations_pkey PRIMARY KEY ("version") |
| 137 | +); |
| 138 | +INSERT INTO auth.schema_migrations (version) |
| 139 | +VALUES ('20171026211738'), |
| 140 | + ('20171026211808'), |
| 141 | + ('20171026211834'), |
| 142 | + ('20180103212743'), |
| 143 | + ('20180108183307'), |
| 144 | + ('20180119214651'), |
| 145 | + ('20180125194653'); |
| 146 | +-- Gets the User ID from the request cookie |
| 147 | +create or replace function auth.uid() returns uuid as $$ |
| 148 | + select nullif(current_setting('request.jwt.claim.sub', true), '')::uuid; |
| 149 | +$$ language sql stable; |
| 150 | +-- Gets the User ID from the request cookie |
| 151 | +create or replace function auth.role() returns text as $$ |
| 152 | + select nullif(current_setting('request.jwt.claim.role', true), '')::text; |
| 153 | +$$ language sql stable; |
| 154 | +GRANT ALL PRIVILEGES ON SCHEMA auth TO postgres; |
| 155 | +GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA auth TO postgres; |
| 156 | +GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA auth TO postgres; |
| 157 | +ALTER USER postgres SET search_path = "auth"; |
0 commit comments