From 36e8422cc8221ee34a1ca715377fcc7b8f616039 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Mon, 16 Jun 2025 17:29:33 -0400 Subject: [PATCH 1/2] ENG-463 autogenerate arity column --- .../20250616212706_generate-arity.sql | 35 +++++++++++++++++++ .../database/supabase/schemas/concept.sql | 19 ++++++++-- 2 files changed, 52 insertions(+), 2 deletions(-) create mode 100644 packages/database/supabase/migrations/20250616212706_generate-arity.sql diff --git a/packages/database/supabase/migrations/20250616212706_generate-arity.sql b/packages/database/supabase/migrations/20250616212706_generate-arity.sql new file mode 100644 index 000000000..dcd9cd4f1 --- /dev/null +++ b/packages/database/supabase/migrations/20250616212706_generate-arity.sql @@ -0,0 +1,35 @@ +ALTER TABLE "public"."Concept" DROP COLUMN "arity"; + +ALTER TABLE "public"."Concept" ADD COLUMN "arity" smallint GENERATED ALWAYS AS (compute_arity_local(schema_id, literal_content)) STORED; + +CREATE OR REPLACE FUNCTION public.compute_arity_id(p_schema_id bigint) +RETURNS smallint +LANGUAGE sql +IMMUTABLE +AS $function$ + WITH q AS (SELECT jsonb_path_query(literal_content, '$.roles[*]') FROM public."Concept" WHERE id=p_schema_id) SELECT count(*) FROM q; +$function$; + +CREATE OR REPLACE FUNCTION public.compute_arity_lit(lit_content jsonb) +RETURNS smallint +LANGUAGE sql +IMMUTABLE +AS $function$ + WITH q AS (SELECT jsonb_path_query(lit_content, '$.roles[*]')) SELECT count(*) FROM q; +$function$; + +CREATE OR REPLACE FUNCTION public.compute_arity_local(schema_id bigint, lit_content jsonb) +RETURNS smallint +LANGUAGE sql +IMMUTABLE +AS $function$ + SELECT CASE WHEN schema_id IS NULL THEN compute_arity_lit(lit_content) ELSE compute_arity_id(schema_id) END; +$function$; + +CREATE OR REPLACE FUNCTION public.extract_references(refs jsonb) +RETURNS bigint [] +LANGUAGE sql +IMMUTABLE +AS $function$ + SELECT COALESCE(array_agg(i::bigint), '{}') FROM (SELECT DISTINCT jsonb_array_elements(jsonb_path_query_array(refs, '$.*[*]')) i) exrefs; +$function$; diff --git a/packages/database/supabase/schemas/concept.sql b/packages/database/supabase/schemas/concept.sql index 8e7ab7ddd..dade63e56 100644 --- a/packages/database/supabase/schemas/concept.sql +++ b/packages/database/supabase/schemas/concept.sql @@ -13,9 +13,24 @@ CREATE TYPE public."EpistemicStatus" AS ENUM ( ALTER TYPE public."EpistemicStatus" OWNER TO postgres; CREATE OR REPLACE FUNCTION extract_references(refs JSONB) RETURNS BIGINT [] LANGUAGE sql IMMUTABLE AS $$ - SELECT COALESCE(array_agg(i::bigint), '{}') FROM (SELECT jsonb_array_elements(jsonb_path_query_array(refs, '$.*[*]')) i) exrefs; + SELECT COALESCE(array_agg(i::bigint), '{}') FROM (SELECT DISTINCT jsonb_array_elements(jsonb_path_query_array(refs, '$.*[*]')) i) exrefs; $$; +CREATE OR REPLACE FUNCTION compute_arity_lit(lit_content JSONB) RETURNS smallint language sql IMMUTABLE AS $$ + WITH q AS (SELECT jsonb_path_query(lit_content, '$.roles[*]')) SELECT count(*) FROM q; +$$; + +SET check_function_bodies = false; +CREATE OR REPLACE FUNCTION compute_arity_id(p_schema_id BIGINT) RETURNS smallint language sql IMMUTABLE AS $$ + WITH q AS (SELECT jsonb_path_query(literal_content, '$.roles[*]') FROM public."Concept" WHERE id=p_schema_id) SELECT count(*) FROM q; +$$; +SET check_function_bodies = true; + +CREATE OR REPLACE FUNCTION compute_arity_local(schema_id BIGINT, lit_content JSONB) RETURNS smallint language sql IMMUTABLE AS $$ + SELECT CASE WHEN schema_id IS NULL THEN compute_arity_lit(lit_content) ELSE compute_arity_id(schema_id) END; +$$; + + CREATE TABLE IF NOT EXISTS public."Concept" ( id bigint DEFAULT nextval( 'public.entity_id_seq'::regclass @@ -27,7 +42,7 @@ CREATE TABLE IF NOT EXISTS public."Concept" ( created timestamp without time zone NOT NULL, last_modified timestamp without time zone NOT NULL, space_id bigint NOT NULL, - arity smallint DEFAULT 0 NOT NULL, + arity smallint GENERATED ALWAYS AS (compute_arity_local(schema_id, literal_content)) STORED, schema_id bigint, literal_content jsonb NOT NULL DEFAULT '{}'::jsonb, reference_content jsonb NOT NULL DEFAULT '{}'::jsonb, From 3a7d7ed5b9602df8035d31ce876c21ee0d3b02da Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Tue, 17 Jun 2025 13:38:41 -0400 Subject: [PATCH 2/2] coderabbit optimization --- .../migrations/20250616212706_generate-arity.sql | 12 ++++++------ packages/database/supabase/schemas/concept.sql | 4 ++-- 2 files changed, 8 insertions(+), 8 deletions(-) diff --git a/packages/database/supabase/migrations/20250616212706_generate-arity.sql b/packages/database/supabase/migrations/20250616212706_generate-arity.sql index dcd9cd4f1..8ba7dda26 100644 --- a/packages/database/supabase/migrations/20250616212706_generate-arity.sql +++ b/packages/database/supabase/migrations/20250616212706_generate-arity.sql @@ -1,13 +1,9 @@ -ALTER TABLE "public"."Concept" DROP COLUMN "arity"; - -ALTER TABLE "public"."Concept" ADD COLUMN "arity" smallint GENERATED ALWAYS AS (compute_arity_local(schema_id, literal_content)) STORED; - CREATE OR REPLACE FUNCTION public.compute_arity_id(p_schema_id bigint) RETURNS smallint LANGUAGE sql IMMUTABLE AS $function$ - WITH q AS (SELECT jsonb_path_query(literal_content, '$.roles[*]') FROM public."Concept" WHERE id=p_schema_id) SELECT count(*) FROM q; + SELECT COALESCE(jsonb_array_length(literal_content->'roles'), 0) FROM public."Concept" WHERE id=p_schema_id; $function$; CREATE OR REPLACE FUNCTION public.compute_arity_lit(lit_content jsonb) @@ -15,7 +11,7 @@ RETURNS smallint LANGUAGE sql IMMUTABLE AS $function$ - WITH q AS (SELECT jsonb_path_query(lit_content, '$.roles[*]')) SELECT count(*) FROM q; + SELECT COALESCE(jsonb_array_length(lit_content->'roles'), 0); $function$; CREATE OR REPLACE FUNCTION public.compute_arity_local(schema_id bigint, lit_content jsonb) @@ -26,6 +22,10 @@ AS $function$ SELECT CASE WHEN schema_id IS NULL THEN compute_arity_lit(lit_content) ELSE compute_arity_id(schema_id) END; $function$; +ALTER TABLE "public"."Concept" DROP COLUMN "arity"; + +ALTER TABLE "public"."Concept" ADD COLUMN "arity" smallint GENERATED ALWAYS AS (compute_arity_local(schema_id, literal_content)) STORED; + CREATE OR REPLACE FUNCTION public.extract_references(refs jsonb) RETURNS bigint [] LANGUAGE sql diff --git a/packages/database/supabase/schemas/concept.sql b/packages/database/supabase/schemas/concept.sql index dade63e56..e42498568 100644 --- a/packages/database/supabase/schemas/concept.sql +++ b/packages/database/supabase/schemas/concept.sql @@ -17,12 +17,12 @@ CREATE OR REPLACE FUNCTION extract_references(refs JSONB) RETURNS BIGINT [] LANG $$; CREATE OR REPLACE FUNCTION compute_arity_lit(lit_content JSONB) RETURNS smallint language sql IMMUTABLE AS $$ - WITH q AS (SELECT jsonb_path_query(lit_content, '$.roles[*]')) SELECT count(*) FROM q; + SELECT COALESCE(jsonb_array_length(lit_content->'roles'), 0); $$; SET check_function_bodies = false; CREATE OR REPLACE FUNCTION compute_arity_id(p_schema_id BIGINT) RETURNS smallint language sql IMMUTABLE AS $$ - WITH q AS (SELECT jsonb_path_query(literal_content, '$.roles[*]') FROM public."Concept" WHERE id=p_schema_id) SELECT count(*) FROM q; + SELECT COALESCE(jsonb_array_length(literal_content->'roles'), 0) FROM public."Concept" WHERE id=p_schema_id; $$; SET check_function_bodies = true;