-
Notifications
You must be signed in to change notification settings - Fork 0
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
Showing
3 changed files
with
132 additions
and
7 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,65 @@ | ||
CREATE | ||
OR REPLACE FUNCTION fix_corrupted_baselayers () | ||
RETURNS void | ||
AS $body$ | ||
DECLARE | ||
_default_ctx_id uuid; | ||
_proj_doc_array uuid[]; | ||
_proj_row public.projects % rowtype; | ||
_ctx_doc_row public.context_documents; | ||
_layer_context_row public.layer_contexts % rowtype; | ||
BEGIN | ||
-- This script fixes corrupted baselayers using the following steps | ||
-- 1. Iterate through all projects | ||
FOR _proj_row IN SELECT * FROM public.projects p | ||
LOOP | ||
-- 2. For each project get the default context | ||
SELECT c.id INTO _default_ctx_id FROM public.contexts c | ||
WHERE c.project_id = _proj_row.id | ||
AND c.is_project_default IS TRUE | ||
AND c.is_archived IS NOT TRUE; | ||
|
||
-- 3. Create an array of project_document ids | ||
_proj_doc_array := ARRAY(SELECT pd.document_id FROM public.project_documents pd WHERE pd.project_id = _proj_row.id AND pd.is_archived IS NOT TRUE); | ||
RAISE LOG 'Doc Array for project %: %', _proj_row.id, _proj_doc_array; | ||
|
||
-- 4. Archive any context documents that reference documents not in the project_documents array | ||
|
||
IF EXISTS( | ||
SELECT 1 a | ||
FROM public.context_documents cd | ||
WHERE cd.context_id = _default_ctx_id | ||
AND cd.is_archived IS NOT TRUE | ||
AND NOT (cd.document_id = ANY(_proj_doc_array))) | ||
THEN | ||
FOR _ctx_doc_row IN SELECT * | ||
FROM public.context_documents cd | ||
WHERE cd.context_id = _default_ctx_id | ||
AND cd.is_archived IS NOT TRUE | ||
AND NOT (cd.document_id = ANY(_proj_doc_array)) | ||
LOOP | ||
UPDATE public.context_documents cd | ||
SET is_archived = TRUE | ||
WHERE cd.id = _ctx_doc_row.id; | ||
|
||
-- 5. Archive any layer contexts and layers associated with these documents | ||
FOR _layer_context_row IN SELECT * | ||
FROM public.layer_contexts lc | ||
INNER JOIN public.layers l ON l.project_id = _proj_row.id | ||
AND (l.document_id = _ctx_doc_row.document_id OR NOT (l.document_id = ANY(_proj_doc_array))) | ||
AND l.is_archived IS NOT TRUE | ||
WHERE lc.layer_id = l.id AND lc.context_id = _default_ctx_id | ||
LOOP | ||
UPDATE public.layer_contexts lc | ||
SET is_archived = TRUE | ||
WHERE lc.id = _layer_context_row.id; | ||
|
||
UPDATE public.layers l | ||
SET is_archived = TRUE | ||
WHERE l.id = _layer_context_row.layer_id; | ||
END LOOP; | ||
END LOOP; | ||
END IF; | ||
END LOOP; | ||
END; | ||
$body$ LANGUAGE plpgsql SECURITY DEFINER; |
58 changes: 58 additions & 0 deletions
58
supabase/migrations/20240821143058_fix_context_deletion.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,58 @@ | ||
set check_function_bodies = off; | ||
|
||
CREATE | ||
OR REPLACE FUNCTION archive_context_rpc ( | ||
_context_id uuid | ||
) RETURNS BOOLEAN AS $body$ | ||
DECLARE | ||
_project_id uuid; | ||
_layer_id uuid; | ||
_document_id uuid; | ||
_row RECORD; | ||
_row_2 RECORD; | ||
BEGIN | ||
-- Find the project for this context | ||
SELECT p.id INTO _project_id FROM public.projects p | ||
INNER JOIN public.contexts c ON c.id = _context_id | ||
WHERE p.id = c.project_id; | ||
|
||
-- Check project policy that context documents can be updated by this user | ||
IF NOT (check_action_policy_organization(auth.uid(), 'contexts', 'UPDATE') | ||
OR check_action_policy_project(auth.uid(), 'contexts', 'UPDATE', _project_id)) | ||
THEN | ||
RAISE LOG 'Check action policy failed for project %', _project_id; | ||
RETURN FALSE; | ||
END IF; | ||
|
||
-- Iterate through the document ids in this context and archive them in all context_documents | ||
FOR _row IN SELECT * FROM public.context_documents cd WHERE cd.context_id = _context_id | ||
LOOP | ||
-- Archive the context_documents record | ||
UPDATE public.context_documents cd | ||
SET is_archived = TRUE | ||
WHERE cd.id = _row.id; | ||
|
||
-- Archive any related layers | ||
FOR _row_2 IN SELECT * FROM public.layer_contexts lc | ||
WHERE lc.context_id = _context_id | ||
LOOP | ||
IF _row_2.is_active_layer IS TRUE | ||
THEN | ||
UPDATE public.layers l | ||
SET is_archived = TRUE | ||
WHERE l.id = _row_2.layer_id; | ||
END IF; | ||
|
||
UPDATE public.layer_contexts lc | ||
SET is_archived = TRUE | ||
WHERE lc.id = _row_2.id; | ||
END LOOP; | ||
|
||
END LOOP; | ||
|
||
UPDATE public.contexts | ||
SET is_archived = TRUE | ||
WHERE id = _context_id; | ||
RETURN TRUE; | ||
END | ||
$body$ LANGUAGE plpgsql SECURITY DEFINER; |