-
Notifications
You must be signed in to change notification settings - Fork 5
/
Copy pathdatabase-setup.sql
283 lines (254 loc) · 10.3 KB
/
database-setup.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
/*
Target Server Type : PostgreSQL
Target Server Version : 110009
File Encoding : 65001
*/
-- ----------------------------
-- Extension pgcrypto
-- ----------------------------
CREATE EXTENSION IF NOT EXISTS pgcrypto;
-- ----------------------------
-- Function structure for generate_snowflake
-- ----------------------------
CREATE OR REPLACE FUNCTION "public"."generate_snowflake"(IN "seq" text, OUT "snowflake" int8)
RETURNS "pg_catalog"."int8" AS $BODY$
DECLARE
our_epoch bigint := 1314220021721;
seq_id bigint;
now_millis bigint;
-- the id of this DB shard, must be set for each
-- schema shard you have - you could pass this as a parameter too
shard_id int := 1;
BEGIN
SELECT nextval(seq) % 1024 INTO seq_id;
SELECT FLOOR(EXTRACT(EPOCH FROM clock_timestamp()) * 1000) INTO now_millis;
snowflake := (now_millis - our_epoch) << 23;
snowflake := snowflake | (shard_id << 10);
snowflake := snowflake | (seq_id);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
-- ----------------------------
-- Function structure for random_string
-- ----------------------------
CREATE OR REPLACE FUNCTION "public"."random_string"("length" int4)
RETURNS "pg_catalog"."varchar" AS $BODY$
declare
chars text[] := '{0,1,2,3,4,5,6,7,8,9,A,B,C,D,E,F,G,H,I,J,K,L,M,N,O,P,Q,R,S,T,U,V,W,X,Y,Z,a,b,c,d,e,f,g,h,i,j,k,l,m,n,o,p,q,r,s,t,u,v,w,x,y,z}';
result varchar := '';
i integer := 0;
begin
for i in 1..length loop
result := result || chars[1+random()*(array_length(chars, 1)-1)];
end loop;
return result;
end;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
-- ----------------------------
-- Type structure for GrantResult
-- ----------------------------
DROP TYPE IF EXISTS "public"."GrantResult";
CREATE TYPE "public"."GrantResult" AS ENUM (
'GRANTED',
'DENIED',
'REVOKED'
);
-- ----------------------------
-- Sequence structure for apps_id_sequence
-- ----------------------------
DROP SEQUENCE IF EXISTS "public"."apps_id_sequence";
CREATE SEQUENCE "public"."apps_id_sequence"
INCREMENT 1
MINVALUE 1
MAXVALUE 9223372036854775807
START 1
CACHE 1;
-- ----------------------------
-- Sequence structure for apps_secret_sequence
-- ----------------------------
DROP SEQUENCE IF EXISTS "public"."apps_secret_sequence";
CREATE SEQUENCE "public"."apps_secret_sequence"
INCREMENT 1
MINVALUE 1
MAXVALUE 9223372036854775807
START 1
CACHE 1;
-- ----------------------------
-- Sequence structure for grants_id_sequence
-- ----------------------------
DROP SEQUENCE IF EXISTS "public"."grants_id_sequence";
CREATE SEQUENCE "public"."grants_id_sequence"
INCREMENT 1
MINVALUE 1
MAXVALUE 9223372036854775807
START 1
CACHE 1;
-- ----------------------------
-- Sequence structure for icons_id_sequence
-- ----------------------------
DROP SEQUENCE IF EXISTS "public"."icons_id_sequence";
CREATE SEQUENCE "public"."icons_id_sequence"
INCREMENT 1
MINVALUE 1
MAXVALUE 9223372036854775807
START 1
CACHE 1;
-- ----------------------------
-- Table structure for accounts
-- ----------------------------
DROP TABLE IF EXISTS "public"."accounts";
CREATE TABLE "public"."accounts" (
"id" varchar(32) COLLATE "pg_catalog"."default" NOT NULL,
"name" varchar(128) COLLATE "pg_catalog"."default" NOT NULL,
"email" varchar(255) COLLATE "pg_catalog"."default",
"email_pending" varchar(255) COLLATE "pg_catalog"."default",
"email_pending_since" timestamptz(0),
"last_login" timestamptz(0)
);
-- ----------------------------
-- Table structure for apps
-- ----------------------------
DROP TABLE IF EXISTS "public"."apps";
CREATE TABLE "public"."apps" (
"id" int8 NOT NULL DEFAULT generate_snowflake('public.apps_id_sequence'::text),
"owner" varchar(32) COLLATE "pg_catalog"."default" NOT NULL,
"name" varchar(128) COLLATE "pg_catalog"."default" NOT NULL,
"description" varchar(512) COLLATE "pg_catalog"."default",
"website" varchar(512) COLLATE "pg_catalog"."default" NOT NULL DEFAULT '[]'::character varying,
"icon" int8,
"redirect_uris" jsonb NOT NULL DEFAULT '[]'::jsonb,
-- FIXME: Generate secret similar to new access and exchange tokens
"secret" varchar(255) COLLATE "pg_catalog"."default" DEFAULT concat(random_string(8), '.', generate_snowflake('public.apps_secret_sequence'::text), '.', random_string(4)),
"verified" bool NOT NULL DEFAULT false,
"deleted" bool NOT NULL DEFAULT false,
"created" timestamptz(0) NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- ----------------------------
-- Table structure for grants
-- ----------------------------
DROP TABLE IF EXISTS "public"."grants";
CREATE TABLE "public"."grants" (
"id" int8 NOT NULL DEFAULT generate_snowflake('public.grants_id_sequence'::text),
"app" int8 NOT NULL,
"account" varchar(32) COLLATE "pg_catalog"."default" NOT NULL,
"result" "public"."GrantResult",
"scopes" jsonb NOT NULL,
"response_type" varchar(128) COLLATE "pg_catalog"."default" NOT NULL,
"state" varchar(128) COLLATE "pg_catalog"."default",
"access_token" varchar(37) COLLATE "pg_catalog"."default",
"exchange_token" varchar(37) COLLATE "pg_catalog"."default",
"redirect_uri" varchar(255) COLLATE "pg_catalog"."default" NOT NULL,
"issued" timestamptz(0) NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- ----------------------------
-- Table structure for icons
-- ----------------------------
DROP TABLE IF EXISTS "public"."icons";
CREATE TABLE "public"."icons" (
"id" int8 NOT NULL DEFAULT generate_snowflake('public.icons_id_sequence'::text),
"optimized" bytea,
"original" bytea,
"duplicate_of" int8,
"added_by" varchar(32) COLLATE "pg_catalog"."default" NOT NULL,
"added" timestamptz(0) NOT NULL DEFAULT CURRENT_TIMESTAMP
);
-- ----------------------------
-- Table structure for otps
-- ----------------------------
DROP TABLE IF EXISTS "public"."otps";
CREATE TABLE "public"."otps" (
"account" varchar(32) COLLATE "pg_catalog"."default" NOT NULL,
"code" int4 NOT NULL,
"issued" timestamptz(0) DEFAULT CURRENT_TIMESTAMP
);
COMMENT ON TABLE "public"."otps" IS 'OTPs or One-Time-Passwords';
-- ----------------------------
-- Table structure for sessions
-- ----------------------------
DROP TABLE IF EXISTS "public"."sessions";
CREATE TABLE "public"."sessions" (
"sid" varchar COLLATE "pg_catalog"."default" NOT NULL,
"sess" json NOT NULL,
"expire" timestamp(6) NOT NULL
);
-- ----------------------------
-- Alter sequences owned by
-- ----------------------------
ALTER SEQUENCE "public"."apps_id_sequence"
OWNED BY "public"."apps"."id";
ALTER SEQUENCE "public"."apps_secret_sequence"
OWNED BY "public"."apps"."secret";
ALTER SEQUENCE "public"."grants_id_sequence"
OWNED BY "public"."grants"."id";
ALTER SEQUENCE "public"."icons_id_sequence"
OWNED BY "public"."icons"."id";
-- ----------------------------
-- Primary Key structure for table accounts
-- ----------------------------
ALTER TABLE "public"."accounts" ADD CONSTRAINT "accounts_pkey" PRIMARY KEY ("id");
-- ----------------------------
-- Primary Key structure for table apps
-- ----------------------------
ALTER TABLE "public"."apps" ADD CONSTRAINT "applications_pkey" PRIMARY KEY ("id");
-- ----------------------------
-- Indexes structure for table grants
-- ----------------------------
CREATE UNIQUE INDEX "grants_access_token_idx" ON "public"."grants" USING btree (
"access_token" COLLATE "pg_catalog"."default" "pg_catalog"."text_ops" ASC NULLS LAST
);
CREATE UNIQUE INDEX "grants_exchange_token_idx" ON "public"."grants" USING btree (
"exchange_token" COLLATE "pg_catalog"."default" "pg_catalog"."text_ops" ASC NULLS LAST
);
-- ----------------------------
-- Primary Key structure for table grants
-- ----------------------------
ALTER TABLE "public"."grants" ADD CONSTRAINT "grants_pkey" PRIMARY KEY ("id");
-- ----------------------------
-- Indexes structure for table icons
-- ----------------------------
CREATE UNIQUE INDEX "icons_digest_idx" ON "public"."icons" USING btree (
digest(original, 'sha256'::text) "pg_catalog"."bytea_ops" ASC NULLS LAST
);
CREATE INDEX "icons_original_idx" ON "public"."icons" USING hash (
"original" "pg_catalog"."bytea_ops"
);
-- ----------------------------
-- Primary Key structure for table icons
-- ----------------------------
ALTER TABLE "public"."icons" ADD CONSTRAINT "images_pkey" PRIMARY KEY ("id");
-- ----------------------------
-- Primary Key structure for table otps
-- ----------------------------
ALTER TABLE "public"."otps" ADD CONSTRAINT "otps_pkey" PRIMARY KEY ("account");
-- ----------------------------
-- Indexes structure for table sessions
-- ----------------------------
CREATE INDEX "IDX_session_expire" ON "public"."sessions" USING btree (
"expire" "pg_catalog"."timestamp_ops" ASC NULLS LAST
);
-- ----------------------------
-- Primary Key structure for table sessions
-- ----------------------------
ALTER TABLE "public"."sessions" ADD CONSTRAINT "session_pkey" PRIMARY KEY ("sid");
-- ----------------------------
-- Foreign Keys structure for table apps
-- ----------------------------
ALTER TABLE "public"."apps" ADD CONSTRAINT "applications_icon_fkey" FOREIGN KEY ("icon") REFERENCES "public"."icons" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
ALTER TABLE "public"."apps" ADD CONSTRAINT "applications_owner_fkey" FOREIGN KEY ("owner") REFERENCES "public"."accounts" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
-- ----------------------------
-- Foreign Keys structure for table grants
-- ----------------------------
ALTER TABLE "public"."grants" ADD CONSTRAINT "grants_account_fkey" FOREIGN KEY ("account") REFERENCES "public"."accounts" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
ALTER TABLE "public"."grants" ADD CONSTRAINT "grants_app_fkey" FOREIGN KEY ("app") REFERENCES "public"."apps" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
-- ----------------------------
-- Foreign Keys structure for table icons
-- ----------------------------
ALTER TABLE "public"."icons" ADD CONSTRAINT "images_added_by_fkey" FOREIGN KEY ("added_by") REFERENCES "public"."accounts" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
ALTER TABLE "public"."icons" ADD CONSTRAINT "images_duplicate_of_fkey" FOREIGN KEY ("duplicate_of") REFERENCES "public"."icons" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;
-- ----------------------------
-- Foreign Keys structure for table otps
-- ----------------------------
ALTER TABLE "public"."otps" ADD CONSTRAINT "otps_account_fkey" FOREIGN KEY ("account") REFERENCES "public"."accounts" ("id") ON DELETE NO ACTION ON UPDATE NO ACTION;