Skip to content

Commit 92d0931

Browse files
committed
concept upsert functions
1 parent 9504ec5 commit 92d0931

File tree

3 files changed

+308
-1
lines changed

3 files changed

+308
-1
lines changed
Lines changed: 131 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,131 @@
1+
CREATE TYPE public.concept_local_input AS (
2+
-- concept columns
3+
epistemic_status public."EpistemicStatus",
4+
name character varying,
5+
description text,
6+
author_id bigint,
7+
created timestamp without time zone,
8+
last_modified timestamp without time zone,
9+
space_id bigint,
10+
schema_id bigint,
11+
literal_content jsonb,
12+
is_schema boolean,
13+
represented_by_id bigint,
14+
reference_content jsonb,
15+
-- local values
16+
author_local_id VARCHAR,
17+
represented_by_local_id VARCHAR,
18+
schema_represented_by_local_id VARCHAR,
19+
space_url VARCHAR,
20+
local_reference_content JSONB
21+
);
22+
23+
24+
CREATE OR REPLACE FUNCTION public.local_concept_to_db_concept(data public.concept_local_input) RETURNS public."Concept" LANGUAGE plpgsql STABLE AS $$
25+
DECLARE
26+
concept public."Concept"%ROWTYPE;
27+
reference_content JSONB := jsonb_build_object();
28+
key varchar;
29+
value JSONB;
30+
ref_single_val BIGINT;
31+
ref_array_val BIGINT[];
32+
BEGIN
33+
-- not fan of going through json, but not finding how to populate a record by a different shape record
34+
concept := jsonb_populate_record(NULL::public."Concept", to_jsonb(data));
35+
IF data.author_local_id IS NOT NULL THEN
36+
SELECT id FROM public."PlatformAccount"
37+
WHERE account_local_id = data.author_local_id INTO concept.author_id;
38+
END IF;
39+
IF data.represented_by_local_id IS NOT NULL THEN
40+
SELECT id FROM public."Content"
41+
WHERE source_local_id = data.represented_by_local_id INTO concept.represented_by_id;
42+
END IF;
43+
IF data.space_url IS NOT NULL THEN
44+
SELECT id FROM public."Space"
45+
WHERE url = data.space_url INTO concept.space_id;
46+
END IF;
47+
IF data.schema_represented_by_local_id IS NOT NULL THEN
48+
SELECT cpt.id FROM public."Concept" cpt
49+
JOIN public."Content" AS cnt ON cpt.represented_by_id = cnt.id
50+
WHERE cnt.source_local_id = data.schema_represented_by_local_id INTO concept.schema_id;
51+
END IF;
52+
IF data.local_reference_content IS NOT NULL THEN
53+
FOR key, value IN SELECT * FROM jsonb_each(data.local_reference_content) LOOP
54+
IF jsonb_typeof(value) = 'array' THEN
55+
WITH el AS (SELECT jsonb_array_elements_text(value) as x),
56+
ela AS (SELECT array_agg(x) AS a FROM el)
57+
SELECT array_agg(DISTINCT cpt.id) INTO STRICT ref_array_val
58+
FROM public."Concept" AS cpt
59+
JOIN public."Content" AS cnt ON (cpt.represented_by_id = cnt.id)
60+
JOIN ela ON (true) WHERE cnt.source_local_id = ANY(ela.a);
61+
reference_content := jsonb_set(reference_content, ARRAY[key], to_jsonb(ref_array_val));
62+
ELSIF jsonb_typeof(value) = 'string' THEN
63+
SELECT cpt.id INTO STRICT ref_single_val
64+
FROM public."Concept" AS cpt
65+
JOIN public."Content" AS cnt ON (cpt.represented_by_id = cnt.id)
66+
WHERE cnt.source_local_id = (value #>> '{}');
67+
reference_content := jsonb_set(reference_content, ARRAY[key], to_jsonb(ref_single_val));
68+
ELSE
69+
RAISE EXCEPTION 'Invalid value in local_reference_content % %', value, jsonb_typeof(value);
70+
END IF;
71+
END LOOP;
72+
SELECT reference_content INTO concept.reference_content;
73+
END IF;
74+
RETURN concept;
75+
END;
76+
$$;
77+
78+
79+
80+
CREATE OR REPLACE FUNCTION public.upsert_concepts(v_space_id bigint, data jsonb)
81+
RETURNS SETOF BIGINT
82+
LANGUAGE plpgsql
83+
AS $$
84+
DECLARE
85+
v_platform public."Platform";
86+
local_concept public.concept_local_input;
87+
db_concept public."Concept"%ROWTYPE;
88+
concept_row JSONB;
89+
concept_id BIGINT;
90+
BEGIN
91+
SELECT platform INTO STRICT v_platform FROM public."Space" WHERE id=v_space_id;
92+
FOR concept_row IN SELECT * FROM jsonb_array_elements(data)
93+
LOOP
94+
-- first set defaults
95+
local_concept := jsonb_populate_record(NULL::public.concept_local_input, '{"epistemic_status": "unknown", "literal_content":{},"reference_content":{},"is_schema":false}');
96+
-- then input values
97+
local_concept := jsonb_populate_record(local_concept, concept_row);
98+
local_concept.space_id := v_space_id;
99+
db_concept := public.local_concept_to_db_concept(local_concept);
100+
BEGIN
101+
-- cannot use db_concept.* because of refs.
102+
INSERT INTO public."Concept" (
103+
epistemic_status, name, description, author_id, created, last_modified, space_id, schema_id, literal_content, is_schema, represented_by_id, reference_content
104+
) VALUES (
105+
db_concept.epistemic_status, db_concept.name, db_concept.description, db_concept.author_id, db_concept.created, db_concept.last_modified, db_concept.space_id, db_concept.schema_id, db_concept.literal_content, db_concept.is_schema, db_concept.represented_by_id, db_concept.reference_content
106+
)
107+
ON CONFLICT (represented_by_id) DO UPDATE SET
108+
epistemic_status = db_concept.epistemic_status,
109+
name = db_concept.name,
110+
description = db_concept.description,
111+
author_id = db_concept.author_id,
112+
created = db_concept.created,
113+
last_modified = db_concept.last_modified,
114+
space_id = db_concept.space_id,
115+
schema_id = db_concept.schema_id,
116+
literal_content = db_concept.literal_content,
117+
is_schema = db_concept.is_schema,
118+
reference_content = db_concept.reference_content
119+
-- ON CONFLICT (space_id, name) DO NOTHING... why can't I specify two conflict clauses?
120+
RETURNING id INTO concept_id;
121+
RETURN NEXT concept_id;
122+
EXCEPTION
123+
WHEN unique_violation THEN
124+
-- a distinct unique constraint failed
125+
RAISE WARNING 'Concept with space_id: % and name % already exists', v_space_id, local_concept.name;
126+
RETURN NEXT -1; -- Return a special value to indicate conflict
127+
END;
128+
END LOOP;
129+
RAISE DEBUG 'Completed upsert_content successfully';
130+
END;
131+
$$;

packages/database/supabase/schemas/concept.sql

Lines changed: 132 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -111,3 +111,135 @@ ADD CONSTRAINT "Concept_space_id_fkey" FOREIGN KEY (
111111
GRANT ALL ON TABLE public."Concept" TO anon;
112112
GRANT ALL ON TABLE public."Concept" TO authenticated;
113113
GRANT ALL ON TABLE public."Concept" TO service_role;
114+
115+
116+
CREATE TYPE public.concept_local_input AS (
117+
-- concept columns
118+
epistemic_status public."EpistemicStatus",
119+
name character varying,
120+
description text,
121+
author_id bigint,
122+
created timestamp without time zone,
123+
last_modified timestamp without time zone,
124+
space_id bigint,
125+
schema_id bigint,
126+
literal_content jsonb,
127+
is_schema boolean,
128+
represented_by_id bigint,
129+
reference_content jsonb,
130+
-- local values
131+
author_local_id VARCHAR,
132+
represented_by_local_id VARCHAR,
133+
schema_represented_by_local_id VARCHAR,
134+
space_url VARCHAR,
135+
local_reference_content JSONB
136+
);
137+
138+
139+
CREATE OR REPLACE FUNCTION public.local_concept_to_db_concept(data public.concept_local_input) RETURNS public."Concept" LANGUAGE plpgsql STABLE AS $$
140+
DECLARE
141+
concept public."Concept"%ROWTYPE;
142+
reference_content JSONB := jsonb_build_object();
143+
key varchar;
144+
value JSONB;
145+
ref_single_val BIGINT;
146+
ref_array_val BIGINT[];
147+
BEGIN
148+
-- not fan of going through json, but not finding how to populate a record by a different shape record
149+
concept := jsonb_populate_record(NULL::public."Concept", to_jsonb(data));
150+
IF data.author_local_id IS NOT NULL THEN
151+
SELECT id FROM public."PlatformAccount"
152+
WHERE account_local_id = data.author_local_id INTO concept.author_id;
153+
END IF;
154+
IF data.represented_by_local_id IS NOT NULL THEN
155+
SELECT id FROM public."Content"
156+
WHERE source_local_id = data.represented_by_local_id INTO concept.represented_by_id;
157+
END IF;
158+
IF data.space_url IS NOT NULL THEN
159+
SELECT id FROM public."Space"
160+
WHERE url = data.space_url INTO concept.space_id;
161+
END IF;
162+
IF data.schema_represented_by_local_id IS NOT NULL THEN
163+
SELECT cpt.id FROM public."Concept" cpt
164+
JOIN public."Content" AS cnt ON cpt.represented_by_id = cnt.id
165+
WHERE cnt.source_local_id = data.schema_represented_by_local_id INTO concept.schema_id;
166+
END IF;
167+
IF data.local_reference_content IS NOT NULL THEN
168+
FOR key, value IN SELECT * FROM jsonb_each(data.local_reference_content) LOOP
169+
IF jsonb_typeof(value) = 'array' THEN
170+
WITH el AS (SELECT jsonb_array_elements_text(value) as x),
171+
ela AS (SELECT array_agg(x) AS a FROM el)
172+
SELECT array_agg(DISTINCT cpt.id) INTO STRICT ref_array_val
173+
FROM public."Concept" AS cpt
174+
JOIN public."Content" AS cnt ON (cpt.represented_by_id = cnt.id)
175+
JOIN ela ON (true) WHERE cnt.source_local_id = ANY(ela.a);
176+
reference_content := jsonb_set(reference_content, ARRAY[key], to_jsonb(ref_array_val));
177+
ELSIF jsonb_typeof(value) = 'string' THEN
178+
SELECT cpt.id INTO STRICT ref_single_val
179+
FROM public."Concept" AS cpt
180+
JOIN public."Content" AS cnt ON (cpt.represented_by_id = cnt.id)
181+
WHERE cnt.source_local_id = (value #>> '{}');
182+
reference_content := jsonb_set(reference_content, ARRAY[key], to_jsonb(ref_single_val));
183+
ELSE
184+
RAISE EXCEPTION 'Invalid value in local_reference_content % %', value, jsonb_typeof(value);
185+
END IF;
186+
END LOOP;
187+
SELECT reference_content INTO concept.reference_content;
188+
END IF;
189+
RETURN concept;
190+
END;
191+
$$;
192+
193+
194+
CREATE OR REPLACE FUNCTION public.upsert_concepts(v_space_id bigint, data jsonb)
195+
RETURNS SETOF BIGINT
196+
LANGUAGE plpgsql
197+
AS $$
198+
DECLARE
199+
v_platform public."Platform";
200+
local_concept public.concept_local_input;
201+
db_concept public."Concept"%ROWTYPE;
202+
concept_row JSONB;
203+
concept_id BIGINT;
204+
BEGIN
205+
SELECT platform INTO STRICT v_platform FROM public."Space" WHERE id=v_space_id;
206+
FOR concept_row IN SELECT * FROM jsonb_array_elements(data)
207+
LOOP
208+
-- first set defaults
209+
local_concept := jsonb_populate_record(NULL::public.concept_local_input, '{"epistemic_status": "unknown", "literal_content":{},"reference_content":{},"is_schema":false}');
210+
-- then input values
211+
local_concept := jsonb_populate_record(local_concept, concept_row);
212+
local_concept.space_id := v_space_id;
213+
db_concept := public.local_concept_to_db_concept(local_concept);
214+
BEGIN
215+
-- cannot use db_concept.* because of refs.
216+
INSERT INTO public."Concept" (
217+
epistemic_status, name, description, author_id, created, last_modified, space_id, schema_id, literal_content, is_schema, represented_by_id, reference_content
218+
) VALUES (
219+
db_concept.epistemic_status, db_concept.name, db_concept.description, db_concept.author_id, db_concept.created, db_concept.last_modified, db_concept.space_id, db_concept.schema_id, db_concept.literal_content, db_concept.is_schema, db_concept.represented_by_id, db_concept.reference_content
220+
)
221+
ON CONFLICT (represented_by_id) DO UPDATE SET
222+
epistemic_status = db_concept.epistemic_status,
223+
name = db_concept.name,
224+
description = db_concept.description,
225+
author_id = db_concept.author_id,
226+
created = db_concept.created,
227+
last_modified = db_concept.last_modified,
228+
space_id = db_concept.space_id,
229+
schema_id = db_concept.schema_id,
230+
literal_content = db_concept.literal_content,
231+
is_schema = db_concept.is_schema,
232+
reference_content = db_concept.reference_content
233+
-- ON CONFLICT (space_id, name) DO NOTHING... why can't I specify two conflict clauses?
234+
RETURNING id INTO concept_id;
235+
RETURN NEXT concept_id;
236+
EXCEPTION
237+
WHEN unique_violation THEN
238+
-- a distinct unique constraint failed
239+
RAISE WARNING 'Concept with space_id: % and name % already exists', v_space_id, local_concept.name;
240+
RETURN NEXT -1; -- Return a special value to indicate conflict
241+
END;
242+
END LOOP;
243+
RAISE DEBUG 'Completed upsert_content successfully';
244+
END;
245+
$$;

packages/database/types.gen.ts

Lines changed: 45 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -543,6 +543,28 @@ export type Database = {
543543
uid_to_sync: string
544544
}[]
545545
}
546+
local_concept_to_db_concept: {
547+
Args: {
548+
data: Database["public"]["CompositeTypes"]["concept_local_input"]
549+
}
550+
Returns: {
551+
arity: number
552+
author_id: number | null
553+
created: string
554+
description: string | null
555+
epistemic_status: Database["public"]["Enums"]["EpistemicStatus"]
556+
id: number
557+
is_schema: boolean
558+
last_modified: string
559+
literal_content: Json
560+
name: string
561+
reference_content: Json
562+
refs: number[]
563+
represented_by_id: number | null
564+
schema_id: number | null
565+
space_id: number
566+
}
567+
}
546568
match_content_embeddings: {
547569
Args: {
548570
query_embedding: string
@@ -576,6 +598,10 @@ export type Database = {
576598
}
577599
Returns: unknown
578600
}
601+
upsert_concepts: {
602+
Args: { v_space_id: number; data: Json }
603+
Returns: number[]
604+
}
579605
upsert_discourse_nodes: {
580606
Args: {
581607
p_space_name: string
@@ -644,7 +670,25 @@ export type Database = {
644670
task_status: "active" | "timeout" | "complete" | "failed"
645671
}
646672
CompositeTypes: {
647-
[_ in never]: never
673+
concept_local_input: {
674+
epistemic_status: Database["public"]["Enums"]["EpistemicStatus"] | null
675+
name: string | null
676+
description: string | null
677+
author_id: number | null
678+
created: string | null
679+
last_modified: string | null
680+
space_id: number | null
681+
schema_id: number | null
682+
literal_content: Json | null
683+
is_schema: boolean | null
684+
represented_by_id: number | null
685+
reference_content: Json | null
686+
author_local_id: string | null
687+
represented_by_local_id: string | null
688+
schema_represented_by_local_id: string | null
689+
space_url: string | null
690+
local_reference_content: Json | null
691+
}
648692
}
649693
}
650694
}

0 commit comments

Comments
 (0)