Skip to content

Commit c3b32a4

Browse files
authored
Merge pull request #35 from ethereumfollowprotocol/patch-fix-leaderboard-category
patch: fix leaderboard categories
2 parents 65b8edb + 461476c commit c3b32a4

9 files changed

+501
-0
lines changed
Lines changed: 78 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,78 @@
1+
-- migrate:up
2+
-------------------------------------------------------------------------------
3+
-- Function: get_leaderboard_blocks
4+
-- Description: This fix improves blocks lookups and adds ranks to the results.
5+
--
6+
---------------
7+
8+
DROP FUNCTION
9+
IF EXISTS query.get_leaderboard_blocks(bigint);
10+
11+
CREATE
12+
OR REPLACE FUNCTION query.get_leaderboard_blocks (limit_count BIGINT) RETURNS TABLE (address types.eth_address, blocks_count BIGINT, blocks_rank BIGINT) LANGUAGE PLPGSQL AS $$
13+
BEGIN
14+
CREATE TEMPORARY TABLE temp_leaderboard_blocked (
15+
nft_chain_id bigint,
16+
nft_contract_address varchar(42),
17+
token_id bigint,
18+
owner varchar(42),
19+
manager varchar(42),
20+
"user" varchar(42),
21+
record_data bytea,
22+
record_version smallint,
23+
record_type smallint,
24+
tags types.efp_tag[]
25+
) ON COMMIT DROP;
26+
27+
INSERT INTO temp_leaderboard_blocked SELECT r.chain_id,
28+
r.contract_address,
29+
l.token_id,
30+
l.owner,
31+
l.manager,
32+
l."user",
33+
r.record_data,
34+
r.record_version,
35+
r.record_type,
36+
array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags
37+
FROM efp_list_records r
38+
LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record
39+
JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea
40+
JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text)
41+
WHERE t.tag = 'block'
42+
GROUP BY
43+
r.chain_id,
44+
r.contract_address,
45+
l.token_id,
46+
l.owner,
47+
l.manager,
48+
l."user",
49+
r.record_version,
50+
r.record_type,
51+
r.record_data;
52+
53+
RETURN QUERY
54+
SELECT
55+
v.user::types.eth_address AS address,
56+
COUNT(DISTINCT v.record_data) AS blocks_count,
57+
RANK () OVER (
58+
ORDER BY COUNT(DISTINCT v.record_data) DESC NULLS LAST
59+
) as blocks_rank
60+
FROM
61+
temp_leaderboard_blocked AS v
62+
WHERE
63+
-- only list record version 1
64+
v.record_version = 1 AND
65+
-- address record type (1)
66+
v.record_type = 1 AND
67+
-- -- valid address
68+
public.is_valid_address(v.record_data)
69+
GROUP BY
70+
v.user
71+
ORDER BY
72+
blocks_count DESC,
73+
v.user ASC
74+
LIMIT limit_count;
75+
END;
76+
$$;
77+
78+
--migrate:down
Lines changed: 85 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,85 @@
1+
-- migrate:up
2+
-------------------------------------------------------------------------------
3+
-- Function: get_leaderboard_blocked
4+
-- Description: This fix improves blocked lookups and adds ranks to the results.
5+
--
6+
---------------
7+
8+
DROP VIEW
9+
IF EXISTS PUBLIC.view__join__efp_leaderboard CASCADE;
10+
11+
DROP FUNCTION
12+
IF EXISTS query.get_leaderboard_blocked_or_muted(bigint);
13+
14+
DROP FUNCTION
15+
IF EXISTS query.get_leaderboard_blocked(bigint);
16+
17+
CREATE
18+
OR REPLACE FUNCTION query.get_leaderboard_blocked (limit_count BIGINT) RETURNS TABLE (address types.eth_address, blocked_count BIGINT, blocked_rank BIGINT) LANGUAGE PLPGSQL AS $$
19+
BEGIN
20+
CREATE TEMPORARY TABLE temp_leaderboard_blocked (
21+
nft_chain_id bigint,
22+
nft_contract_address varchar(42),
23+
token_id bigint,
24+
owner varchar(42),
25+
manager varchar(42),
26+
"user" varchar(42),
27+
record_data bytea,
28+
record_version smallint,
29+
record_type smallint,
30+
tags types.efp_tag[]
31+
) ON COMMIT DROP;
32+
33+
INSERT INTO temp_leaderboard_blocked SELECT r.chain_id,
34+
r.contract_address,
35+
l.token_id,
36+
l.owner,
37+
l.manager,
38+
l."user",
39+
r.record_data,
40+
r.record_version,
41+
r.record_type,
42+
array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags
43+
FROM efp_list_records r
44+
LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record
45+
JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea
46+
JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text)
47+
WHERE t.tag = 'block'
48+
GROUP BY
49+
r.chain_id,
50+
r.contract_address,
51+
l.token_id,
52+
l.owner,
53+
l.manager,
54+
l."user",
55+
r.record_version,
56+
r.record_type,
57+
r.record_data;
58+
59+
RETURN QUERY
60+
61+
SELECT
62+
public.hexlify(v.record_data)::types.eth_address AS address,
63+
COUNT(DISTINCT v.user) AS blocked_count,
64+
RANK () OVER (
65+
ORDER BY COUNT(DISTINCT v.user) DESC NULLS LAST
66+
) as blocked_rank
67+
FROM
68+
temp_leaderboard_blocked AS v
69+
WHERE
70+
-- only list record version 1
71+
v.record_version = 1 AND
72+
-- address record type (1)
73+
v.record_type = 1 AND
74+
-- -- valid address
75+
public.is_valid_address(v.record_data)
76+
GROUP BY
77+
v.record_data
78+
ORDER BY
79+
blocked_count DESC,
80+
v.record_data ASC
81+
LIMIT limit_count;
82+
END;
83+
$$;
84+
85+
--migrate:down
Lines changed: 78 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,78 @@
1+
-- migrate:up
2+
-------------------------------------------------------------------------------
3+
-- Function: get_leaderboard_mutes
4+
-- Description: This fix improves mutes lookups and adds ranks to the results.
5+
--
6+
---------------
7+
8+
DROP FUNCTION
9+
IF EXISTS query.get_leaderboard_mutes(bigint);
10+
11+
CREATE
12+
OR REPLACE FUNCTION query.get_leaderboard_mutes (limit_count BIGINT) RETURNS TABLE (address types.eth_address, mutes_count BIGINT, mutes_rank BIGINT) LANGUAGE PLPGSQL AS $$
13+
BEGIN
14+
CREATE TEMPORARY TABLE temp_leaderboard_mutes (
15+
nft_chain_id bigint,
16+
nft_contract_address varchar(42),
17+
token_id bigint,
18+
owner varchar(42),
19+
manager varchar(42),
20+
"user" varchar(42),
21+
record_data bytea,
22+
record_version smallint,
23+
record_type smallint,
24+
tags types.efp_tag[]
25+
) ON COMMIT DROP;
26+
27+
INSERT INTO temp_leaderboard_mutes SELECT r.chain_id,
28+
r.contract_address,
29+
l.token_id,
30+
l.owner,
31+
l.manager,
32+
l."user",
33+
r.record_data,
34+
r.record_version,
35+
r.record_type,
36+
array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags
37+
FROM efp_list_records r
38+
LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record
39+
JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea
40+
JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text)
41+
WHERE t.tag = 'mute'
42+
GROUP BY
43+
r.chain_id,
44+
r.contract_address,
45+
l.token_id,
46+
l.owner,
47+
l.manager,
48+
l."user",
49+
r.record_version,
50+
r.record_type,
51+
r.record_data;
52+
53+
RETURN QUERY
54+
SELECT
55+
v.user::types.eth_address AS address,
56+
COUNT(DISTINCT v.record_data) AS mutes_count,
57+
RANK () OVER (
58+
ORDER BY COUNT(DISTINCT v.record_data) DESC NULLS LAST
59+
) as mutes_rank
60+
FROM
61+
temp_leaderboard_mutes AS v
62+
WHERE
63+
-- only list record version 1
64+
v.record_version = 1 AND
65+
-- address record type (1)
66+
v.record_type = 1 AND
67+
-- -- valid address
68+
public.is_valid_address(v.record_data)
69+
GROUP BY
70+
v.user
71+
ORDER BY
72+
mutes_count DESC,
73+
v.user ASC
74+
LIMIT limit_count;
75+
END;
76+
$$;
77+
78+
--migrate:down
Lines changed: 79 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,79 @@
1+
-- migrate:up
2+
-------------------------------------------------------------------------------
3+
-- Function: get_leaderboard_muted
4+
-- Description: This fix improves muted lookups and adds ranks to the results.
5+
--
6+
---------------
7+
8+
DROP FUNCTION
9+
IF EXISTS query.get_leaderboard_muted(bigint);
10+
11+
CREATE
12+
OR REPLACE FUNCTION query.get_leaderboard_muted (limit_count BIGINT) RETURNS TABLE (address types.eth_address, muted_count BIGINT, muted_rank BIGINT) LANGUAGE PLPGSQL AS $$
13+
BEGIN
14+
CREATE TEMPORARY TABLE temp_leaderboard_muted (
15+
nft_chain_id bigint,
16+
nft_contract_address varchar(42),
17+
token_id bigint,
18+
owner varchar(42),
19+
manager varchar(42),
20+
"user" varchar(42),
21+
record_data bytea,
22+
record_version smallint,
23+
record_type smallint,
24+
tags types.efp_tag[]
25+
) ON COMMIT DROP;
26+
27+
INSERT INTO temp_leaderboard_muted SELECT r.chain_id,
28+
r.contract_address,
29+
l.token_id,
30+
l.owner,
31+
l.manager,
32+
l."user",
33+
r.record_data,
34+
r.record_version,
35+
r.record_type,
36+
array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags
37+
FROM efp_list_records r
38+
LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record
39+
JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea
40+
JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text)
41+
WHERE t.tag = 'mute'
42+
GROUP BY
43+
r.chain_id,
44+
r.contract_address,
45+
l.token_id,
46+
l.owner,
47+
l.manager,
48+
l."user",
49+
r.record_version,
50+
r.record_type,
51+
r.record_data;
52+
53+
RETURN QUERY
54+
55+
SELECT
56+
public.hexlify(v.record_data)::types.eth_address AS address,
57+
COUNT(DISTINCT v.user) AS muted_count,
58+
RANK () OVER (
59+
ORDER BY COUNT(DISTINCT v.user) DESC NULLS LAST
60+
) as muted_rank
61+
FROM
62+
temp_leaderboard_muted AS v
63+
WHERE
64+
-- only list record version 1
65+
v.record_version = 1 AND
66+
-- address record type (1)
67+
v.record_type = 1 AND
68+
-- -- valid address
69+
public.is_valid_address(v.record_data)
70+
GROUP BY
71+
v.record_data
72+
ORDER BY
73+
muted_count DESC,
74+
v.record_data ASC
75+
LIMIT limit_count;
76+
END;
77+
$$;
78+
79+
--migrate:down

0 commit comments

Comments
 (0)