From 409332ab406616c2f08febcfd2e1f7de338be728 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Wed, 8 Oct 2025 14:16:11 -0400 Subject: [PATCH 01/10] Make queries through security-aware views to bypass RLS. --- packages/database/src/dbTypes.ts | 374 ++++++++++++++++-- packages/database/src/lib/contextFunctions.ts | 9 +- packages/database/src/lib/queries.ts | 12 +- .../supabase/functions/create-space/index.ts | 31 +- .../20251008131345_security_views.sql | 255 ++++++++++++ .../supabase/schemas/access_token.sql | 2 +- .../database/supabase/schemas/account.sql | 94 +++-- .../database/supabase/schemas/concept.sql | 124 ++++-- .../database/supabase/schemas/content.sql | 52 +++ 9 files changed, 857 insertions(+), 96 deletions(-) create mode 100644 packages/database/supabase/migrations/20251008131345_security_views.sql diff --git a/packages/database/src/dbTypes.ts b/packages/database/src/dbTypes.ts index dc48a6a4c..c569ee829 100644 --- a/packages/database/src/dbTypes.ts +++ b/packages/database/src/dbTypes.ts @@ -138,6 +138,13 @@ export type Database = { referencedRelation: "Content" referencedColumns: ["id"] }, + { + foreignKeyName: "Concept_represented_by_id_fkey" + columns: ["represented_by_id"] + isOneToOne: false + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_schema_id_fkey" columns: ["schema_id"] @@ -145,6 +152,13 @@ export type Database = { referencedRelation: "Concept" referencedColumns: ["id"] }, + { + foreignKeyName: "Concept_schema_id_fkey" + columns: ["schema_id"] + isOneToOne: false + referencedRelation: "my_concepts" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_space_id_fkey" columns: ["space_id"] @@ -175,6 +189,13 @@ export type Database = { referencedRelation: "Concept" referencedColumns: ["id"] }, + { + foreignKeyName: "concept_contributors_concept_id_fkey" + columns: ["concept_id"] + isOneToOne: false + referencedRelation: "my_concepts" + referencedColumns: ["id"] + }, { foreignKeyName: "concept_contributors_contributor_id_fkey" columns: ["contributor_id"] @@ -252,6 +273,13 @@ export type Database = { referencedRelation: "Document" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_document_id_fkey" + columns: ["document_id"] + isOneToOne: false + referencedRelation: "my_documents" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_part_of_id_fkey" columns: ["part_of_id"] @@ -259,6 +287,13 @@ export type Database = { referencedRelation: "Content" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_part_of_id_fkey" + columns: ["part_of_id"] + isOneToOne: false + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_space_id_fkey" columns: ["space_id"] @@ -289,6 +324,13 @@ export type Database = { referencedRelation: "Content" referencedColumns: ["id"] }, + { + foreignKeyName: "content_contributors_content_id_fkey" + columns: ["content_id"] + isOneToOne: false + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, { foreignKeyName: "content_contributors_contributor_id_fkey" columns: ["contributor_id"] @@ -325,6 +367,13 @@ export type Database = { referencedRelation: "Content" referencedColumns: ["id"] }, + { + foreignKeyName: "ContentEmbedding_openai_text_embedding_3_small_1_target_id_fkey" + columns: ["target_id"] + isOneToOne: true + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, ] } Document: { @@ -509,7 +558,258 @@ export type Database = { } } Views: { - [_ in never]: never + my_concepts: { + Row: { + arity: number | null + author_id: number | null + created: string | null + description: string | null + epistemic_status: + | Database["public"]["Enums"]["EpistemicStatus"] + | null + id: number | null + is_schema: boolean | null + last_modified: string | null + literal_content: Json | null + name: string | null + reference_content: Json | null + refs: number[] | null + represented_by_id: number | null + schema_id: number | null + space_id: number | null + } + Insert: { + arity?: number | null + author_id?: number | null + created?: string | null + description?: string | null + epistemic_status?: + | Database["public"]["Enums"]["EpistemicStatus"] + | null + id?: number | null + is_schema?: boolean | null + last_modified?: string | null + literal_content?: Json | null + name?: string | null + reference_content?: Json | null + refs?: number[] | null + represented_by_id?: number | null + schema_id?: number | null + space_id?: number | null + } + Update: { + arity?: number | null + author_id?: number | null + created?: string | null + description?: string | null + epistemic_status?: + | Database["public"]["Enums"]["EpistemicStatus"] + | null + id?: number | null + is_schema?: boolean | null + last_modified?: string | null + literal_content?: Json | null + name?: string | null + reference_content?: Json | null + refs?: number[] | null + represented_by_id?: number | null + schema_id?: number | null + space_id?: number | null + } + Relationships: [ + { + foreignKeyName: "Concept_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "PlatformAccount" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Concept_represented_by_id_fkey" + columns: ["represented_by_id"] + isOneToOne: false + referencedRelation: "Content" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Concept_represented_by_id_fkey" + columns: ["represented_by_id"] + isOneToOne: false + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Concept_schema_id_fkey" + columns: ["schema_id"] + isOneToOne: false + referencedRelation: "Concept" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Concept_schema_id_fkey" + columns: ["schema_id"] + isOneToOne: false + referencedRelation: "my_concepts" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Concept_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "Space" + referencedColumns: ["id"] + }, + ] + } + my_contents: { + Row: { + author_id: number | null + created: string | null + creator_id: number | null + document_id: number | null + id: number | null + last_modified: string | null + metadata: Json | null + part_of_id: number | null + scale: Database["public"]["Enums"]["Scale"] | null + source_local_id: string | null + space_id: number | null + text: string | null + variant: Database["public"]["Enums"]["ContentVariant"] | null + } + Insert: { + author_id?: number | null + created?: string | null + creator_id?: number | null + document_id?: number | null + id?: number | null + last_modified?: string | null + metadata?: Json | null + part_of_id?: number | null + scale?: Database["public"]["Enums"]["Scale"] | null + source_local_id?: string | null + space_id?: number | null + text?: string | null + variant?: Database["public"]["Enums"]["ContentVariant"] | null + } + Update: { + author_id?: number | null + created?: string | null + creator_id?: number | null + document_id?: number | null + id?: number | null + last_modified?: string | null + metadata?: Json | null + part_of_id?: number | null + scale?: Database["public"]["Enums"]["Scale"] | null + source_local_id?: string | null + space_id?: number | null + text?: string | null + variant?: Database["public"]["Enums"]["ContentVariant"] | null + } + Relationships: [ + { + foreignKeyName: "Content_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "PlatformAccount" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_creator_id_fkey" + columns: ["creator_id"] + isOneToOne: false + referencedRelation: "PlatformAccount" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_document_id_fkey" + columns: ["document_id"] + isOneToOne: false + referencedRelation: "Document" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_document_id_fkey" + columns: ["document_id"] + isOneToOne: false + referencedRelation: "my_documents" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_part_of_id_fkey" + columns: ["part_of_id"] + isOneToOne: false + referencedRelation: "Content" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_part_of_id_fkey" + columns: ["part_of_id"] + isOneToOne: false + referencedRelation: "my_contents" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Content_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "Space" + referencedColumns: ["id"] + }, + ] + } + my_documents: { + Row: { + author_id: number | null + contents: unknown | null + created: string | null + id: number | null + last_modified: string | null + metadata: Json | null + source_local_id: string | null + space_id: number | null + url: string | null + } + Insert: { + author_id?: number | null + contents?: unknown | null + created?: string | null + id?: number | null + last_modified?: string | null + metadata?: Json | null + source_local_id?: string | null + space_id?: number | null + url?: string | null + } + Update: { + author_id?: number | null + contents?: unknown | null + created?: string | null + id?: number | null + last_modified?: string | null + metadata?: Json | null + source_local_id?: string | null + space_id?: number | null + url?: string | null + } + Relationships: [ + { + foreignKeyName: "Document_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "PlatformAccount" + referencedColumns: ["id"] + }, + { + foreignKeyName: "Document_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "Space" + referencedColumns: ["id"] + }, + ] + } } Functions: { _local_concept_to_db_concept: { @@ -579,23 +879,27 @@ export type Database = { Returns: number } concept_in_relations: { - Args: { concept: Database["public"]["Tables"]["Concept"]["Row"] } + Args: + | { concept: Database["public"]["Tables"]["Concept"]["Row"] } + | { concept: unknown } Returns: { arity: number | null author_id: number | null - created: string + created: string | null description: string | null - epistemic_status: Database["public"]["Enums"]["EpistemicStatus"] - id: number - is_schema: boolean - last_modified: string - literal_content: Json - name: string - reference_content: Json - refs: number[] + epistemic_status: + | Database["public"]["Enums"]["EpistemicStatus"] + | null + id: number | null + is_schema: boolean | null + last_modified: string | null + literal_content: Json | null + name: string | null + reference_content: Json | null + refs: number[] | null represented_by_id: number | null schema_id: number | null - space_id: number + space_id: number | null }[] } concept_in_space: { @@ -603,23 +907,27 @@ export type Database = { Returns: boolean } concepts_of_relation: { - Args: { relation: Database["public"]["Tables"]["Concept"]["Row"] } + Args: + | { relation: Database["public"]["Tables"]["Concept"]["Row"] } + | { relation: unknown } Returns: { arity: number | null author_id: number | null - created: string + created: string | null description: string | null - epistemic_status: Database["public"]["Enums"]["EpistemicStatus"] - id: number - is_schema: boolean - last_modified: string - literal_content: Json - name: string - reference_content: Json - refs: number[] + epistemic_status: + | Database["public"]["Enums"]["EpistemicStatus"] + | null + id: number | null + is_schema: boolean | null + last_modified: string | null + literal_content: Json | null + name: string | null + reference_content: Json | null + refs: number[] | null represented_by_id: number | null schema_id: number | null - space_id: number + space_id: number | null }[] } content_in_space: { @@ -673,7 +981,9 @@ export type Database = { Returns: boolean } instances_of_schema: { - Args: { schema: Database["public"]["Tables"]["Concept"]["Row"] } + Args: + | { schema: Database["public"]["Tables"]["Concept"]["Row"] } + | { schema: unknown } Returns: { arity: number | null author_id: number | null @@ -692,6 +1002,10 @@ export type Database = { space_id: number }[] } + is_my_account: { + Args: { account_id: number } + Returns: boolean + } match_content_embeddings: { Args: { current_document_id?: number @@ -716,8 +1030,12 @@ export type Database = { }[] } my_account: { - Args: { account_id: number } - Returns: boolean + Args: Record + Returns: number + } + my_spaces: { + Args: Record + Returns: number[] } propose_sync_task: { Args: { @@ -730,7 +1048,9 @@ export type Database = { Returns: string } schema_of_concept: { - Args: { concept: Database["public"]["Tables"]["Concept"]["Row"] } + Args: + | { concept: Database["public"]["Tables"]["Concept"]["Row"] } + | { concept: unknown } Returns: { arity: number | null author_id: number | null diff --git a/packages/database/src/lib/contextFunctions.ts b/packages/database/src/lib/contextFunctions.ts index d82e0403e..21fd1e963 100644 --- a/packages/database/src/lib/contextFunctions.ts +++ b/packages/database/src/lib/contextFunctions.ts @@ -102,10 +102,11 @@ export const fetchOrCreateSpaceDirect = async ( }); if (result2.data === null) { - return asPostgrestFailure( - JSON.stringify(result2.error), - "Failed to create space", - ); + let error: string = (result2.error?.message as string | undefined) || ""; + if (result2.error?.context?.body) + error += await new Response(result2.error.context.body).text(); + console.log(result); + return asPostgrestFailure(error, "Failed to create space"); } return { data: result2.data, diff --git a/packages/database/src/lib/queries.ts b/packages/database/src/lib/queries.ts index b9d1374ee..05e6325d5 100644 --- a/packages/database/src/lib/queries.ts +++ b/packages/database/src/lib/queries.ts @@ -114,9 +114,11 @@ const composeConceptQuery = ({ if (contentFields.length > 0) { const args: string[] = contentFields.slice(); if (documentFields.length > 0) { - args.push("Document (\n" + documentFields.join(",\n") + ")"); + args.push( + "Document:document_of_content (\n" + documentFields.join(",\n") + ")", + ); } - q += `,\nContent${innerContent ? "!inner" : ""} (\n${args.join(",\n")})`; + q += `,\nContent:content_of_concept${innerContent ? "!inner" : ""} (\n${args.join(",\n")})`; } if (nodeAuthor !== undefined) { q += ", author:author_id!inner(account_local_id)"; @@ -139,7 +141,7 @@ const composeConceptQuery = ({ if (inRelsToNodesOfType !== undefined && !args2.includes("schema_id")) args2.push("schema_id"); if (inRelsToNodeLocalIds !== undefined) - args2.push("Content!inner(source_local_id)"); + args2.push("Content:content_of_concept!inner(source_local_id)"); if (inRelsToNodesOfAuthor !== undefined) { if (!args2.includes("author_id")) args2.push("author_id"); args2.push("author:author_id!inner(account_local_id)"); @@ -148,7 +150,7 @@ const composeConceptQuery = ({ } q += `, relations:concept_in_relations!inner(${args.join(",\n")})`; } - let query = supabase.from("Concept").select(q); + let query = supabase.from("my_concepts").select(q); if (fetchNodes === true) { query = query.eq("arity", 0); } else if (fetchNodes === false) { @@ -172,7 +174,7 @@ const composeConceptQuery = ({ else throw new Error("schemaDbIds should be a number or number[]"); } if (baseNodeLocalIds.length > 0) - query = query.in("content.source_local_id", baseNodeLocalIds); + query = query.in("Content.source_local_id", baseNodeLocalIds); if (inRelsOfType !== undefined && inRelsOfType.length > 0) query = query.in("relations.schema_id", inRelsOfType); if (inRelsToNodesOfType !== undefined && inRelsToNodesOfType.length > 0) diff --git a/packages/database/supabase/functions/create-space/index.ts b/packages/database/supabase/functions/create-space/index.ts index ccf8daea6..7c82ab120 100644 --- a/packages/database/supabase/functions/create-space/index.ts +++ b/packages/database/supabase/functions/create-space/index.ts @@ -114,6 +114,7 @@ const processAndGetOrCreateSpace = async ( return asPostgrestFailure(error.message, "authentication_error"); } anonymousUser = data.user; + await supabase.auth.signOut({ scope: "local" }); } if (anonymousUser === null) { const resultCreateAnonymousUser = await supabase.auth.admin.createUser({ @@ -185,7 +186,7 @@ const processAndGetOrCreateSpace = async ( const allowedOrigins = ["https://roamresearch.com", "http://localhost:3000"]; const isVercelPreviewUrl = (origin: string): boolean => - /^https:\/\/.*-discourse-graph-[a-z0-9]+\.vercel\.app$/.test(origin) + /^https:\/\/.*-discourse-graph-[a-z0-9]+\.vercel\.app$/.test(origin); const isAllowedOrigin = (origin: string): boolean => allowedOrigins.some((allowed) => origin.startsWith(allowed)) || @@ -193,20 +194,20 @@ const isAllowedOrigin = (origin: string): boolean => // @ts-ignore Deno is not visible to the IDE Deno.serve(async (req) => { - const origin = req.headers.get("origin"); - const originIsAllowed = origin && isAllowedOrigin(origin); - if (req.method === "OPTIONS") { - return new Response(null, { - status: 204, - headers: { - ...(originIsAllowed ? { "Access-Control-Allow-Origin": origin } : {}), - "Access-Control-Allow-Methods": "GET, POST, OPTIONS", - "Access-Control-Allow-Headers": - "Content-Type, Authorization, x-vercel-protection-bypass, x-client-info, apikey", - "Access-Control-Max-Age": "86400", - }, - }); - } + const origin = req.headers.get("origin"); + const originIsAllowed = origin && isAllowedOrigin(origin); + if (req.method === "OPTIONS") { + return new Response(null, { + status: 204, + headers: { + ...(originIsAllowed ? { "Access-Control-Allow-Origin": origin } : {}), + "Access-Control-Allow-Methods": "GET, POST, OPTIONS", + "Access-Control-Allow-Headers": + "Content-Type, Authorization, x-vercel-protection-bypass, x-client-info, apikey", + "Access-Control-Max-Age": "86400", + }, + }); + } const input = await req.json(); // @ts-ignore Deno is not visible to the IDE diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql new file mode 100644 index 000000000..d4e47a241 --- /dev/null +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -0,0 +1,255 @@ +ALTER FUNCTION public.my_account RENAME TO is_my_account; + +DROP POLICY IF EXISTS access_token_policy ON public.access_token; +CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (public.is_my_account(platform_account_id)); + +CREATE OR REPLACE FUNCTION public.is_my_account(account_id BIGINT) RETURNS boolean +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT true FROM public."PlatformAccount" pa + JOIN u ON pa.dg_account = u.uid + WHERE pa.id = account_id; +$$; + +COMMENT ON FUNCTION public.is_my_account IS 'security utility: is this my own account?'; + +CREATE OR REPLACE FUNCTION public.my_account() RETURNS BIGINT +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT id FROM public."PlatformAccount" pa + JOIN u ON pa.dg_account = u.uid LIMIT 1; +$$; + +COMMENT ON FUNCTION public.my_account IS 'security utility: id of my account'; + +CREATE OR REPLACE FUNCTION public.my_space_ids() RETURNS BIGINT [] +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT array_agg(distinct sa.space_id) AS ids FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id + JOIN u ON pa.dg_account = u.uid; +$$; +COMMENT ON FUNCTION public.my_space_ids IS 'security utility: all spaces the user has access to'; + + +CREATE OR REPLACE FUNCTION public.in_space(space_id BIGINT) RETURNS boolean +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT space_id = ANY(public.my_space_ids()); +$$; + +COMMENT ON FUNCTION public.in_space IS 'security utility: does current user have access to this space?'; + + +CREATE OR REPLACE FUNCTION public.account_in_shared_space(p_account_id BIGINT) RETURNS boolean +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql AS $$ + SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()); +$$; + +COMMENT ON FUNCTION public.account_in_shared_space IS 'security utility: does current user share a space with this account?'; + +CREATE OR REPLACE FUNCTION public.unowned_account_in_shared_space(p_account_id BIGINT) RETURNS boolean +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql AS $$ + SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + AND pa.dg_account IS NULL; +$$; + +COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this unowned account?'; + +DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + +DROP POLICY IF EXISTS platform_account_select_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SELECT USING (dg_account = (SELECT auth.uid() LIMIT 1) OR public.account_in_shared_space(id)); + +DROP POLICY IF EXISTS space_access_policy ON public."SpaceAccess"; +CREATE POLICY space_access_policy ON public."SpaceAccess" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS space_access_select_policy ON public."SpaceAccess"; +CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR SELECT USING (public.in_space(space_id)); + +DROP POLICY IF EXISTS agent_identifier_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_policy ON public."AgentIdentifier" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS agent_identifier_select_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_select_policy ON public."AgentIdentifier" FOR SELECT USING (public.account_in_shared_space(account_id)); + +CREATE OR REPLACE VIEW public.my_spaces AS +SELECT + id, + url, + name, + platform +FROM public."Space" WHERE id = any(public.my_space_ids()); + +CREATE OR REPLACE VIEW public.my_accounts AS +SELECT + pa.id, + pa.name, + pa.platform, + pa.account_local_id, + pa.write_permission, + pa.active, + pa.agent_type, + pa.metadata, + pa.dg_account +FROM public."PlatformAccount" AS pa +JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) +WHERE sa.space_id = ANY(public.my_space_ids()); + + +CREATE OR REPLACE VIEW public.my_documents AS +SELECT + id, + space_id, + source_local_id, + url, + "created", + metadata, + last_modified, + author_id, + contents +FROM public."Document" WHERE space_id = any(public.my_space_ids()); + +CREATE OR REPLACE VIEW public.my_contents AS +SELECT + id, + document_id, + source_local_id, + variant, + author_id, + creator_id, + created, + text, + metadata, + scale, + space_id, + last_modified, + part_of_id +FROM public."Content" WHERE space_id = any(public.my_space_ids()); + +CREATE OR REPLACE VIEW public.my_concepts AS +SELECT + id, + epistemic_status, + name, + description, + author_id, + created, + last_modified, + space_id, + arity, + schema_id, + literal_content, + reference_content, + refs, + is_schema, + represented_by_id +FROM public."Concept" WHERE space_id = any(public.my_space_ids()); + + +CREATE OR REPLACE FUNCTION public.schema_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE id=concept.schema_id; +$$; +COMMENT ON FUNCTION public.schema_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the schema Concept for a given Concept (by schema_id).'; + +CREATE OR REPLACE FUNCTION public.instances_of_schema(schema public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE schema_id=schema.id; +$$; +COMMENT ON FUNCTION public.instances_of_schema(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances that are based on the given schema Concept.'; + + +CREATE OR REPLACE FUNCTION public.concept_in_relations(concept public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE refs @> ARRAY[concept.id]; +$$; +COMMENT ON FUNCTION public.concept_in_relations(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances that are relations including the current concept.'; + +CREATE OR REPLACE FUNCTION public.concepts_of_relation(relation public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE id = any(relation.refs); +$$; +COMMENT ON FUNCTION public.concepts_of_relation(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances are referred to in the current concept.'; + +CREATE OR REPLACE FUNCTION public.document_of_content(content public.my_contents) +RETURNS SETOF public.my_documents STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_documents WHERE id=content.document_id; +$$; +COMMENT ON FUNCTION public.document_of_content(public.my_contents) +IS 'Computed one-to-one: returns the containing Document for a given Content.'; + +CREATE OR REPLACE FUNCTION public.content_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_contents STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_contents WHERE id=concept.represented_by_id; +$$; +COMMENT ON FUNCTION public.content_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the representing Content for a given Concept.'; + +CREATE OR REPLACE FUNCTION public.author_of_content(content public.my_contents) +RETURNS SETOF public.my_accounts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_accounts WHERE id=content.author_id; +$$; +COMMENT ON FUNCTION public.author_of_content(public.my_contents) +IS 'Computed one-to-one: returns the PlatformAccount which authored a given Content.'; + +CREATE OR REPLACE FUNCTION public.author_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_accounts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_accounts WHERE id=concept.author_id; +$$; +COMMENT ON FUNCTION public.author_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the PlatformAccount which authored a given Concept.'; diff --git a/packages/database/supabase/schemas/access_token.sql b/packages/database/supabase/schemas/access_token.sql index a1b7b2c9c..4fc2ba802 100644 --- a/packages/database/supabase/schemas/access_token.sql +++ b/packages/database/supabase/schemas/access_token.sql @@ -40,4 +40,4 @@ GRANT INSERT ON TABLE "public"."access_token" TO "anon"; ALTER TABLE public.access_token ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS access_token_policy ON public.access_token; -CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (public.my_account(platform_account_id)); +CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (public.is_my_account(platform_account_id)); diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index d1b7ccaef..ad0b3c8cc 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -181,24 +181,50 @@ AS $$ $$; -CREATE OR REPLACE FUNCTION public.my_account(account_id BIGINT) RETURNS boolean +CREATE OR REPLACE FUNCTION public.is_my_account(account_id BIGINT) RETURNS boolean STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT dg_account = auth.uid() FROM public."PlatformAccount" WHERE id=account_id; + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT true FROM public."PlatformAccount" pa + JOIN u ON pa.dg_account = u.uid + WHERE pa.id = account_id; $$; -COMMENT ON FUNCTION public.my_account IS 'security utility: is this my own account?'; +COMMENT ON FUNCTION public.is_my_account IS 'security utility: is this my own account?'; + +CREATE OR REPLACE FUNCTION public.my_account() RETURNS BIGINT +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT id FROM public."PlatformAccount" pa + JOIN u ON pa.dg_account = u.uid LIMIT 1; +$$; + +COMMENT ON FUNCTION public.my_account IS 'security utility: id of my account'; + +CREATE OR REPLACE FUNCTION public.my_space_ids() RETURNS BIGINT [] +STABLE SECURITY DEFINER +SET search_path = '' +LANGUAGE sql +AS $$ + WITH u AS (SELECT auth.uid() LIMIT 1) + SELECT array_agg(distinct sa.space_id) AS ids FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id + JOIN u ON pa.dg_account = u.uid; +$$; +COMMENT ON FUNCTION public.my_space_ids IS 'security utility: all spaces the user has access to'; + CREATE OR REPLACE FUNCTION public.in_space(space_id BIGINT) RETURNS boolean STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT COUNT(*) > 0 FROM public."SpaceAccess" AS sa - JOIN public."PlatformAccount" AS pa ON (pa.id=sa.account_id) - WHERE sa.space_id = $1 AND pa.dg_account = auth.uid(); + SELECT space_id = ANY(public.my_space_ids()); $$; COMMENT ON FUNCTION public.in_space IS 'security utility: does current user have access to this space?'; @@ -208,25 +234,25 @@ CREATE OR REPLACE FUNCTION public.account_in_shared_space(p_account_id BIGINT) R STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT COUNT(*) > 0 FROM public."PlatformAccount" AS my_account - JOIN public."SpaceAccess" AS my_access ON (my_account.id=my_access.account_id) - JOIN public."SpaceAccess" AS their_access ON (their_access.space_id = my_access.space_id AND their_access.account_id=p_account_id) - WHERE my_account.dg_account = auth.uid(); + SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()); $$; +COMMENT ON FUNCTION public.account_in_shared_space IS 'security utility: does current user share a space with this account?'; + CREATE OR REPLACE FUNCTION public.unowned_account_in_shared_space(p_account_id BIGINT) RETURNS boolean STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT COUNT(*) > 0 FROM public."PlatformAccount" AS my_account - JOIN public."SpaceAccess" AS my_access ON (my_account.id=my_access.account_id) - JOIN public."SpaceAccess" AS their_access ON (their_access.space_id = my_access.space_id AND their_access.account_id=p_account_id) - JOIN public."PlatformAccount" AS their_account ON (their_access.account_id = their_account.id AND their_account.id=p_account_id) - WHERE my_account.dg_account = auth.uid() AND COALESCE(their_account.dg_account, auth.uid()) = auth.uid(); + SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + AND pa.dg_account IS NULL; $$; -COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this account? And is this an un-owned account (other than mine)?'; - +COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this unowned account?'; -- Space: Allow anyone to insert, but only users who are members of the space can update or select @@ -238,17 +264,41 @@ CREATE POLICY space_policy ON public."Space" FOR ALL USING (public.in_space(id)) DROP POLICY IF EXISTS space_insert_policy ON public."Space"; CREATE POLICY space_insert_policy ON public."Space" FOR INSERT WITH CHECK (true); +CREATE OR REPLACE VIEW public.my_spaces AS +SELECT + id, + url, + name, + platform +FROM public."Space" WHERE id = any(public.my_space_ids()); + -- PlatformAccount: Access to anyone sharing a space with you to create an account, to allow editing authors -- Once the account is claimed by a user, only allow this user to modify it. -- Eventually: Allow platform admin to modify? ALTER TABLE public."PlatformAccount" ENABLE ROW LEVEL SECURITY; +CREATE OR REPLACE VIEW public.my_accounts AS +SELECT + pa.id, + pa.name, + pa.platform, + pa.account_local_id, + pa.write_permission, + pa.active, + pa.agent_type, + pa.metadata, + pa.dg_account +FROM public."PlatformAccount" AS pa +JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) +WHERE sa.space_id = ANY(public.my_space_ids()); + + DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; -CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid()) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); +CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); DROP POLICY IF EXISTS platform_account_select_policy ON public."PlatformAccount"; -CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SELECT USING (dg_account = (SELECT auth.uid()) OR public.account_in_shared_space(id)); +CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SELECT USING (dg_account = (SELECT auth.uid() LIMIT 1) OR public.account_in_shared_space(id)); -- SpaceAccess: Created through the create_account_in_space and the Space create route, both of which bypass RLS. -- Can be updated by a space peer for now, unless claimed by a user. @@ -257,10 +307,10 @@ CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SEL ALTER TABLE public."SpaceAccess" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS space_access_policy ON public."SpaceAccess"; -CREATE POLICY space_access_policy ON public."SpaceAccess" FOR ALL USING (public.unowned_account_in_shared_space(account_id)); +CREATE POLICY space_access_policy ON public."SpaceAccess" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS space_access_select_policy ON public."SpaceAccess"; -CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR ALL USING (public.in_space(space_id)); +CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR SELECT USING (public.in_space(space_id)); -- AgentIdentifier: Allow space members to do anything, to allow editing authors. -- Eventually: Once the account is claimed by a user, only allow this user to modify it. @@ -268,7 +318,7 @@ CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR ALL USING ( ALTER TABLE public."AgentIdentifier" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS agent_identifier_policy ON public."AgentIdentifier"; -CREATE POLICY agent_identifier_policy ON public."AgentIdentifier" FOR ALL USING (public.unowned_account_in_shared_space(account_id)); +CREATE POLICY agent_identifier_policy ON public."AgentIdentifier" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS agent_identifier_select_policy ON public."AgentIdentifier"; CREATE POLICY agent_identifier_select_policy ON public."AgentIdentifier" FOR SELECT USING (public.account_in_shared_space(account_id)); diff --git a/packages/database/supabase/schemas/concept.sql b/packages/database/supabase/schemas/concept.sql index 623b76884..21b73cd2a 100644 --- a/packages/database/supabase/schemas/concept.sql +++ b/packages/database/supabase/schemas/concept.sql @@ -115,28 +115,24 @@ REVOKE ALL ON TABLE public."Concept" FROM anon; GRANT ALL ON TABLE public."Concept" TO authenticated; GRANT ALL ON TABLE public."Concept" TO service_role; - -CREATE TYPE public.concept_local_input AS ( - -- concept columns - epistemic_status public."EpistemicStatus", - name character varying, - description text, - author_id bigint, - created timestamp without time zone, - last_modified timestamp without time zone, - space_id bigint, - schema_id bigint, - literal_content jsonb, - is_schema boolean, - represented_by_id bigint, - reference_content jsonb, - -- local values - author_local_id VARCHAR, - represented_by_local_id VARCHAR, - schema_represented_by_local_id VARCHAR, - space_url VARCHAR, - local_reference_content JSONB -); +CREATE OR REPLACE VIEW public.my_concepts AS +SELECT + id, + epistemic_status, + name, + description, + author_id, + created, + last_modified, + space_id, + arity, + schema_id, + literal_content, + reference_content, + refs, + is_schema, + represented_by_id +FROM public."Concept" WHERE space_id = any(public.my_space_ids()); -- following https://docs.postgrest.org/en/v13/references/api/resource_embedding.html#recursive-relationships CREATE OR REPLACE FUNCTION public.schema_of_concept(concept public."Concept") @@ -150,6 +146,17 @@ $$; COMMENT ON FUNCTION public.schema_of_concept(public."Concept") IS 'Computed one-to-one: returns the schema Concept for a given Concept (by schema_id).'; +CREATE OR REPLACE FUNCTION public.schema_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE id=concept.schema_id; +$$; +COMMENT ON FUNCTION public.schema_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the schema Concept for a given Concept (by schema_id).'; + CREATE OR REPLACE FUNCTION public.instances_of_schema(schema public."Concept") RETURNS SETOF public."Concept" STRICT STABLE SET search_path = '' @@ -160,6 +167,15 @@ $$; COMMENT ON FUNCTION public.instances_of_schema(public."Concept") IS 'Computed one-to-many: returns all Concept instances that are based on the given schema Concept.'; +CREATE OR REPLACE FUNCTION public.instances_of_schema(schema public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE schema_id=schema.id; +$$; +COMMENT ON FUNCTION public.instances_of_schema(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances that are based on the given schema Concept.'; CREATE OR REPLACE FUNCTION public.concept_in_relations(concept public."Concept") RETURNS SETOF public."Concept" STRICT STABLE @@ -171,6 +187,16 @@ $$; COMMENT ON FUNCTION public.concept_in_relations(public."Concept") IS 'Computed one-to-many: returns all Concept instances that are relations including the current concept.'; +CREATE OR REPLACE FUNCTION public.concept_in_relations(concept public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE refs @> ARRAY[concept.id]; +$$; +COMMENT ON FUNCTION public.concept_in_relations(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances that are relations including the current concept.'; + CREATE OR REPLACE FUNCTION public.concepts_of_relation(relation public."Concept") RETURNS SETOF public."Concept" STRICT STABLE SET search_path = '' @@ -181,6 +207,60 @@ $$; COMMENT ON FUNCTION public.concepts_of_relation(public."Concept") IS 'Computed one-to-many: returns all Concept instances are referred to in the current concept.'; +CREATE OR REPLACE FUNCTION public.concepts_of_relation(relation public.my_concepts) +RETURNS SETOF public.my_concepts STRICT STABLE +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_concepts WHERE id = any(relation.refs); +$$; +COMMENT ON FUNCTION public.concepts_of_relation(public.my_concepts) +IS 'Computed one-to-many: returns all Concept instances are referred to in the current concept.'; + +CREATE OR REPLACE FUNCTION public.content_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_contents STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_contents WHERE id=concept.represented_by_id; +$$; +COMMENT ON FUNCTION public.content_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the representing Content for a given Concept.'; + +CREATE OR REPLACE FUNCTION public.author_of_concept(concept public.my_concepts) +RETURNS SETOF public.my_accounts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_accounts WHERE id=concept.author_id; +$$; +COMMENT ON FUNCTION public.author_of_concept(public.my_concepts) +IS 'Computed one-to-one: returns the PlatformAccount which authored a given Concept.'; + + +CREATE TYPE public.concept_local_input AS ( + -- concept columns + epistemic_status public."EpistemicStatus", + name character varying, + description text, + author_id bigint, + created timestamp without time zone, + last_modified timestamp without time zone, + space_id bigint, + schema_id bigint, + literal_content jsonb, + is_schema boolean, + represented_by_id bigint, + reference_content jsonb, + -- local values + author_local_id VARCHAR, + represented_by_local_id VARCHAR, + schema_represented_by_local_id VARCHAR, + space_url VARCHAR, + local_reference_content JSONB +); -- private function. Transform concept with local (platform) references to concept with db references CREATE OR REPLACE FUNCTION public._local_concept_to_db_concept(data public.concept_local_input) diff --git a/packages/database/supabase/schemas/content.sql b/packages/database/supabase/schemas/content.sql index 8bc6382c4..b8a4c8694 100644 --- a/packages/database/supabase/schemas/content.sql +++ b/packages/database/supabase/schemas/content.sql @@ -69,6 +69,19 @@ COMMENT ON COLUMN public."Document".author_id IS 'The author of content'; COMMENT ON COLUMN public."Document".contents IS 'A large object OID for the downloaded raw content'; +-- explicit fields require more maintenance, but respects declared table order. +CREATE OR REPLACE VIEW public.my_documents AS +SELECT + id, + space_id, + source_local_id, + url, + "created", + metadata, + last_modified, + author_id, + contents +FROM public."Document" WHERE space_id = any(public.my_space_ids()); CREATE TABLE IF NOT EXISTS public."Content" ( id bigint DEFAULT nextval( @@ -161,6 +174,45 @@ REVOKE ALL ON TABLE public."Content" FROM anon; GRANT ALL ON TABLE public."Content" TO authenticated; GRANT ALL ON TABLE public."Content" TO service_role; +CREATE OR REPLACE VIEW public.my_contents AS +SELECT + id, + document_id, + source_local_id, + variant, + author_id, + creator_id, + created, + text, + metadata, + scale, + space_id, + last_modified, + part_of_id +FROM public."Content" WHERE space_id = any(public.my_space_ids()); + +CREATE OR REPLACE FUNCTION public.document_of_content(content public.my_contents) +RETURNS SETOF public.my_documents STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_documents WHERE id=content.document_id; +$$; +COMMENT ON FUNCTION public.document_of_content(public.my_contents) +IS 'Computed one-to-one: returns the containing Document for a given Content.'; + +CREATE OR REPLACE FUNCTION public.author_of_content(content public.my_contents) +RETURNS SETOF public.my_accounts STRICT STABLE +ROWS 1 +SET search_path = '' +LANGUAGE sql +AS $$ + SELECT * from public.my_accounts WHERE id=content.author_id; +$$; +COMMENT ON FUNCTION public.author_of_content(public.my_contents) +IS 'Computed one-to-one: returns the PlatformAccount which authored a given Content.'; + CREATE TYPE public.document_local_input AS ( -- document columns space_id bigint, From ba33576dcff1ad09000ee32c60107003fac919a4 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Wed, 8 Oct 2025 14:54:49 -0400 Subject: [PATCH 02/10] coderabbit comments --- packages/database/src/lib/contextFunctions.ts | 10 ++++++++-- .../migrations/20251008131345_security_views.sql | 2 +- packages/database/supabase/schemas/account.sql | 2 +- 3 files changed, 10 insertions(+), 4 deletions(-) diff --git a/packages/database/src/lib/contextFunctions.ts b/packages/database/src/lib/contextFunctions.ts index 21fd1e963..dd93fa2f8 100644 --- a/packages/database/src/lib/contextFunctions.ts +++ b/packages/database/src/lib/contextFunctions.ts @@ -102,10 +102,16 @@ export const fetchOrCreateSpaceDirect = async ( }); if (result2.data === null) { + // eslint-disable-next-line @typescript-eslint/no-unsafe-member-access let error: string = (result2.error?.message as string | undefined) || ""; + // eslint-disable-next-line @typescript-eslint/no-unsafe-member-access if (result2.error?.context?.body) - error += await new Response(result2.error.context.body).text(); - console.log(result); + try { + // eslint-disable-next-line + error += await new Response(result2.error.context.body).text(); + } catch (err) { + // could not parse, not important + } return asPostgrestFailure(error, "Failed to create space"); } return { diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql index d4e47a241..c0d0aa87c 100644 --- a/packages/database/supabase/migrations/20251008131345_security_views.sql +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -34,7 +34,7 @@ SET search_path = '' LANGUAGE sql AS $$ WITH u AS (SELECT auth.uid() LIMIT 1) - SELECT array_agg(distinct sa.space_id) AS ids FROM public."SpaceAccess" AS sa + SELECT COALESCE(array_agg(distinct sa.space_id), '{}') AS ids FROM public."SpaceAccess" AS sa JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id JOIN u ON pa.dg_account = u.uid; $$; diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index ad0b3c8cc..d5d3a03dc 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -212,7 +212,7 @@ SET search_path = '' LANGUAGE sql AS $$ WITH u AS (SELECT auth.uid() LIMIT 1) - SELECT array_agg(distinct sa.space_id) AS ids FROM public."SpaceAccess" AS sa + SELECT COALESCE(array_agg(distinct sa.space_id), '{}') AS ids FROM public."SpaceAccess" AS sa JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id JOIN u ON pa.dg_account = u.uid; $$; From 9c4755a4c79fda391065da4050b913bf828411c7 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Wed, 8 Oct 2025 15:39:21 -0400 Subject: [PATCH 03/10] missing changes to dbTypes --- packages/database/src/dbTypes.ts | 237 ++++++++++++++++++++++++++++++- 1 file changed, 236 insertions(+), 1 deletion(-) diff --git a/packages/database/src/dbTypes.ts b/packages/database/src/dbTypes.ts index c569ee829..9ece1617b 100644 --- a/packages/database/src/dbTypes.ts +++ b/packages/database/src/dbTypes.ts @@ -33,6 +33,13 @@ export type Database = { request_id?: string } Relationships: [ + { + foreignKeyName: "access_token_platform_account_id_fkey" + columns: ["platform_account_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "access_token_platform_account_id_fkey" columns: ["platform_account_id"] @@ -62,6 +69,13 @@ export type Database = { value?: string } Relationships: [ + { + foreignKeyName: "AgentIdentifier_account_id_fkey" + columns: ["account_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "AgentIdentifier_account_id_fkey" columns: ["account_id"] @@ -124,6 +138,13 @@ export type Database = { space_id?: number } Relationships: [ + { + foreignKeyName: "Concept_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_author_id_fkey" columns: ["author_id"] @@ -159,6 +180,13 @@ export type Database = { referencedRelation: "my_concepts" referencedColumns: ["id"] }, + { + foreignKeyName: "Concept_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_space_id_fkey" columns: ["space_id"] @@ -196,6 +224,13 @@ export type Database = { referencedRelation: "my_concepts" referencedColumns: ["id"] }, + { + foreignKeyName: "concept_contributors_contributor_id_fkey" + columns: ["contributor_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "concept_contributors_contributor_id_fkey" columns: ["contributor_id"] @@ -252,6 +287,13 @@ export type Database = { variant?: Database["public"]["Enums"]["ContentVariant"] } Relationships: [ + { + foreignKeyName: "Content_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_author_id_fkey" columns: ["author_id"] @@ -259,6 +301,13 @@ export type Database = { referencedRelation: "PlatformAccount" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_creator_id_fkey" + columns: ["creator_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_creator_id_fkey" columns: ["creator_id"] @@ -294,6 +343,13 @@ export type Database = { referencedRelation: "my_contents" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_space_id_fkey" columns: ["space_id"] @@ -331,6 +387,13 @@ export type Database = { referencedRelation: "my_contents" referencedColumns: ["id"] }, + { + foreignKeyName: "content_contributors_contributor_id_fkey" + columns: ["contributor_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "content_contributors_contributor_id_fkey" columns: ["contributor_id"] @@ -411,6 +474,13 @@ export type Database = { url?: string | null } Relationships: [ + { + foreignKeyName: "Document_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Document_author_id_fkey" columns: ["author_id"] @@ -418,6 +488,13 @@ export type Database = { referencedRelation: "PlatformAccount" referencedColumns: ["id"] }, + { + foreignKeyName: "Document_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Document_space_id_fkey" columns: ["space_id"] @@ -501,6 +578,13 @@ export type Database = { space_id?: number } Relationships: [ + { + foreignKeyName: "SpaceAccess_account_id_fkey" + columns: ["account_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "SpaceAccess_account_id_fkey" columns: ["account_id"] @@ -508,6 +592,13 @@ export type Database = { referencedRelation: "PlatformAccount" referencedColumns: ["id"] }, + { + foreignKeyName: "SpaceAccess_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "SpaceAccess_space_id_fkey" columns: ["space_id"] @@ -558,6 +649,20 @@ export type Database = { } } Views: { + my_accounts: { + Row: { + account_local_id: string | null + active: boolean | null + agent_type: Database["public"]["Enums"]["AgentType"] | null + dg_account: string | null + id: number | null + metadata: Json | null + name: string | null + platform: Database["public"]["Enums"]["Platform"] | null + write_permission: boolean | null + } + Relationships: [] + } my_concepts: { Row: { arity: number | null @@ -617,6 +722,13 @@ export type Database = { space_id?: number | null } Relationships: [ + { + foreignKeyName: "Concept_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_author_id_fkey" columns: ["author_id"] @@ -652,6 +764,13 @@ export type Database = { referencedRelation: "my_concepts" referencedColumns: ["id"] }, + { + foreignKeyName: "Concept_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Concept_space_id_fkey" columns: ["space_id"] @@ -708,6 +827,13 @@ export type Database = { variant?: Database["public"]["Enums"]["ContentVariant"] | null } Relationships: [ + { + foreignKeyName: "Content_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_author_id_fkey" columns: ["author_id"] @@ -715,6 +841,13 @@ export type Database = { referencedRelation: "PlatformAccount" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_creator_id_fkey" + columns: ["creator_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_creator_id_fkey" columns: ["creator_id"] @@ -750,6 +883,13 @@ export type Database = { referencedRelation: "my_contents" referencedColumns: ["id"] }, + { + foreignKeyName: "Content_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Content_space_id_fkey" columns: ["space_id"] @@ -794,6 +934,13 @@ export type Database = { url?: string | null } Relationships: [ + { + foreignKeyName: "Document_author_id_fkey" + columns: ["author_id"] + isOneToOne: false + referencedRelation: "my_accounts" + referencedColumns: ["id"] + }, { foreignKeyName: "Document_author_id_fkey" columns: ["author_id"] @@ -801,6 +948,13 @@ export type Database = { referencedRelation: "PlatformAccount" referencedColumns: ["id"] }, + { + foreignKeyName: "Document_space_id_fkey" + columns: ["space_id"] + isOneToOne: false + referencedRelation: "my_spaces" + referencedColumns: ["id"] + }, { foreignKeyName: "Document_space_id_fkey" columns: ["space_id"] @@ -810,6 +964,27 @@ export type Database = { }, ] } + my_spaces: { + Row: { + id: number | null + name: string | null + platform: Database["public"]["Enums"]["Platform"] | null + url: string | null + } + Insert: { + id?: number | null + name?: string | null + platform?: Database["public"]["Enums"]["Platform"] | null + url?: string | null + } + Update: { + id?: number | null + name?: string | null + platform?: Database["public"]["Enums"]["Platform"] | null + url?: string | null + } + Relationships: [] + } } Functions: { _local_concept_to_db_concept: { @@ -874,6 +1049,34 @@ export type Database = { Args: { p_account_id: number } Returns: boolean } + author_of_concept: { + Args: { concept: unknown } + Returns: { + account_local_id: string | null + active: boolean | null + agent_type: Database["public"]["Enums"]["AgentType"] | null + dg_account: string | null + id: number | null + metadata: Json | null + name: string | null + platform: Database["public"]["Enums"]["Platform"] | null + write_permission: boolean | null + }[] + } + author_of_content: { + Args: { content: unknown } + Returns: { + account_local_id: string | null + active: boolean | null + agent_type: Database["public"]["Enums"]["AgentType"] | null + dg_account: string | null + id: number | null + metadata: Json | null + name: string | null + platform: Database["public"]["Enums"]["Platform"] | null + write_permission: boolean | null + }[] + } compute_arity_local: { Args: { lit_content: Json; schema_id: number } Returns: number @@ -934,6 +1137,24 @@ export type Database = { Args: { content_id: number } Returns: boolean } + content_of_concept: { + Args: { concept: unknown } + Returns: { + author_id: number | null + created: string | null + creator_id: number | null + document_id: number | null + id: number | null + last_modified: string | null + metadata: Json | null + part_of_id: number | null + scale: Database["public"]["Enums"]["Scale"] | null + source_local_id: string | null + space_id: number | null + text: string | null + variant: Database["public"]["Enums"]["ContentVariant"] | null + }[] + } create_account_in_space: { Args: { account_local_id_: string @@ -949,6 +1170,20 @@ export type Database = { Args: { document_id: number } Returns: boolean } + document_of_content: { + Args: { content: unknown } + Returns: { + author_id: number | null + contents: unknown | null + created: string | null + id: number | null + last_modified: string | null + metadata: Json | null + source_local_id: string | null + space_id: number | null + url: string | null + }[] + } end_sync_task: { Args: { s_function: string @@ -1033,7 +1268,7 @@ export type Database = { Args: Record Returns: number } - my_spaces: { + my_space_ids: { Args: Record Returns: number[] } From d7a302c1d8f31af5d058e5354e4b7b268a387fa5 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Sun, 12 Oct 2025 22:55:39 -0400 Subject: [PATCH 04/10] optimization for rls case --- .../supabase/migrations/20251008131345_security_views.sql | 6 +++++- packages/database/supabase/schemas/account.sql | 6 +++++- 2 files changed, 10 insertions(+), 2 deletions(-) diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql index c0d0aa87c..f1f6b8447 100644 --- a/packages/database/supabase/migrations/20251008131345_security_views.sql +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -46,7 +46,11 @@ STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT space_id = ANY(public.my_space_ids()); + WITH u AS (SELECT auth.uid() LIMIT 1), + pa AS (SELECT sa.space_id AS id FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id + JOIN u ON pa.dg_account = u.uid) + SELECT EXISTS (SELECT id FROM pa WHERE id = space_id ); $$; COMMENT ON FUNCTION public.in_space IS 'security utility: does current user have access to this space?'; diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index d5d3a03dc..6e441cc0d 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -224,7 +224,11 @@ STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT space_id = ANY(public.my_space_ids()); + WITH u AS (SELECT auth.uid() LIMIT 1), + pa AS (SELECT sa.space_id AS id FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON pa.id=sa.account_id + JOIN u ON pa.dg_account = u.uid) + SELECT EXISTS (SELECT id FROM pa WHERE id = space_id ); $$; COMMENT ON FUNCTION public.in_space IS 'security utility: does current user have access to this space?'; From b8b6916945bd8acaff22dce7d423e60475060ee8 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Mon, 13 Oct 2025 11:22:39 -0400 Subject: [PATCH 05/10] optimize access to my_accounts --- packages/database/package.json | 1 + packages/database/src/lib/queries.ts | 4 ++-- .../supabase/migrations/20251008131345_security_views.sql | 3 ++- packages/database/supabase/schemas/account.sql | 4 ++-- 4 files changed, 7 insertions(+), 5 deletions(-) diff --git a/packages/database/package.json b/packages/database/package.json index c8bda01eb..e157f79ce 100644 --- a/packages/database/package.json +++ b/packages/database/package.json @@ -26,6 +26,7 @@ "dev": "pnpm run setup && pnpm run serve", "build": "pnpm run setup && tsc", "serve": "tsx scripts/serve.ts", + "bench": "tsx scripts/bench.mts", "stop": "supabase stop", "check-types": "tsc --noEmit --skipLibCheck", "check-schema": "tsx scripts/lintSchemas.ts && supabase stop && pnpm run dbdiff", diff --git a/packages/database/src/lib/queries.ts b/packages/database/src/lib/queries.ts index 05e6325d5..04f2caa9e 100644 --- a/packages/database/src/lib/queries.ts +++ b/packages/database/src/lib/queries.ts @@ -121,7 +121,7 @@ const composeConceptQuery = ({ q += `,\nContent:content_of_concept${innerContent ? "!inner" : ""} (\n${args.join(",\n")})`; } if (nodeAuthor !== undefined) { - q += ", author:author_id!inner(account_local_id)"; + q += ", author:author_of_concept!inner(account_local_id)"; } if ( inRelsOfType !== undefined || @@ -144,7 +144,7 @@ const composeConceptQuery = ({ args2.push("Content:content_of_concept!inner(source_local_id)"); if (inRelsToNodesOfAuthor !== undefined) { if (!args2.includes("author_id")) args2.push("author_id"); - args2.push("author:author_id!inner(account_local_id)"); + args2.push("author:author_of_concept!inner(account_local_id)"); } args.push(`subnodes:concepts_of_relation!inner(${args2.join(",\n")})`); } diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql index f1f6b8447..8d2c80278 100644 --- a/packages/database/supabase/migrations/20251008131345_security_views.sql +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -119,7 +119,8 @@ SELECT pa.dg_account FROM public."PlatformAccount" AS pa JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) -WHERE sa.space_id = ANY(public.my_space_ids()); +WHERE sa.space_id = ANY(public.my_space_ids()) +GROUP BY pa.id; CREATE OR REPLACE VIEW public.my_documents AS diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index 6e441cc0d..b52b1a3ec 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -295,8 +295,8 @@ SELECT pa.dg_account FROM public."PlatformAccount" AS pa JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) -WHERE sa.space_id = ANY(public.my_space_ids()); - +WHERE sa.space_id = ANY(public.my_space_ids()) +GROUP BY pa.id; DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); From 183acb52602351caef2ace0bbb0fca5213939f60 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Mon, 13 Oct 2025 16:27:56 -0400 Subject: [PATCH 06/10] optimize access to embeddings --- .../database/supabase/schemas/embedding.sql | 37 ++++++++++++++----- 1 file changed, 27 insertions(+), 10 deletions(-) diff --git a/packages/database/supabase/schemas/embedding.sql b/packages/database/supabase/schemas/embedding.sql index 6d72b8c86..5e02fddc1 100644 --- a/packages/database/supabase/schemas/embedding.sql +++ b/packages/database/supabase/schemas/embedding.sql @@ -28,6 +28,27 @@ REVOKE ALL ON TABLE public."ContentEmbedding_openai_text_embedding_3_small_1536" GRANT ALL ON TABLE public."ContentEmbedding_openai_text_embedding_3_small_1536" TO "authenticated" ; GRANT ALL ON TABLE public."ContentEmbedding_openai_text_embedding_3_small_1536" TO "service_role" ; +CREATE OR REPLACE VIEW public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS +SELECT + ct.id, + ct.document_id, + ct.source_local_id, + ct.variant, + ct.author_id, + ct.creator_id, + ct.created, + ct.text, + ct.metadata, + ct.scale, + ct.space_id, + ct.last_modified, + ct.part_of_id, + emb.model, + emb.vector +FROM public."Content" AS ct +JOIN public."ContentEmbedding_openai_text_embedding_3_small_1536" AS emb ON (ct.id=emb.target_id) +WHERE ct.space_id = any(public.my_space_ids()) AND NOT emb.obsolete; + set search_path to public, extensions ; CREATE OR REPLACE FUNCTION public.match_content_embeddings ( @@ -47,14 +68,12 @@ SELECT c.id AS content_id, c.source_local_id AS roam_uid, c.text AS text_content, - 1 - (ce.vector <=> query_embedding) AS similarity -FROM public."ContentEmbedding_openai_text_embedding_3_small_1536" AS ce -JOIN public."Content" AS c ON ce.target_id = c.id -WHERE 1 - (ce.vector <=> query_embedding) > match_threshold - AND ce.obsolete = FALSE + 1 - (c.vector <=> query_embedding) AS similarity +FROM public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS c +WHERE 1 - (c.vector <=> query_embedding) > match_threshold AND (current_document_id IS NULL OR c.document_id = current_document_id) ORDER BY - ce.vector <=> query_embedding ASC + c.vector <=> query_embedding ASC LIMIT match_count; $$ ; @@ -80,12 +99,10 @@ WITH subset_content_with_embeddings AS ( c.id AS content_id, c.source_local_id AS roam_uid, c.text AS text_content, - ce.vector AS embedding_vector - FROM public."Content" AS c - JOIN public."ContentEmbedding_openai_text_embedding_3_small_1536" AS ce ON c.id = ce.target_id + c.vector AS embedding_vector + FROM public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS c WHERE c.source_local_id = ANY(p_subset_roam_uids) -- Filter Content by the provided Roam UIDs - AND ce.obsolete = FALSE ) SELECT ss_ce.content_id, From 80f90322f35e77d5bb0ef381b41a589ecb50b401 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Mon, 13 Oct 2025 16:47:08 -0400 Subject: [PATCH 07/10] avoid policy overlap. Also forgot to add embedding view to migration --- .../20251008131345_security_views.sql | 109 +++++++++++++++++- .../database/supabase/schemas/account.sql | 30 ++++- 2 files changed, 133 insertions(+), 6 deletions(-) diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql index 8d2c80278..3cc112fc9 100644 --- a/packages/database/supabase/migrations/20251008131345_security_views.sql +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -81,23 +81,48 @@ $$; COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this unowned account?'; DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; -CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); DROP POLICY IF EXISTS platform_account_select_policy ON public."PlatformAccount"; CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SELECT USING (dg_account = (SELECT auth.uid() LIMIT 1) OR public.account_in_shared_space(id)); +DROP POLICY IF EXISTS platform_account_delete_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_delete_policy ON public."PlatformAccount" FOR DELETE USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + +DROP POLICY IF EXISTS platform_account_insert_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_insert_policy ON public."PlatformAccount" FOR INSERT WITH CHECK (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + +DROP POLICY IF EXISTS platform_account_update_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_update_policy ON public."PlatformAccount" FOR UPDATE WITH CHECK (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + DROP POLICY IF EXISTS space_access_policy ON public."SpaceAccess"; -CREATE POLICY space_access_policy ON public."SpaceAccess" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS space_access_select_policy ON public."SpaceAccess"; CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR SELECT USING (public.in_space(space_id)); +DROP POLICY IF EXISTS space_access_delete_policy ON public."SpaceAccess"; +CREATE POLICY space_access_delete_policy ON public."SpaceAccess" FOR DELETE USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS space_access_insert_policy ON public."SpaceAccess"; +CREATE POLICY space_access_insert_policy ON public."SpaceAccess" FOR INSERT WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS space_access_update_policy ON public."SpaceAccess"; +CREATE POLICY space_access_update_policy ON public."SpaceAccess" FOR UPDATE WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + + DROP POLICY IF EXISTS agent_identifier_policy ON public."AgentIdentifier"; -CREATE POLICY agent_identifier_policy ON public."AgentIdentifier" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS agent_identifier_select_policy ON public."AgentIdentifier"; CREATE POLICY agent_identifier_select_policy ON public."AgentIdentifier" FOR SELECT USING (public.account_in_shared_space(account_id)); +DROP POLICY IF EXISTS agent_identifier_delete_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_delete_policy ON public."AgentIdentifier" FOR DELETE USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS agent_identifier_insert_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_insert_policy ON public."AgentIdentifier" FOR INSERT WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS agent_identifier_update_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_update_policy ON public."AgentIdentifier" FOR UPDATE WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + CREATE OR REPLACE VIEW public.my_spaces AS SELECT id, @@ -258,3 +283,81 @@ AS $$ $$; COMMENT ON FUNCTION public.author_of_concept(public.my_concepts) IS 'Computed one-to-one: returns the PlatformAccount which authored a given Concept.'; + +CREATE OR REPLACE VIEW public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS +SELECT + ct.id, + ct.document_id, + ct.source_local_id, + ct.variant, + ct.author_id, + ct.creator_id, + ct.created, + ct.text, + ct.metadata, + ct.scale, + ct.space_id, + ct.last_modified, + ct.part_of_id, + emb.model, + emb.vector +FROM public."Content" AS ct +JOIN public."ContentEmbedding_openai_text_embedding_3_small_1536" AS emb ON (ct.id=emb.target_id) +WHERE ct.space_id = any(public.my_space_ids()) AND NOT emb.obsolete; + + +CREATE OR REPLACE FUNCTION public.match_content_embeddings ( +query_embedding extensions.vector, +match_threshold double precision, +match_count integer, +current_document_id integer DEFAULT NULL::integer) +RETURNS TABLE ( +content_id bigint, +roam_uid Text, +text_content Text, +similarity double precision) +SET search_path = 'extensions' +LANGUAGE sql STABLE +AS $$ +SELECT + c.id AS content_id, + c.source_local_id AS roam_uid, + c.text AS text_content, + 1 - (c.vector <=> query_embedding) AS similarity +FROM public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS c +WHERE 1 - (c.vector <=> query_embedding) > match_threshold + AND (current_document_id IS NULL OR c.document_id = current_document_id) +ORDER BY + c.vector <=> query_embedding ASC +LIMIT match_count; +$$ ; + +CREATE OR REPLACE FUNCTION public.match_embeddings_for_subset_nodes ( +"p_query_embedding" extensions.vector, +"p_subset_roam_uids" Text []) +RETURNS TABLE (content_id bigint, +roam_uid Text, +text_content Text, +similarity double precision) +LANGUAGE sql STABLE +SET search_path = 'extensions' +AS $$ +WITH subset_content_with_embeddings AS ( + -- Step 1: Identify content and fetch embeddings ONLY for the nodes in the provided Roam UID subset + SELECT + c.id AS content_id, + c.source_local_id AS roam_uid, + c.text AS text_content, + c.vector AS embedding_vector + FROM public.my_contents_with_embedding_openai_text_embedding_3_small_1536 AS c + WHERE + c.source_local_id = ANY(p_subset_roam_uids) -- Filter Content by the provided Roam UIDs +) +SELECT + ss_ce.content_id, + ss_ce.roam_uid, + ss_ce.text_content, + 1 - (ss_ce.embedding_vector <=> p_query_embedding) AS similarity +FROM subset_content_with_embeddings AS ss_ce +ORDER BY similarity DESC; -- Order by calculated similarity, highest first +$$ ; diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index b52b1a3ec..97dde4420 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -299,11 +299,19 @@ WHERE sa.space_id = ANY(public.my_space_ids()) GROUP BY pa.id; DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; -CREATE POLICY platform_account_policy ON public."PlatformAccount" FOR ALL USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); DROP POLICY IF EXISTS platform_account_select_policy ON public."PlatformAccount"; CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SELECT USING (dg_account = (SELECT auth.uid() LIMIT 1) OR public.account_in_shared_space(id)); +DROP POLICY IF EXISTS platform_account_delete_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_delete_policy ON public."PlatformAccount" FOR DELETE USING (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + +DROP POLICY IF EXISTS platform_account_insert_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_insert_policy ON public."PlatformAccount" FOR INSERT WITH CHECK (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + +DROP POLICY IF EXISTS platform_account_update_policy ON public."PlatformAccount"; +CREATE POLICY platform_account_update_policy ON public."PlatformAccount" FOR UPDATE WITH CHECK (dg_account = (SELECT auth.uid() LIMIT 1) OR (dg_account IS null AND public.unowned_account_in_shared_space(id))); + -- SpaceAccess: Created through the create_account_in_space and the Space create route, both of which bypass RLS. -- Can be updated by a space peer for now, unless claimed by a user. -- Eventually: Allow space admin to modify? @@ -311,18 +319,34 @@ CREATE POLICY platform_account_select_policy ON public."PlatformAccount" FOR SEL ALTER TABLE public."SpaceAccess" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS space_access_policy ON public."SpaceAccess"; -CREATE POLICY space_access_policy ON public."SpaceAccess" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS space_access_select_policy ON public."SpaceAccess"; CREATE POLICY space_access_select_policy ON public."SpaceAccess" FOR SELECT USING (public.in_space(space_id)); +DROP POLICY IF EXISTS space_access_delete_policy ON public."SpaceAccess"; +CREATE POLICY space_access_delete_policy ON public."SpaceAccess" FOR DELETE USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS space_access_insert_policy ON public."SpaceAccess"; +CREATE POLICY space_access_insert_policy ON public."SpaceAccess" FOR INSERT WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS space_access_update_policy ON public."SpaceAccess"; +CREATE POLICY space_access_update_policy ON public."SpaceAccess" FOR UPDATE WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + -- AgentIdentifier: Allow space members to do anything, to allow editing authors. -- Eventually: Once the account is claimed by a user, only allow this user to modify it. ALTER TABLE public."AgentIdentifier" ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS agent_identifier_policy ON public."AgentIdentifier"; -CREATE POLICY agent_identifier_policy ON public."AgentIdentifier" FOR ALL USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); DROP POLICY IF EXISTS agent_identifier_select_policy ON public."AgentIdentifier"; CREATE POLICY agent_identifier_select_policy ON public."AgentIdentifier" FOR SELECT USING (public.account_in_shared_space(account_id)); + +DROP POLICY IF EXISTS agent_identifier_delete_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_delete_policy ON public."AgentIdentifier" FOR DELETE USING (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS agent_identifier_insert_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_insert_policy ON public."AgentIdentifier" FOR INSERT WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); + +DROP POLICY IF EXISTS agent_identifier_update_policy ON public."AgentIdentifier"; +CREATE POLICY agent_identifier_update_policy ON public."AgentIdentifier" FOR UPDATE WITH CHECK (public.unowned_account_in_shared_space(account_id) OR account_id = public.my_account()); From 2ae86d3f86ab3f6309b1d7240af5f722477e28cf Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Tue, 14 Oct 2025 11:11:02 -0400 Subject: [PATCH 08/10] Use foreign key, not computed relation, where possible --- packages/database/src/lib/queries.ts | 12 +++++++----- 1 file changed, 7 insertions(+), 5 deletions(-) diff --git a/packages/database/src/lib/queries.ts b/packages/database/src/lib/queries.ts index 04f2caa9e..aa1f3921e 100644 --- a/packages/database/src/lib/queries.ts +++ b/packages/database/src/lib/queries.ts @@ -115,13 +115,13 @@ const composeConceptQuery = ({ const args: string[] = contentFields.slice(); if (documentFields.length > 0) { args.push( - "Document:document_of_content (\n" + documentFields.join(",\n") + ")", + `Document:my_documents!document_id${innerContent ? "!inner" : ""} (\n${documentFields.join(",\n")})`, ); } - q += `,\nContent:content_of_concept${innerContent ? "!inner" : ""} (\n${args.join(",\n")})`; + q += `,\nContent:my_contents!represented_by_id${innerContent ? "!inner" : ""} (\n${args.join(",\n")})`; } if (nodeAuthor !== undefined) { - q += ", author:author_of_concept!inner(account_local_id)"; + q += ", author:my_accounts!author_id!inner(account_local_id)"; } if ( inRelsOfType !== undefined || @@ -141,10 +141,12 @@ const composeConceptQuery = ({ if (inRelsToNodesOfType !== undefined && !args2.includes("schema_id")) args2.push("schema_id"); if (inRelsToNodeLocalIds !== undefined) - args2.push("Content:content_of_concept!inner(source_local_id)"); + args2.push( + "Content:my_contents!represented_by_id!inner(source_local_id)", + ); if (inRelsToNodesOfAuthor !== undefined) { if (!args2.includes("author_id")) args2.push("author_id"); - args2.push("author:author_of_concept!inner(account_local_id)"); + args2.push("author:my_accounts!author_id!inner(account_local_id)"); } args.push(`subnodes:concepts_of_relation!inner(${args2.join(",\n")})`); } From 5606d303133bcdce2ced5ea2fdaaae0ba1219031 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Tue, 14 Oct 2025 20:13:30 -0400 Subject: [PATCH 09/10] coderabbit suggestions --- .../20251008131345_security_views.sql | 33 ++++++++++++------- .../supabase/schemas/access_token.sql | 2 +- .../database/supabase/schemas/account.sql | 32 +++++++++++------- 3 files changed, 43 insertions(+), 24 deletions(-) diff --git a/packages/database/supabase/migrations/20251008131345_security_views.sql b/packages/database/supabase/migrations/20251008131345_security_views.sql index 3cc112fc9..1821cfddc 100644 --- a/packages/database/supabase/migrations/20251008131345_security_views.sql +++ b/packages/database/supabase/migrations/20251008131345_security_views.sql @@ -1,7 +1,7 @@ ALTER FUNCTION public.my_account RENAME TO is_my_account; DROP POLICY IF EXISTS access_token_policy ON public.access_token; -CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (public.is_my_account(platform_account_id)); +CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (platform_account_id IS NULL OR public.is_my_account(platform_account_id)); CREATE OR REPLACE FUNCTION public.is_my_account(account_id BIGINT) RETURNS boolean STABLE SECURITY DEFINER @@ -60,9 +60,12 @@ CREATE OR REPLACE FUNCTION public.account_in_shared_space(p_account_id BIGINT) R STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa - WHERE sa.account_id = p_account_id - AND sa.space_id = ANY(public.my_space_ids()); + SELECT EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + ); $$; COMMENT ON FUNCTION public.account_in_shared_space IS 'security utility: does current user share a space with this account?'; @@ -71,11 +74,14 @@ CREATE OR REPLACE FUNCTION public.unowned_account_in_shared_space(p_account_id B STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa - JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) - WHERE sa.account_id = p_account_id - AND sa.space_id = ANY(public.my_space_ids()) - AND pa.dg_account IS NULL; + SELECT EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + AND pa.dg_account IS NULL + ); $$; COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this unowned account?'; @@ -143,9 +149,12 @@ SELECT pa.metadata, pa.dg_account FROM public."PlatformAccount" AS pa -JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) -WHERE sa.space_id = ANY(public.my_space_ids()) -GROUP BY pa.id; +WHERE EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + WHERE sa.account_id = pa.id + AND sa.space_id = ANY(public.my_space_ids()) +); CREATE OR REPLACE VIEW public.my_documents AS diff --git a/packages/database/supabase/schemas/access_token.sql b/packages/database/supabase/schemas/access_token.sql index 4fc2ba802..19f5395fd 100644 --- a/packages/database/supabase/schemas/access_token.sql +++ b/packages/database/supabase/schemas/access_token.sql @@ -40,4 +40,4 @@ GRANT INSERT ON TABLE "public"."access_token" TO "anon"; ALTER TABLE public.access_token ENABLE ROW LEVEL SECURITY; DROP POLICY IF EXISTS access_token_policy ON public.access_token; -CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (public.is_my_account(platform_account_id)); +CREATE POLICY access_token_policy ON public.access_token FOR ALL USING (platform_account_id IS NULL OR public.is_my_account(platform_account_id)); diff --git a/packages/database/supabase/schemas/account.sql b/packages/database/supabase/schemas/account.sql index 97dde4420..80944dc83 100644 --- a/packages/database/supabase/schemas/account.sql +++ b/packages/database/supabase/schemas/account.sql @@ -238,9 +238,12 @@ CREATE OR REPLACE FUNCTION public.account_in_shared_space(p_account_id BIGINT) R STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa - WHERE sa.account_id = p_account_id - AND sa.space_id = ANY(public.my_space_ids()); + SELECT EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + ); $$; COMMENT ON FUNCTION public.account_in_shared_space IS 'security utility: does current user share a space with this account?'; @@ -249,11 +252,14 @@ CREATE OR REPLACE FUNCTION public.unowned_account_in_shared_space(p_account_id B STABLE SECURITY DEFINER SET search_path = '' LANGUAGE sql AS $$ - SELECT count(sa.account_id) > 0 FROM public."SpaceAccess" AS sa - JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) - WHERE sa.account_id = p_account_id - AND sa.space_id = ANY(public.my_space_ids()) - AND pa.dg_account IS NULL; + SELECT EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + JOIN public."PlatformAccount" AS pa ON (pa.id = sa.account_id) + WHERE sa.account_id = p_account_id + AND sa.space_id = ANY(public.my_space_ids()) + AND pa.dg_account IS NULL + ); $$; COMMENT ON FUNCTION public.unowned_account_in_shared_space IS 'security utility: does current user share a space with this unowned account?'; @@ -294,9 +300,13 @@ SELECT pa.metadata, pa.dg_account FROM public."PlatformAccount" AS pa -JOIN public."SpaceAccess" AS sa ON (sa.account_id = pa.id) -WHERE sa.space_id = ANY(public.my_space_ids()) -GROUP BY pa.id; +WHERE EXISTS ( + SELECT 1 + FROM public."SpaceAccess" AS sa + WHERE + sa.account_id = pa.id + AND sa.space_id = any(public.my_space_ids()) +); DROP POLICY IF EXISTS platform_account_policy ON public."PlatformAccount"; From 5d724dc7c7d01f36e8aec75930005b078c598154 Mon Sep 17 00:00:00 2001 From: Marc-Antoine Parent Date: Tue, 14 Oct 2025 20:15:12 -0400 Subject: [PATCH 10/10] forgot line from ENG-376 --- packages/database/package.json | 1 - 1 file changed, 1 deletion(-) diff --git a/packages/database/package.json b/packages/database/package.json index e157f79ce..c8bda01eb 100644 --- a/packages/database/package.json +++ b/packages/database/package.json @@ -26,7 +26,6 @@ "dev": "pnpm run setup && pnpm run serve", "build": "pnpm run setup && tsc", "serve": "tsx scripts/serve.ts", - "bench": "tsx scripts/bench.mts", "stop": "supabase stop", "check-types": "tsc --noEmit --skipLibCheck", "check-schema": "tsx scripts/lintSchemas.ts && supabase stop && pnpm run dbdiff",