chatdesk-ui/storage_v1.19.1/migrations/tenant/0023-optimize-search-functi...

78 lines
2.0 KiB
PL/PgSQL

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
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;