|
| 1 | +-- Add level column to objects |
| 2 | +ALTER TABLE storage.objects ADD COLUMN IF NOT EXISTS level INT NULL; |
| 3 | + |
| 4 | +--- Index Functions |
| 5 | +CREATE OR REPLACE FUNCTION "storage"."get_level"("name" text) |
| 6 | + RETURNS int |
| 7 | +AS $func$ |
| 8 | +SELECT array_length(string_to_array("name", '/'), 1); |
| 9 | +$func$ LANGUAGE SQL IMMUTABLE STRICT; |
| 10 | + |
| 11 | + |
| 12 | +-- Function to check if object with prefix exists |
| 13 | +CREATE OR REPLACE FUNCTION storage.object_exists_with_prefix( |
| 14 | + p_bucket_id TEXT, |
| 15 | + p_name TEXT |
| 16 | +) |
| 17 | + RETURNS BOOLEAN |
| 18 | + LANGUAGE plpgsql |
| 19 | + STABLE |
| 20 | + SECURITY INVOKER |
| 21 | +AS $$ |
| 22 | +BEGIN |
| 23 | + RETURN EXISTS ( |
| 24 | + SELECT 1 |
| 25 | + FROM storage.objects o |
| 26 | + WHERE o.bucket_id = p_bucket_id |
| 27 | + AND o.name LIKE p_name || '%' |
| 28 | + ); |
| 29 | +END; |
| 30 | +$$; |
| 31 | + |
| 32 | +-- Table |
| 33 | +CREATE TABLE IF NOT EXISTS "storage"."prefixes" ( |
| 34 | + "bucket_id" text, |
| 35 | + "name" text COLLATE "C" NOT NULL, |
| 36 | + "level" int GENERATED ALWAYS AS ("storage"."get_level"("name")) STORED, |
| 37 | + "created_at" timestamptz DEFAULT now(), |
| 38 | + "updated_at" timestamptz DEFAULT now(), |
| 39 | + CONSTRAINT "prefixes_bucketId_fkey" FOREIGN KEY ("bucket_id") REFERENCES "storage"."buckets"("id"), |
| 40 | + PRIMARY KEY ("bucket_id", "level", "name") |
| 41 | +); |
| 42 | + |
| 43 | +ALTER TABLE storage.prefixes ENABLE ROW LEVEL SECURITY; |
| 44 | + |
| 45 | +DROP POLICY IF EXISTS "prefixes_allow_select_for_owned_objects" ON "storage"."prefixes"; |
| 46 | +CREATE POLICY "prefixes_allow_select_for_owned_objects" ON "storage"."prefixes" |
| 47 | + FOR SELECT |
| 48 | + USING ( |
| 49 | + (storage.object_exists_with_prefix("bucket_id", "name")) |
| 50 | + ); |
| 51 | + |
| 52 | +-- Functions |
| 53 | +CREATE OR REPLACE FUNCTION "storage"."get_prefix"("name" text) |
| 54 | + RETURNS text |
| 55 | +AS $func$ |
| 56 | +SELECT |
| 57 | + CASE WHEN strpos("name", '/') > 0 THEN |
| 58 | + regexp_replace("name", '[\/]{1}[^\/]+\/?$', '') |
| 59 | + ELSE |
| 60 | + '' |
| 61 | + END; |
| 62 | +$func$ LANGUAGE SQL IMMUTABLE STRICT; |
| 63 | + |
| 64 | +CREATE OR REPLACE FUNCTION "storage"."get_prefixes"("name" text) |
| 65 | + RETURNS text[] |
| 66 | +AS $func$ |
| 67 | +DECLARE |
| 68 | + parts text[]; |
| 69 | + prefixes text[]; |
| 70 | + prefix text; |
| 71 | +BEGIN |
| 72 | + -- Split the name into parts by '/' |
| 73 | + parts := string_to_array("name", '/'); |
| 74 | + prefixes := '{}'; |
| 75 | + |
| 76 | + -- Construct the prefixes, stopping one level below the last part |
| 77 | + FOR i IN 1..array_length(parts, 1) - 1 LOOP |
| 78 | + prefix := array_to_string(parts[1:i], '/'); |
| 79 | + prefixes := array_append(prefixes, prefix); |
| 80 | + END LOOP; |
| 81 | + |
| 82 | + RETURN prefixes; |
| 83 | +END; |
| 84 | +$func$ LANGUAGE plpgsql IMMUTABLE STRICT; |
| 85 | + |
| 86 | +CREATE OR REPLACE FUNCTION "storage"."add_prefixes"( |
| 87 | + "_bucket_id" TEXT, |
| 88 | + "_name" TEXT |
| 89 | +) |
| 90 | +RETURNS void |
| 91 | +SECURITY DEFINER |
| 92 | +AS $func$ |
| 93 | +DECLARE |
| 94 | + prefixes text[]; |
| 95 | +BEGIN |
| 96 | + prefixes := "storage"."get_prefixes"("_name"); |
| 97 | + |
| 98 | + IF array_length(prefixes, 1) > 0 THEN |
| 99 | + INSERT INTO storage.prefixes (name, bucket_id) |
| 100 | + SELECT UNNEST(prefixes) as name, "_bucket_id" ON CONFLICT DO NOTHING; |
| 101 | + END IF; |
| 102 | +END; |
| 103 | +$func$ LANGUAGE plpgsql VOLATILE; |
| 104 | + |
| 105 | +CREATE OR REPLACE FUNCTION "storage"."delete_prefix" ( |
| 106 | + "_bucket_id" TEXT, |
| 107 | + "_name" TEXT |
| 108 | +) RETURNS boolean |
| 109 | +SECURITY DEFINER |
| 110 | +AS $func$ |
| 111 | +BEGIN |
| 112 | + -- Check if we can delete the prefix |
| 113 | + IF EXISTS( |
| 114 | + SELECT FROM "storage"."prefixes" |
| 115 | + WHERE "prefixes"."bucket_id" = "_bucket_id" |
| 116 | + AND level = "storage"."get_level"("_name") + 1 |
| 117 | + AND "prefixes"."name" COLLATE "C" LIKE "_name" || '/%' |
| 118 | + LIMIT 1 |
| 119 | + ) |
| 120 | + OR EXISTS( |
| 121 | + SELECT FROM "storage"."objects" |
| 122 | + WHERE "objects"."bucket_id" = "_bucket_id" |
| 123 | + AND "storage"."get_level"("objects"."name") = "storage"."get_level"("_name") + 1 |
| 124 | + AND "objects"."name" COLLATE "C" LIKE "_name" || '/%' |
| 125 | + LIMIT 1 |
| 126 | + ) THEN |
| 127 | + -- There are sub-objects, skip deletion |
| 128 | + RETURN false; |
| 129 | + ELSE |
| 130 | + DELETE FROM "storage"."prefixes" |
| 131 | + WHERE "prefixes"."bucket_id" = "_bucket_id" |
| 132 | + AND level = "storage"."get_level"("_name") |
| 133 | + AND "prefixes"."name" = "_name"; |
| 134 | + RETURN true; |
| 135 | + END IF; |
| 136 | +END; |
| 137 | +$func$ LANGUAGE plpgsql VOLATILE; |
| 138 | + |
| 139 | +-- Triggers |
| 140 | +CREATE OR REPLACE FUNCTION "storage"."prefixes_insert_trigger"() |
| 141 | + RETURNS trigger |
| 142 | +AS $func$ |
| 143 | +BEGIN |
| 144 | + PERFORM "storage"."add_prefixes"(NEW."bucket_id", NEW."name"); |
| 145 | + RETURN NEW; |
| 146 | +END; |
| 147 | +$func$ LANGUAGE plpgsql VOLATILE; |
| 148 | + |
| 149 | +CREATE OR REPLACE FUNCTION "storage"."objects_insert_prefix_trigger"() |
| 150 | + RETURNS trigger |
| 151 | +AS $func$ |
| 152 | +BEGIN |
| 153 | + PERFORM "storage"."add_prefixes"(NEW."bucket_id", NEW."name"); |
| 154 | + NEW.level := "storage"."get_level"(NEW."name"); |
| 155 | + |
| 156 | + RETURN NEW; |
| 157 | +END; |
| 158 | +$func$ LANGUAGE plpgsql VOLATILE; |
| 159 | + |
| 160 | +CREATE OR REPLACE FUNCTION "storage"."delete_prefix_hierarchy_trigger"() |
| 161 | + RETURNS trigger |
| 162 | +AS $func$ |
| 163 | +DECLARE |
| 164 | + prefix text; |
| 165 | +BEGIN |
| 166 | + prefix := "storage"."get_prefix"(OLD."name"); |
| 167 | + |
| 168 | + IF coalesce(prefix, '') != '' THEN |
| 169 | + PERFORM "storage"."delete_prefix"(OLD."bucket_id", prefix); |
| 170 | + END IF; |
| 171 | + |
| 172 | + RETURN OLD; |
| 173 | +END; |
| 174 | +$func$ LANGUAGE plpgsql VOLATILE; |
| 175 | + |
| 176 | +-- "storage"."prefixes" |
| 177 | +CREATE OR REPLACE TRIGGER "prefixes_delete_hierarchy" |
| 178 | + AFTER DELETE ON "storage"."prefixes" |
| 179 | + FOR EACH ROW |
| 180 | +EXECUTE FUNCTION "storage"."delete_prefix_hierarchy_trigger"(); |
| 181 | + |
| 182 | +-- "storage"."objects" |
| 183 | +CREATE OR REPLACE TRIGGER "objects_insert_create_prefix" |
| 184 | + BEFORE INSERT ON "storage"."objects" |
| 185 | + FOR EACH ROW |
| 186 | +EXECUTE FUNCTION "storage"."objects_insert_prefix_trigger"(); |
| 187 | + |
| 188 | +CREATE OR REPLACE TRIGGER "objects_update_create_prefix" |
| 189 | + BEFORE UPDATE ON "storage"."objects" |
| 190 | + FOR EACH ROW |
| 191 | + WHEN (NEW.name != OLD.name) |
| 192 | +EXECUTE FUNCTION "storage"."objects_insert_prefix_trigger"(); |
| 193 | + |
| 194 | +CREATE OR REPLACE TRIGGER "objects_delete_delete_prefix" |
| 195 | + AFTER DELETE ON "storage"."objects" |
| 196 | + FOR EACH ROW |
| 197 | +EXECUTE FUNCTION "storage"."delete_prefix_hierarchy_trigger"(); |
| 198 | + |
| 199 | +-- Permissions |
| 200 | +DO $$ |
| 201 | + DECLARE |
| 202 | + anon_role text = COALESCE(current_setting('storage.anon_role', true), 'anon'); |
| 203 | + authenticated_role text = COALESCE(current_setting('storage.authenticated_role', true), 'authenticated'); |
| 204 | + service_role text = COALESCE(current_setting('storage.service_role', true), 'service_role'); |
| 205 | + BEGIN |
| 206 | + EXECUTE 'GRANT ALL ON TABLE storage.prefixes TO ' || service_role || ',' || authenticated_role || ', ' || anon_role; |
| 207 | +END$$; |
0 commit comments