From c7b6a3234bad4f4e56668282f3376bedd43a91f0 Mon Sep 17 00:00:00 2001 From: lincheoll Date: Wed, 3 Sep 2025 13:26:14 +0900 Subject: [PATCH 1/2] feat: optimize messages_by_address function for partitioned tables --- database/schema/00-cosmos.sql | 104 ++++++++++++++++++++++++++++++---- 1 file changed, 92 insertions(+), 12 deletions(-) diff --git a/database/schema/00-cosmos.sql b/database/schema/00-cosmos.sql index b7c41c084..79d98c8fd 100644 --- a/database/schema/00-cosmos.sql +++ b/database/schema/00-cosmos.sql @@ -100,18 +100,98 @@ CREATE INDEX message_involved_accounts_index ON message USING GIN(involved_accou * This function is used to find all the utils that involve any of the given addresses and have * type that is one of the specified types. */ -CREATE FUNCTION messages_by_address( - addresses TEXT[], - types TEXT[], - "limit" BIGINT = 100, - "offset" BIGINT = 0) - RETURNS SETOF message AS -$$ -SELECT * FROM message -WHERE (cardinality(types) = 0 OR type = ANY (types)) - AND addresses && involved_accounts_addresses -ORDER BY height DESC LIMIT "limit" OFFSET "offset" -$$ LANGUAGE sql STABLE; +CREATE FUNCTION public.messages_by_address( +p_addresses text[], +p_types text[] DEFAULT NULL::text[], +p_limit bigint DEFAULT 100, +p_offset bigint DEFAULT 0) + RETURNS SETOF message + LANGUAGE plpgsql + STABLE +AS $function$ +DECLARE + p regclass; + current_count bigint := 0; + current_offset bigint := p_offset; + partition_result_count bigint; + has_match boolean; + type_condition text; +BEGIN + -- Check Type Condition + IF p_types IS NULL OR array_length(p_types, 1) IS NULL OR array_length(p_types, 1) = 0 THEN + type_condition := 'TRUE'; + ELSE + type_condition := format('type = ANY(ARRAY[%s])', + array_to_string(array(select quote_literal(t) from unnest(p_types) as t), ',')); + END IF; + + FOR p IN + SELECT inhrelid + FROM pg_inherits + WHERE inhparent = 'public.message'::regclass + ORDER BY inhrelid DESC + LOOP + -- Check EXISTS + EXECUTE format( + 'SELECT EXISTS ( + SELECT 1 FROM %s + WHERE %s AND involved_accounts_addresses && $1 + LIMIT 1 + )', p, type_condition + ) + INTO has_match + USING p_addresses; + + IF has_match THEN + -- Check Counts + EXECUTE format( + 'SELECT count(*) FROM %s + WHERE %s AND involved_accounts_addresses && $1', + p, type_condition + ) + INTO partition_result_count + USING p_addresses; + + -- Process offset + IF current_offset > 0 THEN + IF current_offset >= partition_result_count THEN + current_offset := current_offset - partition_result_count; + CONTINUE; + ELSE + RETURN QUERY + EXECUTE format( + 'SELECT * FROM %s + WHERE %s AND involved_accounts_addresses && $1 + ORDER BY height DESC + LIMIT $2 OFFSET $3', + p, type_condition + ) + USING p_addresses, p_limit - current_count, current_offset; + + current_count := current_count + LEAST(partition_result_count - current_offset, p_limit - current_count); + current_offset := 0; + END IF; + ELSE + RETURN QUERY + EXECUTE format( + 'SELECT * FROM %s + WHERE %s AND involved_accounts_addresses && $1 + ORDER BY height DESC + LIMIT $2', + p, type_condition + ) + USING p_addresses, p_limit - current_count; + + current_count := current_count + LEAST(partition_result_count, p_limit - current_count); + END IF; + + IF current_count >= p_limit THEN + EXIT; + END IF; + END IF; + END LOOP; +END; +$function$ CREATE FUNCTION messages_by_type( types text [], From 8d07558ff42da444b09c3de53c77cdf91461fc99 Mon Sep 17 00:00:00 2001 From: lincheoll Date: Wed, 3 Sep 2025 14:39:44 +0900 Subject: [PATCH 2/2] chore: normalize messages_by_address function parameter style --- database/schema/00-cosmos.sql | 32 ++++++++++++++++---------------- 1 file changed, 16 insertions(+), 16 deletions(-) diff --git a/database/schema/00-cosmos.sql b/database/schema/00-cosmos.sql index 79d98c8fd..fe7e63645 100644 --- a/database/schema/00-cosmos.sql +++ b/database/schema/00-cosmos.sql @@ -100,11 +100,11 @@ CREATE INDEX message_involved_accounts_index ON message USING GIN(involved_accou * This function is used to find all the utils that involve any of the given addresses and have * type that is one of the specified types. */ -CREATE FUNCTION public.messages_by_address( -p_addresses text[], -p_types text[] DEFAULT NULL::text[], -p_limit bigint DEFAULT 100, -p_offset bigint DEFAULT 0) +CREATE FUNCTION messages_by_address( +addresses TEXT[], +types TEXT[] DEFAULT NULL::TEXT[], +"limit" BIGINT DEFAULT 100, +"offset" BIGINT DEFAULT 0) RETURNS SETOF message LANGUAGE plpgsql STABLE @@ -112,23 +112,23 @@ AS $function$ DECLARE p regclass; current_count bigint := 0; - current_offset bigint := p_offset; + current_offset bigint := "offset"; partition_result_count bigint; has_match boolean; type_condition text; BEGIN -- Check Type Condition - IF p_types IS NULL OR array_length(p_types, 1) IS NULL OR array_length(p_types, 1) = 0 THEN + IF types IS NULL OR array_length(types, 1) IS NULL OR array_length(types, 1) = 0 THEN type_condition := 'TRUE'; ELSE type_condition := format('type = ANY(ARRAY[%s])', - array_to_string(array(select quote_literal(t) from unnest(p_types) as t), ',')); + array_to_string(array(select quote_literal(t) from unnest(types) as t), ',')); END IF; FOR p IN SELECT inhrelid FROM pg_inherits - WHERE inhparent = 'public.message'::regclass + WHERE inhparent = 'message'::regclass ORDER BY inhrelid DESC LOOP -- Check EXISTS @@ -140,7 +140,7 @@ BEGIN )', p, type_condition ) INTO has_match - USING p_addresses; + USING addresses; IF has_match THEN -- Check Counts @@ -150,7 +150,7 @@ BEGIN p, type_condition ) INTO partition_result_count - USING p_addresses; + USING addresses; -- Process offset IF current_offset > 0 THEN @@ -166,9 +166,9 @@ BEGIN LIMIT $2 OFFSET $3', p, type_condition ) - USING p_addresses, p_limit - current_count, current_offset; + USING addresses, "limit" - current_count, current_offset; - current_count := current_count + LEAST(partition_result_count - current_offset, p_limit - current_count); + current_count := current_count + LEAST(partition_result_count - current_offset, "limit" - current_count); current_offset := 0; END IF; ELSE @@ -180,12 +180,12 @@ BEGIN LIMIT $2', p, type_condition ) - USING p_addresses, p_limit - current_count; + USING addresses, "limit" - current_count; - current_count := current_count + LEAST(partition_result_count, p_limit - current_count); + current_count := current_count + LEAST(partition_result_count, "limit" - current_count); END IF; - IF current_count >= p_limit THEN + IF current_count >= "limit" THEN EXIT; END IF; END IF;