1
+ create or replace function storage .search (
2
+ prefix text ,
3
+ bucketname text ,
4
+ limits int default 100 ,
5
+ levels int default 1 ,
6
+ offsets int default 0 ,
7
+ search text default ' ' ,
8
+ sortcolumn text default ' name' ,
9
+ sortorder text default ' asc'
10
+ ) returns table (
11
+ name text ,
12
+ id uuid,
13
+ updated_at timestamptz ,
14
+ created_at timestamptz ,
15
+ last_accessed_at timestamptz ,
16
+ metadata jsonb
17
+ )
18
+ as $$
19
+ declare
20
+ can_bypass_rls BOOLEAN ;
21
+ begin
22
+ SELECT rolbypassrls
23
+ INTO can_bypass_rls
24
+ FROM pg_roles
25
+ WHERE rolname = coalesce(nullif(current_setting(' role' , true), ' none' ), current_user );
26
+
27
+ IF can_bypass_rls THEN
28
+ RETURN QUERY SELECT * FROM storage .search_v1_optimised (prefix, bucketname, limits, levels, offsets, search, sortcolumn, sortorder);
29
+ ELSE
30
+ RETURN QUERY SELECT * FROM storage .search_legacy_v1 (prefix, bucketname, limits, levels, offsets, search, sortcolumn, sortorder);
31
+ END IF;
32
+ end;
33
+ $$ language plpgsql volatile;
34
+
35
+
36
+ CREATE OR REPLACE FUNCTION storage .extension(name text )
37
+ RETURNS text
38
+ LANGUAGE plpgsql
39
+ IMMUTABLE
40
+ AS $function$
41
+ DECLARE
42
+ _parts text [];
43
+ _filename text ;
44
+ BEGIN
45
+ -- Split on "/" to get path segments
46
+ SELECT string_to_array(name, ' /' ) INTO _parts;
47
+ -- Get the last path segment (the actual filename)
48
+ SELECT _parts[array_length(_parts, 1 )] INTO _filename;
49
+ -- Extract extension: reverse, split on '.', then reverse again
50
+ RETURN reverse(split_part(reverse(_filename), ' .' , 1 ));
51
+ END
52
+ $function$;
53
+
54
+
55
+ CREATE OR REPLACE FUNCTION storage .foldername(name text )
56
+ RETURNS text []
57
+ LANGUAGE plpgsql
58
+ IMMUTABLE
59
+ AS $function$
60
+ DECLARE
61
+ _parts text [];
62
+ BEGIN
63
+ -- Split on "/" to get path segments
64
+ SELECT string_to_array(name, ' /' ) INTO _parts;
65
+ -- Return everything except the last segment
66
+ RETURN _parts[1 : array_length(_parts,1 ) - 1 ];
67
+ END
68
+ $function$;
69
+
70
+
71
+ CREATE OR REPLACE FUNCTION storage .extension(name text )
72
+ RETURNS text
73
+ LANGUAGE plpgsql
74
+ IMMUTABLE
75
+ AS $function$
76
+ DECLARE
77
+ _parts text [];
78
+ _filename text ;
79
+ BEGIN
80
+ SELECT string_to_array(name, ' /' ) INTO _parts;
81
+ SELECT _parts[array_length(_parts,1 )] INTO _filename;
82
+ RETURN reverse(split_part(reverse(_filename), ' .' , 1 ));
83
+ END
84
+ $function$;
85
+
86
+ DROP FUNCTION storage .get_size_by_bucket ();
87
+ CREATE OR REPLACE FUNCTION storage .get_size_by_bucket()
88
+ RETURNS TABLE (
89
+ size BIGINT ,
90
+ bucket_id text
91
+ )
92
+ LANGUAGE plpgsql
93
+ STABLE
94
+ AS $function$
95
+ BEGIN
96
+ return query
97
+ select sum ((metadata- >> ' size' )::bigint ) as size, obj .bucket_id
98
+ from " storage" .objects as obj
99
+ group by obj .bucket_id ;
100
+ END
101
+ $function$;
102
+
103
+ CREATE OR REPLACE FUNCTION "storage "." objects_update_prefix_trigger" ()
104
+ RETURNS trigger
105
+ AS $func$
106
+ DECLARE
107
+ old_prefixes TEXT [];
108
+ BEGIN
109
+ -- Ensure this is an update operation and the name has changed
110
+ IF TG_OP = ' UPDATE' AND (NEW." name" <> OLD." name" OR NEW." bucket_id" <> OLD." bucket_id" ) THEN
111
+ -- Retrieve old prefixes
112
+ old_prefixes := " storage" ." get_prefixes" (OLD." name" );
113
+
114
+ -- Remove old prefixes that are only used by this object
115
+ WITH all_prefixes as (
116
+ SELECT unnest(old_prefixes) as prefix
117
+ ),
118
+ can_delete_prefixes as (
119
+ SELECT prefix
120
+ FROM all_prefixes
121
+ WHERE NOT EXISTS (
122
+ SELECT 1 FROM " storage" ." objects"
123
+ WHERE " bucket_id" = OLD." bucket_id"
124
+ AND " name" <> OLD." name"
125
+ AND " name" LIKE (prefix || ' %' )
126
+ )
127
+ )
128
+ DELETE FROM " storage" ." prefixes" WHERE name IN (SELECT prefix FROM can_delete_prefixes);
129
+
130
+ -- Add new prefixes
131
+ PERFORM " storage" ." add_prefixes" (NEW." bucket_id" , NEW." name" );
132
+ END IF;
133
+ -- Set the new level
134
+ NEW." level" := " storage" ." get_level" (NEW." name" );
135
+
136
+ RETURN NEW;
137
+ END;
138
+ $func$ LANGUAGE plpgsql VOLATILE;
139
+
140
+ CREATE OR REPLACE TRIGGER "objects_update_create_prefix "
141
+ BEFORE UPDATE ON " storage" ." objects"
142
+ FOR EACH ROW
143
+ WHEN (NEW .name != OLD .name OR NEW .bucket_id != OLD .bucket_id )
144
+ EXECUTE FUNCTION " storage" ." objects_update_prefix_trigger" ();
0 commit comments