From 1114448cb2aed6c9de797a489dcced61aad3796c Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Mon, 26 May 2025 11:50:21 -0400 Subject: [PATCH] Add unique keys to schema --- packages/database/schema.puml | 3 +- packages/database/schema.svg | 2 +- packages/database/schema.yaml | 58 ++++++++++++++++-- .../migrations/20250526150535_uniqueness.sql | 61 +++++++++++++++++++ .../database/supabase/schemas/account.sql | 19 +++--- packages/database/supabase/schemas/agent.sql | 5 +- .../database/supabase/schemas/concept.sql | 4 +- .../database/supabase/schemas/content.sql | 9 ++- packages/database/supabase/schemas/space.sql | 23 ++++--- 9 files changed, 150 insertions(+), 34 deletions(-) create mode 100644 packages/database/supabase/migrations/20250526150535_uniqueness.sql diff --git a/packages/database/schema.puml b/packages/database/schema.puml index 914fc6e49..c728ab7a1 100644 --- a/packages/database/schema.puml +++ b/packages/database/schema.puml @@ -9,6 +9,7 @@ class "Account" [[{A user account on a platform}]] { {field} id : integer {field} write_permission : boolean {field} active : boolean + {field} account_local_id : string } class "Space" [[{A space on a platform representing a community engaged in a conversation}]] { {field} id : integer @@ -104,7 +105,7 @@ class "AutomatedAgent" [[{An automated agent}]] { {field} id(i) : integer {field} type(i) : EntityType } -"Account" --> "1" "Agent" : "person" +"Account" --> "1" "Agent" : "agent" "Agent" ^-- "Person" "Agent" ^-- "AutomatedAgent" @enduml diff --git a/packages/database/schema.svg b/packages/database/schema.svg index ab1d233e5..6d1cef850 100644 --- a/packages/database/schema.svg +++ b/packages/database/schema.svg @@ -1 +1 @@ -SpaceAccesseditor : booleanAccountid : integerwrite_permission : booleanactive : booleanSpaceid : integerurl : stringname : stringPlatformid : integername : stringurl : stringContentid : integersource_local_id : stringcreated : datetimetext : stringmetadata : JSONscale : Scalelast_modified : datetimeDocumentid : integersource_local_id : stringurl : stringcreated : datetimemetadata : JSONlast_modified : datetimecontents : blobConceptid : integerepistemic_status : EpistemicStatusname : stringdescription : stringcreated : datetimelast_modified : datetimearity : integercontent : JSONis_schema : booleanAgentid : integertype : EntityTypeContentEmbeddingmodel : EmbeddingNamevector : vectorobsolete : booleanConceptSchemaid(i) : integerepistemic_status(i) : EpistemicStatusname(i) : stringdescription(i) : stringcreated(i) : datetimelast_modified(i) : datetimearity(i) : integercontent(i) : JSONis_schema(i) : booleanPersonname : stringorcid : stringemail : stringid(i) : integertype(i) : EntityTypeAutomatedAgentmetadata : JSONname : stringdeterministic : booleanversion : stringid(i) : integertype(i) : EntityTypeaccount1space0..1platform1space0..1space0..1space0..1platform1contributors0..*author1document1target1part_of0..1contributors0..*creator1author1represented_by0..1schema1contributors0..*author1person1 \ No newline at end of file +SpaceAccesseditor : booleanAccountid : integerwrite_permission : booleanactive : booleanaccount_local_id : stringSpaceid : integerurl : stringname : stringPlatformid : integername : stringurl : stringContentid : integersource_local_id : stringcreated : datetimetext : stringmetadata : JSONscale : Scalelast_modified : datetimeDocumentid : integersource_local_id : stringurl : stringcreated : datetimemetadata : JSONlast_modified : datetimecontents : blobConceptid : integerepistemic_status : EpistemicStatusname : stringdescription : stringcreated : datetimelast_modified : datetimearity : integercontent : JSONis_schema : booleanAgentid : integertype : EntityTypeContentEmbeddingmodel : EmbeddingNamevector : vectorobsolete : booleanConceptSchemaid(i) : integerepistemic_status(i) : EpistemicStatusname(i) : stringdescription(i) : stringcreated(i) : datetimelast_modified(i) : datetimearity(i) : integercontent(i) : JSONis_schema(i) : booleanPersonname : stringorcid : stringemail : stringid(i) : integertype(i) : EntityTypeAutomatedAgentmetadata : JSONname : stringdeterministic : booleanversion : stringid(i) : integertype(i) : EntityTypeaccount1space0..1platform1space0..1space0..1space0..1platform1contributors0..*author1document1target1part_of0..1contributors0..*creator1author1represented_by0..1schema1contributors0..*author1agent1 \ No newline at end of file diff --git a/packages/database/schema.yaml b/packages/database/schema.yaml index 363f9ff8b..063740d47 100644 --- a/packages/database/schema.yaml +++ b/packages/database/schema.yaml @@ -120,6 +120,13 @@ classes: email: required: true # TODO: known skills, i.e. what processes can they confirm. + unique_keys: + person_email: + unique_key_slots: + - email + person_orcid: + unique_key_slots: + - orcid AutomatedAgent: description: An automated agent is_a: Agent @@ -132,22 +139,28 @@ classes: ifabsent: false version: range: string - + unique_keys: + automated_agent_name_version: + unique_key_slots: + - name + - version Platform: description: A data platform where discourse happens slots: - id - name - attributes: - url: - required: true + - url + unique_keys: + platform_url: + unique_key_slots: + - url Account: description: A user account on a platform slots: - id - platform attributes: - person: + agent: range: Agent required: true write_permission: @@ -157,6 +170,14 @@ classes: range: boolean required: true ifabsent: true + account_local_id: + required: true + description: The identity of the person in this space + unique_keys: + account_platform_and_local_id: + unique_key_slots: + - platform + - account_local_id Space: description: A space on a platform representing a community engaged in a conversation slots: @@ -167,6 +188,10 @@ classes: platform: range: Platform required: true + unique_keys: + space_url: + unique_key_slots: + - url SpaceAccess: description: An access control entry for a space slots: @@ -205,6 +230,12 @@ classes: part_of: description: This content is part of a larger content unit range: Content + unique_keys: + content_space_and_local_id: + unique_key_slots: + - space + - source_local_id + # ContentDerivation: # description: A derivation relation between content units # attributes: @@ -226,15 +257,24 @@ classes: - id - space - source_local_id - - url - created - metadata - last_modified - author - contributors attributes: + url: + range: string contents: range: blob + unique_keys: + document_space_and_local_id: + unique_key_slots: + - space + - source_local_id + document_url: + unique_key_slots: + - url # Article: # description: an article # is_a: Document @@ -303,6 +343,11 @@ classes: # Damn, concept schema is a concept, is it not? # Now, if a concept has a complex structwre based on a complex content... # AH, it should be based on occurences. + unique_keys: + concept_space_and_name: + unique_key_slots: + - space + - name ConceptSchema: is_a: Concept @@ -379,6 +424,7 @@ slots: range: string url: range: string + required: true platform: range: Platform required: true diff --git a/packages/database/supabase/migrations/20250526150535_uniqueness.sql b/packages/database/supabase/migrations/20250526150535_uniqueness.sql new file mode 100644 index 000000000..327d13094 --- /dev/null +++ b/packages/database/supabase/migrations/20250526150535_uniqueness.sql @@ -0,0 +1,61 @@ +-- Space + +CREATE UNIQUE INDEX IF NOT EXISTS platform_url_idx ON public."Platform" USING btree (url); + +ALTER TABLE public."Space" ALTER COLUMN url SET NOT NULL; + +CREATE UNIQUE INDEX IF NOT EXISTS space_url_idx ON public."Space" USING btree (url); + +-- Agents + +ALTER TABLE public."AutomatedAgent" ALTER COLUMN version SET NOT NULL; + +CREATE UNIQUE INDEX IF NOT EXISTS automated_agent_name_version_idx ON public."AutomatedAgent" USING btree (name, version); + +CREATE UNIQUE INDEX IF NOT EXISTS person_email_idx ON public."Person" USING btree (email); +CREATE UNIQUE INDEX IF NOT EXISTS person_orcid_idx ON public."Person" USING btree (orcid); + +-- Account + +ALTER TABLE public."Account" RENAME COLUMN "person_id" TO "agent_id"; + +ALTER TABLE public."Account" RENAME CONSTRAINT "Account_person_id_fkey" TO "Account_agent_id_fkey"; + +ALTER TABLE public."Account" ADD COLUMN account_local_id character varying; + +UPDATE public."Account" SET account_local_id = (SELECT email FROM public."Person" AS p WHERE p.id = agent_id); + +ALTER TABLE public."Account" ALTER COLUMN "account_local_id" SET NOT NULL; + +CREATE UNIQUE INDEX IF NOT EXISTS account_platform_and_local_id_idx ON public."Account" USING btree (platform_id, account_local_id); + +-- Document and Content + +CREATE UNIQUE INDEX IF NOT EXISTS document_space_and_local_id_idx ON public."Document" USING btree (space_id, source_local_id) WHERE (space_id IS NOT NULL); +CREATE UNIQUE INDEX IF NOT EXISTS document_url_idx ON public."Document" USING btree (url); + +DROP INDEX IF EXISTS public."Content_space_and_id"; + +CREATE UNIQUE INDEX IF NOT EXISTS content_space_and_local_id_idx ON public."Content" USING btree (space_id, source_local_id) WHERE (space_id IS NOT NULL); + +-- Concept + +ALTER TABLE public."Concept" ALTER COLUMN "space_id" set not null; + +CREATE UNIQUE INDEX IF NOT EXISTS concept_space_and_name_idx ON public."Concept" USING btree (space_id, name); + + +-- SpaceAccess + +ALTER TABLE public."SpaceAccess" DROP CONSTRAINT "SpaceAccess_account_id_space_id_key"; + +ALTER TABLE public."SpaceAccess" DROP CONSTRAINT "SpaceAccess_pkey"; + +ALTER TABLE public."SpaceAccess" DROP COLUMN "id"; +ALTER TABLE public."SpaceAccess" ALTER COLUMN "space_id" set not null; + +CREATE UNIQUE INDEX IF NOT EXISTS "SpaceAccess_pkey" ON public."SpaceAccess" USING btree (space_id, account_id); + +ALTER TABLE public."SpaceAccess" add constraint "SpaceAccess_pkey" PRIMARY KEY using index "SpaceAccess_pkey"; + +COMMENT ON COLUMN public."SpaceAccess".account_id IS 'The identity of the account in this space'; diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index 9914188d9..f7f95f707 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -3,7 +3,8 @@ CREATE TABLE IF NOT EXISTS public."Account" ( 'public.entity_id_seq'::regclass ) NOT NULL, platform_id bigint NOT NULL, - person_id bigint NOT NULL, + agent_id bigint NOT NULL, + account_local_id varchar NOT NULL, write_permission boolean NOT NULL, active boolean DEFAULT true NOT NULL ); @@ -14,8 +15,8 @@ COMMENT ON TABLE public."Account" IS 'A user account on a platform'; ALTER TABLE ONLY public."Account" -ADD CONSTRAINT "Account_person_id_fkey" FOREIGN KEY ( - person_id +ADD CONSTRAINT "Account_agent_id_fkey" FOREIGN KEY ( + agent_id ) REFERENCES public."Agent" (id) ON UPDATE CASCADE ON DELETE CASCADE; ALTER TABLE ONLY public."Account" @@ -28,23 +29,16 @@ ADD CONSTRAINT "Account_platform_id_fkey" FOREIGN KEY ( ALTER TABLE ONLY public."Account" ADD CONSTRAINT "Account_pkey" PRIMARY KEY (id); +CREATE UNIQUE INDEX account_platform_and_local_id_idx ON public."Account" USING btree (platform_id, account_local_id); CREATE TABLE IF NOT EXISTS public."SpaceAccess" ( - id bigint DEFAULT nextval( - 'public.entity_id_seq'::regclass - ) NOT NULL, space_id bigint, account_id bigint NOT NULL, editor boolean NOT NULL ); ALTER TABLE ONLY public."SpaceAccess" -ADD CONSTRAINT "SpaceAccess_account_id_space_id_key" UNIQUE ( - account_id, space_id -); - -ALTER TABLE ONLY public."SpaceAccess" -ADD CONSTRAINT "SpaceAccess_pkey" PRIMARY KEY (id); +ADD CONSTRAINT "SpaceAccess_pkey" PRIMARY KEY (space_id, account_id); ALTER TABLE public."SpaceAccess" OWNER TO "postgres"; @@ -53,6 +47,7 @@ COMMENT ON TABLE public."SpaceAccess" IS 'An access control entry for a space'; COMMENT ON COLUMN public."SpaceAccess".space_id IS 'The space in which the content is located'; +COMMENT ON COLUMN public."SpaceAccess".account_id IS 'The identity of the account in this space'; ALTER TABLE ONLY public."SpaceAccess" ADD CONSTRAINT "SpaceAccess_account_id_fkey" FOREIGN KEY ( diff --git a/packages/database/supabase/schemas/agent.sql b/packages/database/supabase/schemas/agent.sql index ecbf3f511..0384b127b 100644 --- a/packages/database/supabase/schemas/agent.sql +++ b/packages/database/supabase/schemas/agent.sql @@ -18,7 +18,7 @@ CREATE TABLE IF NOT EXISTS public."AutomatedAgent" ( name character varying NOT NULL, metadata jsonb DEFAULT '{}'::jsonb NOT NULL, deterministic boolean DEFAULT false, - version character varying + version character varying NOT NULL ); ALTER TABLE ONLY public."AutomatedAgent" @@ -29,6 +29,7 @@ ADD CONSTRAINT automated_agent_id_fkey FOREIGN KEY ( id ) REFERENCES public."Agent" (id) ON UPDATE CASCADE ON DELETE CASCADE; +CREATE UNIQUE INDEX automated_agent_name_version_idx ON public."AutomatedAgent" USING btree (name, version); ALTER TABLE public."AutomatedAgent" OWNER TO "postgres"; @@ -49,6 +50,8 @@ ADD CONSTRAINT person_id_fkey FOREIGN KEY ( id ) REFERENCES public."Agent" (id) ON UPDATE CASCADE ON DELETE CASCADE; +CREATE UNIQUE INDEX person_email_idx ON public."Person" USING btree (email); +CREATE UNIQUE INDEX person_orcid_idx ON public."Person" USING btree (orcid); ALTER TABLE public."Person" OWNER TO "postgres"; diff --git a/packages/database/supabase/schemas/concept.sql b/packages/database/supabase/schemas/concept.sql index dbbc3686e..8a4b06ada 100644 --- a/packages/database/supabase/schemas/concept.sql +++ b/packages/database/supabase/schemas/concept.sql @@ -23,7 +23,7 @@ CREATE TABLE IF NOT EXISTS public."Concept" ( author_id bigint, created timestamp without time zone NOT NULL, last_modified timestamp without time zone NOT NULL, - space_id bigint, + space_id bigint NOT NULL, arity smallint DEFAULT 0 NOT NULL, schema_id bigint, content jsonb DEFAULT '{}'::jsonb NOT NULL, @@ -64,6 +64,8 @@ CREATE UNIQUE INDEX "Concept_represented_by" ON public."Concept" ( represented_by_id ); +CREATE UNIQUE INDEX concept_space_and_name_idx ON public."Concept" (space_id, name); + ALTER TABLE ONLY public."Concept" ADD CONSTRAINT "Concept_author_id_fkey" FOREIGN KEY ( diff --git a/packages/database/supabase/schemas/content.sql b/packages/database/supabase/schemas/content.sql index 13478f5f8..d60ec1782 100644 --- a/packages/database/supabase/schemas/content.sql +++ b/packages/database/supabase/schemas/content.sql @@ -42,6 +42,11 @@ ADD CONSTRAINT "Document_space_id_fkey" FOREIGN KEY ( id ) ON UPDATE CASCADE ON DELETE CASCADE; +CREATE UNIQUE INDEX document_space_and_local_id_idx ON public."Document" USING btree (space_id, source_local_id) + NULLS DISTINCT WHERE space_id IS NOT NULL; + +CREATE UNIQUE INDEX document_url_idx ON public."Document" USING btree (url); + ALTER TABLE public."Document" OWNER TO "postgres"; COMMENT ON COLUMN public."Document".space_id IS 'The space in which the content is located'; @@ -114,9 +119,9 @@ CREATE INDEX "Content_part_of" ON public."Content" USING btree ( CREATE INDEX "Content_space" ON public."Content" USING btree (space_id); -CREATE UNIQUE INDEX "Content_space_and_id" ON public."Content" USING btree ( +CREATE UNIQUE INDEX content_space_and_local_id_idx ON public."Content" USING btree ( space_id, source_local_id -) WHERE (source_local_id IS NOT NULL); +) NULLS DISTINCT WHERE (space_id IS NOT NULL); CREATE INDEX "Content_text" ON public."Content" USING pgroonga (text); diff --git a/packages/database/supabase/schemas/space.sql b/packages/database/supabase/schemas/space.sql index 122cdd023..1ae1536d8 100644 --- a/packages/database/supabase/schemas/space.sql +++ b/packages/database/supabase/schemas/space.sql @@ -6,7 +6,10 @@ CREATE TABLE IF NOT EXISTS public."Platform" ( url character varying NOT NULL ); -ALTER TABLE public."Platform" OWNER TO "postgres"; +ALTER TABLE ONLY public."Platform" +ADD CONSTRAINT "Platform_pkey" PRIMARY KEY (id); + +CREATE UNIQUE INDEX platform_url_idx ON public."Platform" USING btree (url); COMMENT ON TABLE public."Platform" IS 'A data platform where discourse happens'; @@ -15,22 +18,16 @@ CREATE TABLE IF NOT EXISTS public."Space" ( id bigint DEFAULT nextval( 'public."entity_id_seq"'::regclass ) NOT NULL, - url character varying, + url character varying NOT NULL, name character varying NOT NULL, platform_id bigint NOT NULL ); -ALTER TABLE public."Space" OWNER TO "postgres"; - -COMMENT ON TABLE public."Space" IS -'A space on a platform representing a community engaged in a conversation'; - -ALTER TABLE ONLY public."Platform" -ADD CONSTRAINT "Platform_pkey" PRIMARY KEY (id); - ALTER TABLE ONLY public."Space" ADD CONSTRAINT "Space_pkey" PRIMARY KEY (id); +CREATE UNIQUE INDEX space_url_idx ON public."Space" USING btree (url); + ALTER TABLE ONLY public."Space" ADD CONSTRAINT "Space_platform_id_fkey" FOREIGN KEY ( platform_id @@ -38,6 +35,12 @@ ADD CONSTRAINT "Space_platform_id_fkey" FOREIGN KEY ( id ) ON UPDATE CASCADE ON DELETE CASCADE; +COMMENT ON TABLE public."Space" IS +'A space on a platform representing a community engaged in a conversation'; + +ALTER TABLE public."Platform" OWNER TO "postgres"; +ALTER TABLE public."Space" OWNER TO "postgres"; + GRANT ALL ON TABLE public."Platform" TO anon; GRANT ALL ON TABLE public."Platform" TO authenticated; GRANT ALL ON TABLE public."Platform" TO service_role;