49 lines
2.0 KiB
MySQL
Raw Normal View History

2025-01-30 19:19:49 -06:00
-- add limit and offset
CREATE OR REPLACE FUNCTION item_comments_limited(
_item_id int, _limit int, _offset int, _grandchild_limit int,
_level int, _where text, _order_by text)
RETURNS jsonb
LANGUAGE plpgsql VOLATILE PARALLEL SAFE AS
$$
DECLARE
result jsonb;
BEGIN
IF _level < 1 THEN
RETURN '[]'::jsonb;
END IF;
EXECUTE 'CREATE TEMP TABLE IF NOT EXISTS t_item ON COMMIT DROP AS '
|| 'WITH RECURSIVE base AS ( '
|| ' (SELECT "Item".*, 1 as level, ROW_NUMBER() OVER () as rn '
|| ' FROM "Item" '
|| ' WHERE "Item"."parentId" = $1 '
|| _order_by || ' '
|| ' LIMIT $2 '
|| ' OFFSET $3) '
|| ' UNION ALL '
|| ' (SELECT "Item".*, b.level + 1, ROW_NUMBER() OVER (PARTITION BY "Item"."parentId" ' || _order_by || ') '
|| ' FROM "Item" '
|| ' JOIN base b ON "Item"."parentId" = b.id '
|| ' WHERE b.level < $5 AND (b.level = 1 OR b.rn <= $4)) '
|| ') '
|| 'SELECT "Item".*, "Item".created_at at time zone ''UTC'' AS "createdAt", "Item".updated_at at time zone ''UTC'' AS "updatedAt", '
|| ' "Item"."invoicePaidAt" at time zone ''UTC'' AS "invoicePaidAtUTC", '
|| ' to_jsonb(users.*) as user '
|| 'FROM base "Item" '
|| 'JOIN users ON users.id = "Item"."userId" '
|| 'WHERE ("Item".level = 1 OR "Item".rn <= $4 - "Item".level + 2) ' || _where
USING _item_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by;
EXECUTE ''
|| 'SELECT COALESCE(jsonb_agg(sub), ''[]''::jsonb) AS comments '
|| 'FROM ( '
|| ' SELECT "Item".*, item_comments_limited("Item".id, $2, $3, $4, $5 - 1, $6, $7) AS comments '
|| ' FROM t_item "Item" '
|| ' WHERE "Item"."parentId" = $1 '
|| _order_by
|| ' ) sub'
INTO result USING _item_id, _limit, _offset, _grandchild_limit, _level, _where, _order_by;
RETURN result;
END
$$;