@@ -111,3 +111,135 @@ ADD CONSTRAINT "Concept_space_id_fkey" FOREIGN KEY (
111111GRANT ALL ON TABLE public." Concept" TO anon;
112112GRANT ALL ON TABLE public." Concept" TO authenticated;
113113GRANT 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+ $$;
0 commit comments