Skip to content
Snippets Groups Projects
Commit ce0cb007 authored by Bartek Wrona's avatar Bartek Wrona
Browse files

Merge branch 'bw_hive_account_info_view_opt2' into 'develop'

hive account info view optimization

See merge request !325
parents 21ce1f6d 3b7521c7
No related branches found
No related tags found
2 merge requests!456Release candidate v1 24,!325hive account info view optimization
......@@ -98,7 +98,7 @@ class DbState:
'hive_posts_parent_id_idx',
'hive_posts_depth_idx',
'hive_posts_created_at_idx',
'hive_posts_created_at_author_id_idx',
'hive_posts_root_id_id_idx',
'hive_posts_community_id_idx',
......
......@@ -86,7 +86,6 @@ def build_metadata():
sa.Column('children', sa.Integer, nullable=False, server_default='0'),
# core stats/indexes
sa.Column('payout', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'),
sa.Column('pending_payout', sa.types.DECIMAL(10, 3), nullable=False, server_default='0'),
......@@ -145,7 +144,7 @@ def build_metadata():
sa.Index('hive_posts_promoted_idx', 'promoted'),
sa.Index('hive_posts_sc_trend_id_is_paidout_idx', 'sc_trend', 'id', 'is_paidout'),
sa.Index('hive_posts_sc_hot_id_is_paidout_idx', 'sc_hot', 'id', 'is_paidout'),
sa.Index('hive_posts_created_at_idx', 'created_at'),
sa.Index('hive_posts_created_at_author_id_idx', 'created_at', 'author_id'),
sa.Index('hive_posts_block_num_idx', 'block_num'),
sa.Index('hive_posts_block_num_created_idx', 'block_num_created'),
sa.Index('hive_posts_cashout_time_id_idx', 'cashout_time', 'id'),
......
DROP VIEW IF EXISTS hive_accounts_info_view;
CREATE OR REPLACE VIEW public.hive_accounts_info_view
AS
SELECT ha.id,
ha.name,
COALESCE(post_data.post_count, 0::bigint) AS post_count,
ha.created_at,
( SELECT GREATEST(ha.created_at,
COALESCE(post_data.latest_post, '1970-01-01 00:00:00'::timestamp without time zone),
COALESCE(limited_votes.latest_vote, whole_votes.latest_vote, '1970-01-01 00:00:00'::timestamp without time zone))
AS "greatest"
) AS active_at,
ha.reputation,
ha.rank,
ha.following,
ha.followers,
ha.lastread_at,
ha.posting_json_metadata,
ha.json_metadata
FROM
(
SELECT max(hb.num) - 1200 * 24 * 7 AS block_limit FROM hive_blocks hb
) bl,
hive_accounts ha
LEFT JOIN LATERAL
(
SELECT count(1) AS post_count, max(hp.created_at) AS latest_post, max(hp.block_num) AS latest_post_block
FROM hive_posts hp
WHERE hp.author_id = ha.id
) post_data ON true
LEFT JOIN LATERAL --- let's first try to find a last vote in last 7 days
(
SELECT hv.last_update AS latest_vote
FROM hive_votes hv
WHERE ha.id = hv.voter_id AND hv.block_num >= bl.block_limit AND hv.block_num >= COALESCE(post_data.latest_post_block, 0)
ORDER BY hv.block_num DESC
LIMIT 1
) limited_votes ON true
LEFT JOIN LATERAL -- this is a fallback to case when was no vote in last 7 days
(
SELECT hvf.last_update AS latest_vote
FROM hive_votes hvf
WHERE limited_votes.latest_vote IS NULL AND hvf.voter_id = ha.id
ORDER BY hvf.voter_id DESC, hvf.last_update DESC
LIMIT 1
) whole_votes ON true
;
DROP VIEW IF EXISTS hive_accounts_info_view;
CREATE OR REPLACE VIEW public.hive_accounts_info_view
AS
SELECT ha.id,
ha.name,
COALESCE(posts.post_count, 0::bigint) AS post_count,
ha.created_at,
( SELECT GREATEST(ha.created_at,
COALESCE(latest_post.latest_post, '1970-01-01 00:00:00'::timestamp without time zone),
COALESCE(limited_votes.latest_vote, whole_votes.latest_vote, '1970-01-01 00:00:00'::timestamp without time zone))
AS "greatest"
) AS active_at,
ha.reputation,
ha.rank,
ha.following,
ha.followers,
ha.lastread_at,
ha.posting_json_metadata,
ha.json_metadata
FROM
(
SELECT max(hb.num) - 1200 * 24 * 7 AS block_limit FROM hive_blocks hb
) bl,
hive_accounts ha
LEFT JOIN LATERAL
(
SELECT COUNT(1) AS post_count
FROM hive_posts hp
WHERE hp.counter_deleted = 0 and hp.author_id = ha.id
) posts ON true
LEFT JOIN lateral
(
SELECT hp1.created_at AS latest_post
FROM hive_posts hp1
WHERE hp1.counter_deleted = 0 and hp1.author_id = ha.id
ORDER BY hp1.created_at DESC, hp1.author_id DESC LIMIT 1
) latest_post on true
LEFT JOIN LATERAL --- let's first try to find a last vote in last 7 days
(
SELECT hv.last_update AS latest_vote
FROM hive_votes hv
WHERE ha.id = hv.voter_id AND hv.block_num >= bl.block_limit --AND hv.block_num >= COALESCE(post_data.latest_post_block, 0)
ORDER BY hv.block_num DESC
LIMIT 1
) limited_votes ON true
LEFT JOIN LATERAL -- this is a fallback to case when was no vote in last 7 days
(
SELECT hvf.last_update AS latest_vote
FROM hive_votes hvf
WHERE limited_votes.latest_vote IS NULL AND hvf.voter_id = ha.id
ORDER BY hvf.voter_id DESC, hvf.last_update DESC
LIMIT 1
) whole_votes ON true
;
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment