192 lines
5.2 KiB
PL/PgSQL
192 lines
5.2 KiB
PL/PgSQL
create or replace function storage.search_v1_optimised (
|
|
prefix text,
|
|
bucketname text,
|
|
limits int default 100,
|
|
levels int default 1,
|
|
offsets int default 0,
|
|
search text default '',
|
|
sortcolumn text default 'name',
|
|
sortorder text default 'asc'
|
|
) returns table (
|
|
name text,
|
|
id uuid,
|
|
updated_at timestamptz,
|
|
created_at timestamptz,
|
|
last_accessed_at timestamptz,
|
|
metadata jsonb
|
|
)
|
|
as $$
|
|
declare
|
|
v_order_by text;
|
|
v_sort_order text;
|
|
begin
|
|
case
|
|
when sortcolumn = 'name' then
|
|
v_order_by = 'name';
|
|
when sortcolumn = 'updated_at' then
|
|
v_order_by = 'updated_at';
|
|
when sortcolumn = 'created_at' then
|
|
v_order_by = 'created_at';
|
|
when sortcolumn = 'last_accessed_at' then
|
|
v_order_by = 'last_accessed_at';
|
|
else
|
|
v_order_by = 'name';
|
|
end case;
|
|
|
|
case
|
|
when sortorder = 'asc' then
|
|
v_sort_order = 'asc';
|
|
when sortorder = 'desc' then
|
|
v_sort_order = 'desc';
|
|
else
|
|
v_sort_order = 'asc';
|
|
end case;
|
|
|
|
v_order_by = v_order_by || ' ' || v_sort_order;
|
|
|
|
return query execute
|
|
'with folders as (
|
|
select (string_to_array(name, ''/''))[level] as name
|
|
from storage.prefixes
|
|
where lower(prefixes.name) like lower($2 || $3) || ''%''
|
|
and bucket_id = $4
|
|
and level = $1
|
|
order by name ' || v_sort_order || '
|
|
)
|
|
(select name,
|
|
null as id,
|
|
null as updated_at,
|
|
null as created_at,
|
|
null as last_accessed_at,
|
|
null as metadata from folders)
|
|
union all
|
|
(select path_tokens[level] as "name",
|
|
id,
|
|
updated_at,
|
|
created_at,
|
|
last_accessed_at,
|
|
metadata
|
|
from storage.objects
|
|
where lower(objects.name) like lower($2 || $3) || ''%''
|
|
and bucket_id = $4
|
|
and level = $1
|
|
order by ' || v_order_by || ')
|
|
limit $5
|
|
offset $6' using levels, prefix, search, bucketname, limits, offsets;
|
|
end;
|
|
$$ language plpgsql stable;
|
|
|
|
|
|
create or replace function storage.search_legacy_v1 (
|
|
prefix text,
|
|
bucketname text,
|
|
limits int default 100,
|
|
levels int default 1,
|
|
offsets int default 0,
|
|
search text default '',
|
|
sortcolumn text default 'name',
|
|
sortorder text default 'asc'
|
|
) returns table (
|
|
name text,
|
|
id uuid,
|
|
updated_at timestamptz,
|
|
created_at timestamptz,
|
|
last_accessed_at timestamptz,
|
|
metadata jsonb
|
|
)
|
|
as $$
|
|
declare
|
|
v_order_by text;
|
|
v_sort_order text;
|
|
begin
|
|
case
|
|
when sortcolumn = 'name' then
|
|
v_order_by = 'name';
|
|
when sortcolumn = 'updated_at' then
|
|
v_order_by = 'updated_at';
|
|
when sortcolumn = 'created_at' then
|
|
v_order_by = 'created_at';
|
|
when sortcolumn = 'last_accessed_at' then
|
|
v_order_by = 'last_accessed_at';
|
|
else
|
|
v_order_by = 'name';
|
|
end case;
|
|
|
|
case
|
|
when sortorder = 'asc' then
|
|
v_sort_order = 'asc';
|
|
when sortorder = 'desc' then
|
|
v_sort_order = 'desc';
|
|
else
|
|
v_sort_order = 'asc';
|
|
end case;
|
|
|
|
v_order_by = v_order_by || ' ' || v_sort_order;
|
|
|
|
return query execute
|
|
'with folders as (
|
|
select path_tokens[$1] as folder
|
|
from storage.objects
|
|
where objects.name ilike $2 || $3 || ''%''
|
|
and bucket_id = $4
|
|
and array_length(objects.path_tokens, 1) <> $1
|
|
group by folder
|
|
order by folder ' || v_sort_order || '
|
|
)
|
|
(select folder as "name",
|
|
null as id,
|
|
null as updated_at,
|
|
null as created_at,
|
|
null as last_accessed_at,
|
|
null as metadata from folders)
|
|
union all
|
|
(select path_tokens[$1] as "name",
|
|
id,
|
|
updated_at,
|
|
created_at,
|
|
last_accessed_at,
|
|
metadata
|
|
from storage.objects
|
|
where objects.name ilike $2 || $3 || ''%''
|
|
and bucket_id = $4
|
|
and array_length(objects.path_tokens, 1) = $1
|
|
order by ' || v_order_by || ')
|
|
limit $5
|
|
offset $6' using levels, prefix, search, bucketname, limits, offsets;
|
|
end;
|
|
$$ language plpgsql stable;
|
|
|
|
|
|
create or replace function storage.search (
|
|
prefix text,
|
|
bucketname text,
|
|
limits int default 100,
|
|
levels int default 1,
|
|
offsets int default 0,
|
|
search text default '',
|
|
sortcolumn text default 'name',
|
|
sortorder text default 'asc'
|
|
) returns table (
|
|
name text,
|
|
id uuid,
|
|
updated_at timestamptz,
|
|
created_at timestamptz,
|
|
last_accessed_at timestamptz,
|
|
metadata jsonb
|
|
)
|
|
as $$
|
|
declare
|
|
can_bypass_rls BOOLEAN;
|
|
begin
|
|
SELECT rolbypassrls
|
|
INTO can_bypass_rls
|
|
FROM pg_roles
|
|
WHERE rolname = coalesce(nullif(current_setting('role', true), 'none'), current_user);
|
|
|
|
IF can_bypass_rls THEN
|
|
RETURN QUERY SELECT * FROM storage.search_v1_optimised(prefix, bucketname, limits, levels, offsets, search, sortcolumn, sortorder);
|
|
ELSE
|
|
RETURN QUERY SELECT * FROM storage.search_legacy_v1(prefix, bucketname, limits, levels, offsets, search, sortcolumn, sortorder);
|
|
END IF;
|
|
end;
|
|
$$ language plpgsql stable; |