forked from primocms/primo
-
Notifications
You must be signed in to change notification settings - Fork 0
/
primo_schema.sql
487 lines (415 loc) · 13.6 KB
/
primo_schema.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
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
--
-- Name: collaborators; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."collaborators" (
"id" bigint NOT NULL,
"created_at" timestamp with time zone DEFAULT "now"(),
"site" "uuid",
"user" "uuid" NOT NULL,
"role" "text" NOT NULL
);
ALTER TABLE
"public"."collaborators" OWNER TO "postgres";
--
-- Name: collaborators_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
ALTER TABLE
"public"."collaborators"
ALTER COLUMN
"id"
ADD
GENERATED BY DEFAULT AS IDENTITY (
SEQUENCE NAME "public"."collaborators_id_seq" START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1
);
--
-- Name: config; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."config" (
"id" "text" NOT NULL,
"value" "text",
"options" "jsonb",
"created_at" timestamp with time zone DEFAULT "now"()
);
ALTER TABLE
"public"."config" OWNER TO "postgres";
--
-- Name: invitations; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."invitations" (
"created_at" timestamp with time zone DEFAULT "now"(),
"email" "text",
"site" "uuid",
"inviter_email" "text",
"id" "uuid" DEFAULT "extensions"."uuid_generate_v4"() NOT NULL,
"role" "text" NOT NULL,
"server_invitation" boolean
);
ALTER TABLE
"public"."invitations" OWNER TO "postgres";
INSERT INTO
public.config (id, value, options, created_at)
VALUES
('github_token', null, null, now());
--
-- Name: pages; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."pages" (
"code" "jsonb" DEFAULT '{"js": "", "css": "", "html": {"head": "", "below": ""}}' :: "jsonb",
"name" "text",
"fields" "jsonb" DEFAULT '[]' :: "jsonb",
"created_at" timestamp with time zone DEFAULT "now"(),
"url" "text",
"content" "jsonb" DEFAULT '{}' :: "jsonb" NOT NULL,
"id" "uuid" DEFAULT "extensions"."uuid_generate_v4"() NOT NULL,
"site" "uuid" NOT NULL,
"parent" "uuid"
);
ALTER TABLE
"public"."pages" OWNER TO "postgres";
--
-- Name: sections; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."sections" (
"content" "jsonb" DEFAULT '{"en": {}}' :: "jsonb" NOT NULL,
"created_at" timestamp with time zone DEFAULT "now"(),
"index" smallint DEFAULT '1' :: smallint NOT NULL,
"id" "uuid" DEFAULT "extensions"."uuid_generate_v4"() NOT NULL,
"page" "uuid" NOT NULL,
"symbol" "uuid" NOT NULL
);
ALTER TABLE
"public"."sections" OWNER TO "postgres";
-- Enable realtime for 'sections' table
alter publication supabase_realtime
add
table sections;
--
-- Name: server_members; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."server_members" (
"id" bigint NOT NULL,
"user" "uuid",
"role" "text" DEFAULT 'DEV' :: "text",
"created_at" timestamp with time zone DEFAULT "now"(),
"admin" boolean DEFAULT false
);
ALTER TABLE
"public"."server_members" OWNER TO "postgres";
--
-- Name: server_members_id_seq; Type: SEQUENCE; Schema: public; Owner: postgres
--
ALTER TABLE
"public"."server_members"
ALTER COLUMN
"id"
ADD
GENERATED BY DEFAULT AS IDENTITY (
SEQUENCE NAME "public"."server_members_id_seq" START WITH 1 INCREMENT BY 1 NO MINVALUE NO MAXVALUE CACHE 1
);
--
-- Name: sites; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."sites" (
"id" "uuid" NOT NULL,
"name" "text",
"active_deployment" "jsonb",
"created_at" timestamp with time zone DEFAULT "now"(),
"code" "jsonb" DEFAULT '{"js": "", "css": "", "html": {"head": "", "below": ""}}' :: "jsonb" NOT NULL,
"fields" "jsonb" DEFAULT '[]' :: "jsonb" NOT NULL,
"content" "jsonb" DEFAULT '{}' :: "jsonb" NOT NULL,
"url" "text" NOT NULL
);
ALTER TABLE
"public"."sites" OWNER TO "postgres";
--
-- Name: symbols; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."symbols" (
"name" "text",
"code" "jsonb" DEFAULT '{"js": "", "css": "", "html": ""}' :: "jsonb" NOT NULL,
"fields" "jsonb" DEFAULT '[]' :: "jsonb" NOT NULL,
"content" "jsonb" DEFAULT '{}' :: "jsonb",
"created_at" timestamp with time zone DEFAULT "now"(),
"id" "uuid" DEFAULT "extensions"."uuid_generate_v4"() NOT NULL,
"site" "uuid" NOT NULL,
"index" smallint DEFAULT '1' :: smallint NOT NULL
);
ALTER TABLE
"public"."symbols" OWNER TO "postgres";
--
-- Name: users; Type: TABLE; Schema: public; Owner: postgres
--
CREATE TABLE "public"."users" (
"email" "text",
"created_at" timestamp with time zone DEFAULT "now"(),
"id" "uuid" NOT NULL
);
ALTER TABLE
"public"."users" OWNER TO "postgres";
--
-- Name: collaborators collaborators_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."collaborators"
ADD
CONSTRAINT "collaborators_pkey" PRIMARY KEY ("id");
--
-- Name: config config_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."config"
ADD
CONSTRAINT "config_pkey" PRIMARY KEY ("id");
--
-- Name: invitations invitations_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."invitations"
ADD
CONSTRAINT "invitations_pkey" PRIMARY KEY ("id");
--
-- Name: pages pages_id_key; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."pages"
ADD
CONSTRAINT "pages_id_key" UNIQUE ("id");
--
-- Name: pages pages_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."pages"
ADD
CONSTRAINT "pages_pkey" PRIMARY KEY ("id");
--
-- Name: sections sections_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."sections"
ADD
CONSTRAINT "sections_pkey" PRIMARY KEY ("id");
--
-- Name: server_members server_members_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."server_members"
ADD
CONSTRAINT "server_members_pkey" PRIMARY KEY ("id");
--
-- Name: sites sites_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."sites"
ADD
CONSTRAINT "sites_pkey" PRIMARY KEY ("id");
--
-- Name: sites sites_url_key; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."sites"
ADD
CONSTRAINT "sites_url_key" UNIQUE ("url");
--
-- Name: symbols symbols_id_key; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."symbols"
ADD
CONSTRAINT "symbols_id_key" UNIQUE ("id");
--
-- Name: symbols symbols_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."symbols"
ADD
CONSTRAINT "symbols_pkey" PRIMARY KEY ("id");
--
-- Name: users users_pkey; Type: CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."users"
ADD
CONSTRAINT "users_pkey" PRIMARY KEY ("id");
--
-- Name: collaborators collaborators_site_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."collaborators"
ADD
CONSTRAINT "collaborators_site_fkey" FOREIGN KEY ("site") REFERENCES "public"."sites"("id");
--
-- Name: collaborators collaborators_user_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."collaborators"
ADD
CONSTRAINT "collaborators_user_fkey" FOREIGN KEY ("user") REFERENCES "public"."users"("id");
--
-- Name: invitations invitations_site_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."invitations"
ADD
CONSTRAINT "invitations_site_fkey" FOREIGN KEY ("site") REFERENCES "public"."sites"("id");
--
-- Name: pages pages_parent_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."pages"
ADD
CONSTRAINT "pages_parent_fkey" FOREIGN KEY ("parent") REFERENCES "public"."pages"("id");
--
-- Name: pages pages_site_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."pages"
ADD
CONSTRAINT "pages_site_fkey" FOREIGN KEY ("site") REFERENCES "public"."sites"("id");
--
-- Name: sections sections_page_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."sections"
ADD
CONSTRAINT "sections_page_fkey" FOREIGN KEY ("page") REFERENCES "public"."pages"("id");
--
-- Name: sections sections_symbol_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."sections"
ADD
CONSTRAINT "sections_symbol_fkey" FOREIGN KEY ("symbol") REFERENCES "public"."symbols"("id");
--
-- Name: server_members server_members_user_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."server_members"
ADD
CONSTRAINT "server_members_user_fkey" FOREIGN KEY ("user") REFERENCES "public"."users"("id") ON DELETE CASCADE;
--
-- Name: symbols symbols_site_fkey; Type: FK CONSTRAINT; Schema: public; Owner: postgres
--
ALTER TABLE
ONLY "public"."symbols"
ADD
CONSTRAINT "symbols_site_fkey" FOREIGN KEY ("site") REFERENCES "public"."sites"("id");
-- Set Row Level Security
ALTER TABLE
public.collaborators ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.config ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.invitations ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.pages ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.sections ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.server_members ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.sites ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.symbols ENABLE ROW LEVEL SECURITY;
ALTER TABLE
public.users ENABLE ROW LEVEL SECURITY;
-- Set RLS Policy
CREATE POLICY "Enable ALL for authenticated users" ON "public"."collaborators" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."config" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."invitations" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."pages" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."sections" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."server_members" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."sites" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."symbols" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
CREATE POLICY "Enable ALL for authenticated users" ON "public"."users" AS PERMISSIVE FOR ALL TO authenticated USING (true) WITH CHECK (true);
-- Create storage buckets for site files and images
INSERT INTO
storage.buckets (id, name, public)
VALUES
('sites', 'sites', TRUE),
('images', 'images', TRUE);
-- Set storage security
CREATE POLICY "Public access to view sites" ON storage.objects FOR
SELECT
USING (((bucket_id = 'sites' :: text)));
CREATE POLICY "Give Authenticated users access to upload new sites" ON storage.objects FOR
INSERT
WITH CHECK (
(
(bucket_id = 'sites' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
CREATE POLICY "Give Authenticated users access to update sites" ON storage.objects FOR
UPDATE
USING (
(
(bucket_id = 'sites' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
CREATE POLICY "Give Authenticated users access to delete sites" ON storage.objects FOR DELETE USING (
(
(bucket_id = 'sites' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
-- Set storage security
CREATE POLICY "Public access to view images" ON storage.objects FOR
SELECT
USING (((bucket_id = 'images' :: text)));
CREATE POLICY "Give Authenticated users access to upload new images" ON storage.objects FOR
INSERT
WITH CHECK (
(
(bucket_id = 'images' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
CREATE POLICY "Give Authenticated users access to update images" ON storage.objects FOR
UPDATE
USING (
(
(bucket_id = 'images' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
CREATE POLICY "Give Authenticated users access to delete images" ON storage.objects FOR DELETE USING (
(
(bucket_id = 'images' :: text)
AND (auth.role() = 'authenticated' :: text)
)
);
-- helper functions
CREATE OR REPLACE FUNCTION page_search(search_terms text, site_url text)
RETURNS TABLE(id uuid, name text, url text, created_at timestamp with time zone) AS $$
BEGIN
RETURN QUERY
WITH RECURSIVE parent_urls AS (
SELECT
p.id,
ARRAY[p.url] AS urls
FROM pages p
INNER JOIN sites s ON p.site = s.id
WHERE p.parent IS NULL AND s.url = site_url
UNION ALL
SELECT
p.id,
pu.urls || p.url
FROM pages p
INNER JOIN sites s ON p.site = s.id
INNER JOIN parent_urls pu ON p.parent = pu.id
WHERE s.url = site_url
)
SELECT DISTINCT
p.id,
p.name,
ARRAY_TO_STRING(parent_urls.urls, '/', '/') AS url,
p.created_at
FROM pages p
INNER JOIN sites s ON p.site = s.id
INNER JOIN sections se ON p.id = se.page
INNER JOIN parent_urls ON p.id = parent_urls.id
WHERE s.url = site_url AND to_tsvector(se.content) @@ to_tsquery(search_terms);
END;
$$ LANGUAGE plpgsql;