From 0560eff60bc8585c860c18ea05f9c417b1e8e35e Mon Sep 17 00:00:00 2001 From: Howo Date: Sat, 22 Nov 2025 21:36:33 -0500 Subject: [PATCH 01/36] Registration sqlized --- hive/db/sql_scripts/community.sql | 46 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 33 ++++++++-------------- 2 files changed, 58 insertions(+), 21 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index f29100cc9..751ca5b21 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -124,4 +124,50 @@ BEGIN END as status, (SELECT current_mod_count FROM mod_check) as mod_count; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.register_community; +CREATE OR REPLACE FUNCTION hivemind_app.register_community( + _name VARCHAR, + _account_id INTEGER, + _block_date TIMESTAMP, + _block_num INTEGER, + _counter INTEGER +) RETURNS VOID AS $$ +DECLARE + _type_id INTEGER; + _notification_first_block INTEGER; +BEGIN + -- Extract type_id from name (6th character, after "hive-") + _type_id := SUBSTRING(_name, 6, 1)::INTEGER; + + -- Insert community + INSERT INTO hivemind_app.hive_communities (id, name, type_id, created_at, block_num) + VALUES (_account_id, _name, _type_id, _block_date, _block_num); + + -- Insert owner role + INSERT INTO hivemind_app.hive_roles (community_id, account_id, role_id, created_at) + VALUES (_account_id, _account_id, 8, _block_date); -- 8 = owner role id + + -- Insert community notification + SELECT hivemind_app.block_before_irreversible('90 days') INTO _notification_first_block; + IF _block_num > _notification_first_block THEN + INSERT INTO hivemind_app.hive_notification_cache + (id, block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) + SELECT + hivemind_app.notification_id(_block_date, 1, _counter), + _block_num, + 1, + _block_date, + 0, + _account_id, + 0, + 0, + 35, + '', + _name, + '' + WHERE _block_num > hivemind_app.block_before_irreversible('90 days'); + END IF; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 49d9c5ba1..b8a65481b 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -168,32 +168,23 @@ class Community: This method checks for any valid community names and inserts them. """ + # Validation and preprocessing in Python if not re.match(r'^hive-[123]\d{4,6}$', name): return - type_id = int(name[5]) + _id = Accounts.get_id(name) counter = cls._counter.increment(block_num) - # insert community - sql = f"""INSERT INTO {SCHEMA_NAME}.hive_communities (id, name, type_id, created_at, block_num) - VALUES (:id, :name, :type_id, :date, :block_num)""" - DbAdapterHolder.common_block_processing_db().query(sql, id=_id, name=name, type_id=type_id, date=block_date, block_num=block_num) - - # insert owner - sql = f"""INSERT INTO {SCHEMA_NAME}.hive_roles (community_id, account_id, role_id, created_at) - VALUES (:community_id, :account_id, :role_id, :date)""" - DbAdapterHolder.common_block_processing_db().query(sql, community_id=_id, account_id=_id, role_id=Role.owner.value, date=block_date) - - # insert community notification - # Howo: Maybe we should change this to set dst as the account creator instead - sql = f"""INSERT INTO {SCHEMA_NAME}.hive_notification_cache (id, block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) - SELECT {SCHEMA_NAME}.notification_id((:created_at)::timestamp, 1, :counter), n.* - FROM (VALUES(:block_num, 1, (:created_at)::timestamp, 0, :dst, 0, 0, 35, '', :community, '')) - AS n(block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) - WHERE n.score >= 0 AND n.src IS DISTINCT FROM n.dst - AND n.block_num > hivemind_app.block_before_irreversible('90 days') - """ - DbAdapterHolder.common_block_processing_db().query(sql, block_num=block_num, created_at=block_date, dst=_id, community=name, counter=counter) + # Call SQL function to handle all database operations + sql = f"""SELECT {SCHEMA_NAME}.register_community(:name, :account_id, :block_date, :block_num, :counter)""" + DbAdapterHolder.common_block_processing_db().query_no_return( + sql, + name=name, + account_id=_id, + block_date=block_date, + block_num=block_num, + counter=counter + ) @classmethod def validated_id(cls, name): -- GitLab From 7f68cb6ec0cc683f44bac925a51ff920b739deec Mon Sep 17 00:00:00 2001 From: Howo Date: Sat, 22 Nov 2025 22:09:46 -0500 Subject: [PATCH 02/36] subscribe / unsubscribe sqlized --- hive/db/sql_scripts/community.sql | 89 ++++++++++--------------------- hive/indexer/community.py | 41 ++++++++++---- 2 files changed, 58 insertions(+), 72 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 751ca5b21..cfbc431f1 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -1,25 +1,24 @@ -DROP FUNCTION IF EXISTS hivemind_app.insert_subscription; +DROP FUNCTION IF EXISTS hivemind_app.community_subscribe(INTEGER, INTEGER, TIMESTAMP, INTEGER, INTEGER); CREATE OR REPLACE FUNCTION hivemind_app.community_subscribe( _actor_id INTEGER, _community_id INTEGER, _date TIMESTAMP, _block_num INTEGER, _counter INTEGER -) RETURNS VOID AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ DECLARE _notification_first_block INTEGER; + _already_subscribed BOOLEAN; BEGIN - -- Insert subscription - INSERT INTO hivemind_app.hive_subscriptions - (account_id, community_id, created_at, block_num) - VALUES (_actor_id, _community_id, _date, _block_num); + _already_subscribed := hivemind_app.community_is_subscribed(_actor_id, _community_id); + + IF _already_subscribed THEN + RETURN QUERY SELECT FALSE, 'already subscribed'::TEXT; + END IF; - -- Update community subscriber count - UPDATE hivemind_app.hive_communities - SET subscribers = subscribers + 1 - WHERE id = _community_id; + INSERT INTO hivemind_app.hive_subscriptions(account_id, community_id, created_at, block_num) VALUES (_actor_id, _community_id, _date, _block_num); - -- Insert notification + UPDATE hivemind_app.hive_communities SET subscribers = subscribers + 1 WHERE id = _community_id; -- With clause is inlined, modified call to reptracker_endpoints.get_account_reputation. -- Reputation is multiplied by 7.5 rather than 9 to bring the max value to 100 rather than 115. @@ -66,63 +65,32 @@ BEGIN AND r.id IS DISTINCT FROM hc.id ON CONFLICT (src, dst, type_id, post_id, block_num) DO NOTHING; END IF; + + -- Return success + RETURN QUERY SELECT TRUE, ''::TEXT; END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.community_unsubscribe; +DROP FUNCTION IF EXISTS hivemind_app.community_unsubscribe(INTEGER, INTEGER); CREATE OR REPLACE FUNCTION hivemind_app.community_unsubscribe( _actor_id INTEGER, _community_id INTEGER -) RETURNS VOID AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _is_subscribed BOOLEAN; BEGIN - DELETE FROM hivemind_app.hive_subscriptions - WHERE account_id = _actor_id - AND community_id = _community_id; + _is_subscribed := hivemind_app.community_is_subscribed(_actor_id, _community_id); - UPDATE hivemind_app.hive_communities - SET subscribers = subscribers - 1 - WHERE id = _community_id; -END; -$$ LANGUAGE plpgsql; + IF NOT _is_subscribed THEN + RETURN QUERY SELECT FALSE, 'already unsubscribed'::TEXT; + RETURN; + END IF; -DROP FUNCTION IF EXISTS hivemind_app.set_community_role; -CREATE OR REPLACE FUNCTION hivemind_app.set_community_role( - _account_id INTEGER, - _community_id INTEGER, - _role_id INTEGER, - _date TIMESTAMP, - _max_mod_nb INTEGER, -- maximum number of roles >= to mod in a community - _mod_role_threshold INTEGER -- minimum role id to be counted as -) RETURNS TABLE(status TEXT, mod_count BIGINT) AS $$ -BEGIN - RETURN QUERY - WITH mod_check AS ( - SELECT - CASE - WHEN _role_id >= _mod_role_threshold THEN - (SELECT COUNT(*) - FROM hivemind_app.hive_roles - WHERE community_id = _community_id - AND role_id >= _mod_role_threshold - AND account_id != _account_id) - ELSE 0 - END as current_mod_count - ), - insert_attempt AS ( - INSERT INTO hivemind_app.hive_roles (account_id, community_id, role_id, created_at) - SELECT _account_id, _community_id, _role_id, _date - FROM mod_check - WHERE current_mod_count < _max_mod_nb OR _role_id < _mod_role_threshold - ON CONFLICT (account_id, community_id) - DO UPDATE SET role_id = _role_id - RETURNING * - ) - SELECT - CASE - WHEN EXISTS (SELECT 1 FROM insert_attempt) THEN 'success' - ELSE 'failed_mod_limit' - END as status, - (SELECT current_mod_count FROM mod_check) as mod_count; + DELETE FROM hivemind_app.hive_subscriptions WHERE account_id = _actor_id AND community_id = _community_id; + + UPDATE hivemind_app.hive_communities SET subscribers = subscribers - 1 WHERE id = _community_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; END; $$ LANGUAGE plpgsql; @@ -141,15 +109,12 @@ BEGIN -- Extract type_id from name (6th character, after "hive-") _type_id := SUBSTRING(_name, 6, 1)::INTEGER; - -- Insert community INSERT INTO hivemind_app.hive_communities (id, name, type_id, created_at, block_num) VALUES (_account_id, _name, _type_id, _block_date, _block_num); - -- Insert owner role INSERT INTO hivemind_app.hive_roles (community_id, account_id, role_id, created_at) VALUES (_account_id, _account_id, 8, _block_date); -- 8 = owner role id - -- Insert community notification SELECT hivemind_app.block_before_irreversible('90 days') INTO _notification_first_block; IF _block_num > _notification_first_block THEN INSERT INTO hivemind_app.hive_notification_cache diff --git a/hive/indexer/community.py b/hive/indexer/community.py index b8a65481b..63e45b77f 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -168,14 +168,12 @@ class Community: This method checks for any valid community names and inserts them. """ - # Validation and preprocessing in Python if not re.match(r'^hive-[123]\d{4,6}$', name): return _id = Accounts.get_id(name) counter = cls._counter.increment(block_num) - # Call SQL function to handle all database operations sql = f"""SELECT {SCHEMA_NAME}.register_community(:name, :account_id, :block_date, :block_num, :counter)""" DbAdapterHolder.common_block_processing_db().query_no_return( sql, @@ -388,15 +386,37 @@ class CommunityOp: elif action == 'subscribe': params['counter'] = CommunityOp._counter.increment(self.block_num) - DbAdapterHolder.common_block_processing_db().query_no_return( - f"""SELECT {SCHEMA_NAME}.community_subscribe(:actor_id, :community_id, :date, :block_num, :counter)""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.community_subscribe(:actor_id, :community_id, :date, :block_num, :counter)""", **params, ) + if result and not result['success']: + Notify( + block_num=self.block_num, + type_id='error', + dst_id=self.actor_id, + when=self.date, + payload=result['error_message'], + community_id=self.community_id, + src_id=self.community_id + ) + return False elif action == 'unsubscribe': - DbAdapterHolder.common_block_processing_db().query_no_return( - f"""SELECT {SCHEMA_NAME}.community_unsubscribe(:actor_id, :community_id)""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.community_unsubscribe(:actor_id, :community_id)""", **params, ) + if result and not result['success']: + Notify( + block_num=self.block_num, + type_id='error', + dst_id=self.actor_id, + when=self.date, + payload=result['error_message'], + community_id=self.community_id, + src_id=self.community_id + ) + return False # Account-level actions elif action == 'setRole': @@ -642,6 +662,11 @@ class CommunityOp: def _validate_permissions(self): community_id = self.community_id action = self.action + + # Skip validation as it's handled in SQL + if action in ('subscribe', 'unsubscribe'): + return + actor_role = Community.get_user_role(community_id, self.actor_id) new_role = self.role_id @@ -674,10 +699,6 @@ class CommunityOp: elif action == 'flagPost': assert actor_role > Role.muted, 'muted users cannot flag posts' assert not self._flagged(), 'user already flagged this post' - elif action == 'subscribe': - assert not self._subscribed(self.actor_id), 'already subscribed' - elif action == 'unsubscribe': - assert self._subscribed(self.actor_id), 'already unsubscribed' def _subscribed(self, account_id): """Check an account's subscription status.""" -- GitLab From 4c48e386123dac206695d994601f9dc3adca86a4 Mon Sep 17 00:00:00 2001 From: Howo Date: Sat, 22 Nov 2025 22:18:01 -0500 Subject: [PATCH 03/36] add back set_role --- hive/db/sql_scripts/community.sql | 72 +++++++++++++++---------------- 1 file changed, 35 insertions(+), 37 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index cfbc431f1..37e525c44 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -94,45 +94,43 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.register_community; -CREATE OR REPLACE FUNCTION hivemind_app.register_community( - _name VARCHAR, +DROP FUNCTION IF EXISTS hivemind_app.set_community_role; +CREATE OR REPLACE FUNCTION hivemind_app.set_community_role( _account_id INTEGER, - _block_date TIMESTAMP, - _block_num INTEGER, - _counter INTEGER -) RETURNS VOID AS $$ -DECLARE - _type_id INTEGER; - _notification_first_block INTEGER; + _community_id INTEGER, + _role_id INTEGER, + _date TIMESTAMP, + _max_mod_nb INTEGER, -- maximum number of roles >= to mod in a community + _mod_role_threshold INTEGER -- minimum role id to be counted as +) RETURNS TABLE(status TEXT, mod_count BIGINT) AS $$ BEGIN - -- Extract type_id from name (6th character, after "hive-") - _type_id := SUBSTRING(_name, 6, 1)::INTEGER; - - INSERT INTO hivemind_app.hive_communities (id, name, type_id, created_at, block_num) - VALUES (_account_id, _name, _type_id, _block_date, _block_num); - - INSERT INTO hivemind_app.hive_roles (community_id, account_id, role_id, created_at) - VALUES (_account_id, _account_id, 8, _block_date); -- 8 = owner role id - - SELECT hivemind_app.block_before_irreversible('90 days') INTO _notification_first_block; - IF _block_num > _notification_first_block THEN - INSERT INTO hivemind_app.hive_notification_cache - (id, block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) + RETURN QUERY + WITH mod_check AS ( SELECT - hivemind_app.notification_id(_block_date, 1, _counter), - _block_num, - 1, - _block_date, - 0, - _account_id, - 0, - 0, - 35, - '', - _name, - '' - WHERE _block_num > hivemind_app.block_before_irreversible('90 days'); - END IF; + CASE + WHEN _role_id >= _mod_role_threshold THEN + (SELECT COUNT(*) + FROM hivemind_app.hive_roles + WHERE community_id = _community_id + AND role_id >= _mod_role_threshold + AND account_id != _account_id) + ELSE 0 + END as current_mod_count + ), + insert_attempt AS ( + INSERT INTO hivemind_app.hive_roles (account_id, community_id, role_id, created_at) + SELECT _account_id, _community_id, _role_id, _date + FROM mod_check + WHERE current_mod_count < _max_mod_nb OR _role_id < _mod_role_threshold + ON CONFLICT (account_id, community_id) + DO UPDATE SET role_id = _role_id + RETURNING * + ) + SELECT + CASE + WHEN EXISTS (SELECT 1 FROM insert_attempt) THEN 'success' + ELSE 'failed_mod_limit' + END as status, + (SELECT current_mod_count FROM mod_check) as mod_count; END; $$ LANGUAGE plpgsql; \ No newline at end of file -- GitLab From c8438fabcf51fe0d6deb7bf752e11973d07e7d63 Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 09:21:55 -0500 Subject: [PATCH 04/36] fix query --- hive/indexer/community.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 63e45b77f..6d0607bc1 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -174,7 +174,7 @@ class Community: _id = Accounts.get_id(name) counter = cls._counter.increment(block_num) - sql = f"""SELECT {SCHEMA_NAME}.register_community(:name, :account_id, :block_date, :block_num, :counter)""" + sql = f"""SELECT {SCHEMA_NAME}.register_community(:name::VARCHAR, :account_id::INTEGER, :block_date::TIMESTAMP, :block_num::INTEGER, :counter::INTEGER)""" DbAdapterHolder.common_block_processing_db().query_no_return( sql, name=name, -- GitLab From a4ee066260841f2e1b0ed727ff8c6c798b8ec329 Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 16:47:40 -0500 Subject: [PATCH 05/36] added forgotten file --- hive/db/schema.py | 1 + hive/db/sql_scripts/community.sql | 46 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 2 +- 3 files changed, 48 insertions(+), 1 deletion(-) diff --git a/hive/db/schema.py b/hive/db/schema.py index 5987ab855..215833a92 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -659,6 +659,7 @@ def setup_runtime_code(db): "hafapp_api.sql", "grant_hivemind_user.sql", "community.sql", + "community_utils.sql", "postgrest/utilities/exceptions.sql", "postgrest/utilities/validate_json_arguments.sql", "postgrest/utilities/api_limits.sql", diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 37e525c44..a70a4b068 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -133,4 +133,50 @@ BEGIN END as status, (SELECT current_mod_count FROM mod_check) as mod_count; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.register_community; +CREATE OR REPLACE FUNCTION hivemind_app.register_community( + _name VARCHAR, + _account_id INTEGER, + _block_date TIMESTAMP, + _block_num INTEGER, + _counter INTEGER +) RETURNS VOID AS $$ +DECLARE + _type_id INTEGER; + _notification_first_block INTEGER; +BEGIN + -- Extract type_id from name (6th character, after "hive-") + _type_id := SUBSTRING(_name, 6, 1)::INTEGER; + + -- Insert community + INSERT INTO hivemind_app.hive_communities (id, name, type_id, created_at, block_num) + VALUES (_account_id, _name, _type_id, _block_date, _block_num); + + -- Insert owner role + INSERT INTO hivemind_app.hive_roles (community_id, account_id, role_id, created_at) + VALUES (_account_id, _account_id, 8, _block_date); -- 8 = owner role id + + -- Insert community notification + SELECT hivemind_app.block_before_irreversible('90 days') INTO _notification_first_block; + IF _block_num > _notification_first_block THEN + INSERT INTO hivemind_app.hive_notification_cache + (id, block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) + SELECT + hivemind_app.notification_id(_block_date, 1, _counter), + _block_num, + 1, + _block_date, + 0, + _account_id, + 0, + 0, + 35, + '', + _name, + '' + WHERE _block_num > hivemind_app.block_before_irreversible('90 days'); + END IF; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 6d0607bc1..63e45b77f 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -174,7 +174,7 @@ class Community: _id = Accounts.get_id(name) counter = cls._counter.increment(block_num) - sql = f"""SELECT {SCHEMA_NAME}.register_community(:name::VARCHAR, :account_id::INTEGER, :block_date::TIMESTAMP, :block_num::INTEGER, :counter::INTEGER)""" + sql = f"""SELECT {SCHEMA_NAME}.register_community(:name, :account_id, :block_date, :block_num, :counter)""" DbAdapterHolder.common_block_processing_db().query_no_return( sql, name=name, -- GitLab From f3b4e4adfe9e8cf6f5dbb652d32cacc432c1a867 Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 18:24:21 -0500 Subject: [PATCH 06/36] Implemented set_user_title --- hive/db/sql_scripts/community.sql | 36 ++++++++++++++++++++++--- hive/db/sql_scripts/community_utils.sql | 13 +++++++++ hive/indexer/community.py | 24 +++++++++++------ 3 files changed, 62 insertions(+), 11 deletions(-) create mode 100644 hive/db/sql_scripts/community_utils.sql diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index a70a4b068..0572b4116 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -150,15 +150,12 @@ BEGIN -- Extract type_id from name (6th character, after "hive-") _type_id := SUBSTRING(_name, 6, 1)::INTEGER; - -- Insert community INSERT INTO hivemind_app.hive_communities (id, name, type_id, created_at, block_num) VALUES (_account_id, _name, _type_id, _block_date, _block_num); - -- Insert owner role INSERT INTO hivemind_app.hive_roles (community_id, account_id, role_id, created_at) VALUES (_account_id, _account_id, 8, _block_date); -- 8 = owner role id - -- Insert community notification SELECT hivemind_app.block_before_irreversible('90 days') INTO _notification_first_block; IF _block_num > _notification_first_block THEN INSERT INTO hivemind_app.hive_notification_cache @@ -179,4 +176,37 @@ BEGIN WHERE _block_num > hivemind_app.block_before_irreversible('90 days'); END IF; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.set_user_title; +CREATE OR REPLACE FUNCTION hivemind_app.set_user_title( + _actor_id INTEGER, + _account_id INTEGER, + _community_id INTEGER, + _title VARCHAR, + _date TIMESTAMP +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _community_name VARCHAR; + _community_title VARCHAR; +BEGIN + -- Get role in the community (default to guest = 0 if no role) + SELECT COALESCE(role_id, 0) INTO _actor_role + FROM hivemind_app.hive_roles + WHERE community_id = _community_id AND account_id = _actor_id; + + -- 4 is mod + IF _actor_role < 4 THEN + RETURN QUERY SELECT FALSE, 'only mods can set user titles'::TEXT; + RETURN; + END IF; + + INSERT INTO hivemind_app.hive_roles (account_id, community_id, title, created_at) + VALUES (_account_id, _community_id, _title, _date) + ON CONFLICT (account_id, community_id) + DO UPDATE SET title = _title; + + RETURN QUERY SELECT TRUE, ''::TEXT; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql new file mode 100644 index 000000000..64ef3d399 --- /dev/null +++ b/hive/db/sql_scripts/community_utils.sql @@ -0,0 +1,13 @@ +DROP FUNCTION IF EXISTS hivemind_app.community_is_subscribed; +CREATE OR REPLACE FUNCTION hivemind_app.community_is_subscribed( + _account_id INTEGER, + _community_id INTEGER +) RETURNS BOOLEAN AS $$ +BEGIN + RETURN EXISTS( + SELECT 1 FROM hivemind_app.hive_subscriptions + WHERE community_id = _community_id + AND account_id = _account_id + ); +END; +$$ LANGUAGE plpgsql STABLE; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 63e45b77f..f6dd972cb 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -443,15 +443,23 @@ class CommunityOp: payload=f'Cannot set role: {Role(self.role_id).name} limit of {MAX_MOD_NB} moderators/admins/owners exceeded' ) elif action == 'setUserTitle': - DbAdapterHolder.common_block_processing_db().query( - f"""INSERT INTO {SCHEMA_NAME}.hive_roles - (account_id, community_id, title, created_at) - VALUES (:account_id, :community_id, :title, :date) - ON CONFLICT (account_id, community_id) - DO UPDATE SET title = :title""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.set_user_title( + :actor_id, :account_id, :community_id, :title, :date + )""", **params, ) - self._notify('set_title', payload=self.title) + if result and not result['success']: + Notify( + block_num=self.block_num, + type_id='error', + dst_id=self.actor_id, + when=self.date, + payload=result['error_message'], + community_id=self.community_id, + src_id=self.community_id + ) + return False # Post-level actions elif action == 'mutePost': @@ -664,7 +672,7 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle'): return actor_role = Community.get_user_role(community_id, self.actor_id) -- GitLab From 83b7279c759acb13dbec7b11cd7aa36e536baa3c Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 19:39:54 -0500 Subject: [PATCH 07/36] Fix missing set_title notification --- hive/indexer/community.py | 7 +++++-- 1 file changed, 5 insertions(+), 2 deletions(-) diff --git a/hive/indexer/community.py b/hive/indexer/community.py index f6dd972cb..b9815013b 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -440,7 +440,7 @@ class CommunityOp: community_id=self.community_id, dst_id=self.actor_id, when=self.date, - payload=f'Cannot set role: {Role(self.role_id).name} limit of {MAX_MOD_NB} moderators/admins/owners exceeded' + payload=f'Cannot set role: {Role(self.role_id).name} limit of {MAX_MOD_NB} moderators/admins/owners exceeded' # TODO, when sqlizing, make sure to update this to take into account permission validation text too ) elif action == 'setUserTitle': result = DbAdapterHolder.common_block_processing_db().query_row( @@ -449,7 +449,10 @@ class CommunityOp: )""", **params, ) - if result and not result['success']: + + if result[0]['status'] == 'success': + self._notify('set_title', payload=self.title) + else: Notify( block_num=self.block_num, type_id='error', -- GitLab From 019d65fb14a6b4a97a334243faaea2209db60b5d Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 21:14:34 -0500 Subject: [PATCH 08/36] set_role --- hive/db/sql_scripts/community.sql | 87 +++++++++++++++---------- hive/db/sql_scripts/community_utils.sql | 15 +++++ hive/indexer/community.py | 17 +++-- 3 files changed, 75 insertions(+), 44 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 0572b4116..20504cd73 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -66,7 +66,6 @@ BEGIN ON CONFLICT (src, dst, type_id, post_id, block_num) DO NOTHING; END IF; - -- Return success RETURN QUERY SELECT TRUE, ''::TEXT; END; $$ LANGUAGE plpgsql; @@ -96,42 +95,64 @@ $$ LANGUAGE plpgsql; DROP FUNCTION IF EXISTS hivemind_app.set_community_role; CREATE OR REPLACE FUNCTION hivemind_app.set_community_role( + _actor_id INTEGER, _account_id INTEGER, _community_id INTEGER, _role_id INTEGER, _date TIMESTAMP, _max_mod_nb INTEGER, -- maximum number of roles >= to mod in a community _mod_role_threshold INTEGER -- minimum role id to be counted as -) RETURNS TABLE(status TEXT, mod_count BIGINT) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _account_role INTEGER; + _mod_count BIGINT; BEGIN - RETURN QUERY - WITH mod_check AS ( - SELECT - CASE - WHEN _role_id >= _mod_role_threshold THEN - (SELECT COUNT(*) - FROM hivemind_app.hive_roles - WHERE community_id = _community_id - AND role_id >= _mod_role_threshold - AND account_id != _account_id) - ELSE 0 - END as current_mod_count - ), - insert_attempt AS ( - INSERT INTO hivemind_app.hive_roles (account_id, community_id, role_id, created_at) - SELECT _account_id, _community_id, _role_id, _date - FROM mod_check - WHERE current_mod_count < _max_mod_nb OR _role_id < _mod_role_threshold - ON CONFLICT (account_id, community_id) - DO UPDATE SET role_id = _role_id - RETURNING * - ) - SELECT - CASE - WHEN EXISTS (SELECT 1 FROM insert_attempt) THEN 'success' - ELSE 'failed_mod_limit' - END as status, - (SELECT current_mod_count FROM mod_check) as mod_count; + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + _account_role := hivemind_app.get_community_role(_account_id, _community_id); + + IF _actor_role < 4 THEN -- 4 = Role.mod + RETURN QUERY SELECT FALSE, 'only mods and up can alter roles'::TEXT; + END IF; + + IF _actor_role <= _role_id THEN + RETURN QUERY SELECT FALSE, 'cannot promote to or above own rank'::TEXT; + END IF; + + IF _account_role = 8 THEN -- 8 = Role.owner + RETURN QUERY SELECT FALSE, 'cant modify owner role'::TEXT; + END IF; + + IF _actor_id != _account_id THEN + IF _account_role >= _actor_role THEN + RETURN QUERY SELECT FALSE, 'cant modify a user with a higher role'::TEXT; + END IF; + + IF _account_role = _role_id THEN + RETURN QUERY SELECT FALSE, 'role would not change'::TEXT; + END IF; + END IF; + + -- Check mod limit if promoting to mod or above + IF _role_id >= _mod_role_threshold THEN + SELECT COUNT(*) INTO _mod_count + FROM hivemind_app.hive_roles + WHERE community_id = _community_id + AND role_id >= _mod_role_threshold + AND account_id != _account_id; + + IF _mod_count >= _max_mod_nb THEN + RETURN QUERY SELECT FALSE, 'moderator limit exceeded'::TEXT; + END IF; + END IF; + + INSERT INTO hivemind_app.hive_roles (account_id, community_id, role_id, created_at) + VALUES (_account_id, _community_id, _role_id, _date) + ON CONFLICT (account_id, community_id) + DO UPDATE SET role_id = _role_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; END; $$ LANGUAGE plpgsql; @@ -191,15 +212,11 @@ DECLARE _community_name VARCHAR; _community_title VARCHAR; BEGIN - -- Get role in the community (default to guest = 0 if no role) - SELECT COALESCE(role_id, 0) INTO _actor_role - FROM hivemind_app.hive_roles - WHERE community_id = _community_id AND account_id = _actor_id; + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); -- 4 is mod IF _actor_role < 4 THEN RETURN QUERY SELECT FALSE, 'only mods can set user titles'::TEXT; - RETURN; END IF; INSERT INTO hivemind_app.hive_roles (account_id, community_id, title, created_at) diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 64ef3d399..16de2d813 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -11,3 +11,18 @@ BEGIN ); END; $$ LANGUAGE plpgsql STABLE; + +DROP FUNCTION IF EXISTS hivemind_app.get_community_role; +CREATE OR REPLACE FUNCTION hivemind_app.get_community_role( + _account_id INTEGER, + _community_id INTEGER +) RETURNS INTEGER AS $$ +BEGIN + -- Get account's role in the community (default to guest = 0 if no role) + RETURN COALESCE( + (SELECT role_id FROM hivemind_app.hive_roles + WHERE community_id = _community_id AND account_id = _account_id), + 0 + ); +END; +$$ LANGUAGE plpgsql STABLE; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index b9815013b..371bd03ee 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -420,9 +420,9 @@ class CommunityOp: # Account-level actions elif action == 'setRole': - result = DbAdapterHolder.common_block_processing_db().query_all( + result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.set_community_role( - :account_id, :community_id, :role_id, :date, + :actor_id, :account_id, :community_id, :role_id, :date, :max_mod_nb, :mod_role_threshold )""", max_mod_nb=MAX_MOD_NB, @@ -430,9 +430,9 @@ class CommunityOp: **params ) - if result[0]['status'] == 'success': + if result and result['success']: self._notify('set_role', payload=Role(self.role_id).name) - else: + elif result: Notify( block_num=self.block_num, type_id='error', @@ -440,7 +440,7 @@ class CommunityOp: community_id=self.community_id, dst_id=self.actor_id, when=self.date, - payload=f'Cannot set role: {Role(self.role_id).name} limit of {MAX_MOD_NB} moderators/admins/owners exceeded' # TODO, when sqlizing, make sure to update this to take into account permission validation text too + payload=result['error_message'] ) elif action == 'setUserTitle': result = DbAdapterHolder.common_block_processing_db().query_row( @@ -450,9 +450,9 @@ class CommunityOp: **params, ) - if result[0]['status'] == 'success': + if result and result['success']: self._notify('set_title', payload=self.title) - else: + elif result: Notify( block_num=self.block_num, type_id='error', @@ -675,7 +675,7 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole'): return actor_role = Community.get_user_role(community_id, self.actor_id) @@ -692,7 +692,6 @@ class CommunityOp: elif action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' elif action == 'setUserTitle': - # TODO: assert title changed? assert actor_role >= Role.mod, 'only mods can set user titles' elif action == 'mutePost': assert not self._muted(), 'post is already muted' -- GitLab From 35ba2cf26f8c45f9fca9032817a94ba935b34d54 Mon Sep 17 00:00:00 2001 From: Howo Date: Sun, 23 Nov 2025 21:16:55 -0500 Subject: [PATCH 09/36] clarify comment --- hive/db/sql_scripts/community_utils.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 16de2d813..7801b9cc8 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -18,7 +18,7 @@ CREATE OR REPLACE FUNCTION hivemind_app.get_community_role( _community_id INTEGER ) RETURNS INTEGER AS $$ BEGIN - -- Get account's role in the community (default to guest = 0 if no role) + -- default to guest = 0 if no role RETURN COALESCE( (SELECT role_id FROM hivemind_app.hive_roles WHERE community_id = _community_id AND account_id = _account_id), -- GitLab From 0a0b93618a20e5826e0ae254083146f1e890cf90 Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 11:10:07 -0500 Subject: [PATCH 10/36] Fix returns for proper error management + slight optimization in set_community_role --- hive/db/sql_scripts/community.sql | 13 +++++++++++-- 1 file changed, 11 insertions(+), 2 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 20504cd73..d02516b76 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -14,6 +14,7 @@ BEGIN IF _already_subscribed THEN RETURN QUERY SELECT FALSE, 'already subscribed'::TEXT; + RETURN; END IF; INSERT INTO hivemind_app.hive_subscriptions(account_id, community_id, created_at, block_num) VALUES (_actor_id, _community_id, _date, _block_num); @@ -110,27 +111,33 @@ DECLARE BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); - _account_role := hivemind_app.get_community_role(_account_id, _community_id); - IF _actor_role < 4 THEN -- 4 = Role.mod RETURN QUERY SELECT FALSE, 'only mods and up can alter roles'::TEXT; + RETURN; END IF; IF _actor_role <= _role_id THEN RETURN QUERY SELECT FALSE, 'cannot promote to or above own rank'::TEXT; + RETURN; END IF; + _account_role := hivemind_app.get_community_role(_account_id, _community_id); + IF _account_role = 8 THEN -- 8 = Role.owner RETURN QUERY SELECT FALSE, 'cant modify owner role'::TEXT; + RETURN; END IF; + IF _actor_id != _account_id THEN IF _account_role >= _actor_role THEN RETURN QUERY SELECT FALSE, 'cant modify a user with a higher role'::TEXT; + RETURN; END IF; IF _account_role = _role_id THEN RETURN QUERY SELECT FALSE, 'role would not change'::TEXT; + RETURN; END IF; END IF; @@ -144,6 +151,7 @@ BEGIN IF _mod_count >= _max_mod_nb THEN RETURN QUERY SELECT FALSE, 'moderator limit exceeded'::TEXT; + RETURN; END IF; END IF; @@ -217,6 +225,7 @@ BEGIN -- 4 is mod IF _actor_role < 4 THEN RETURN QUERY SELECT FALSE, 'only mods can set user titles'::TEXT; + RETURN; END IF; INSERT INTO hivemind_app.hive_roles (account_id, community_id, title, created_at) -- GitLab From 070424cd86c52a05011e1a4d728d52021514a91e Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 11:29:47 -0500 Subject: [PATCH 11/36] removed useless checks --- hive/indexer/community.py | 16 +++------------- 1 file changed, 3 insertions(+), 13 deletions(-) diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 371bd03ee..328dd0a7e 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -679,20 +679,9 @@ class CommunityOp: return actor_role = Community.get_user_role(community_id, self.actor_id) - new_role = self.role_id - - if action == 'setRole': - assert actor_role >= Role.mod, 'only mods and up can alter roles' - assert actor_role > new_role, 'cannot promote to or above own rank' - account_role = Community.get_user_role(community_id, self.account_id) - assert account_role != Role.owner, 'cant modify owner role' - if self.actor != self.account: - assert account_role < actor_role, 'cant modify higher-role user' - assert account_role != new_role, 'role would not change' - elif action == 'updateProps': + + if action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' - elif action == 'setUserTitle': - assert actor_role >= Role.mod, 'only mods can set user titles' elif action == 'mutePost': assert not self._muted(), 'post is already muted' assert actor_role >= Role.mod, 'only mods can mute posts' @@ -710,6 +699,7 @@ class CommunityOp: assert actor_role > Role.muted, 'muted users cannot flag posts' assert not self._flagged(), 'user already flagged this post' + # TODO drop this, functions should return if user is subscribed or not if they result in a notification def _subscribed(self, account_id): """Check an account's subscription status.""" sql = f"""SELECT EXISTS( -- GitLab From 406c7d3fa875536871620599be0133dc8bdf6b0b Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 18:18:47 -0500 Subject: [PATCH 12/36] cleaned up redundant code with helper func --- hive/indexer/community.py | 73 ++++++++++++--------------------------- 1 file changed, 22 insertions(+), 51 deletions(-) diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 328dd0a7e..1b638fbcf 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -390,34 +390,13 @@ class CommunityOp: f"""SELECT * FROM {SCHEMA_NAME}.community_subscribe(:actor_id, :community_id, :date, :block_num, :counter)""", **params, ) - if result and not result['success']: - Notify( - block_num=self.block_num, - type_id='error', - dst_id=self.actor_id, - when=self.date, - payload=result['error_message'], - community_id=self.community_id, - src_id=self.community_id - ) - return False + self._handle_result(result, None) elif action == 'unsubscribe': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.community_unsubscribe(:actor_id, :community_id)""", **params, ) - if result and not result['success']: - Notify( - block_num=self.block_num, - type_id='error', - dst_id=self.actor_id, - when=self.date, - payload=result['error_message'], - community_id=self.community_id, - src_id=self.community_id - ) - return False - + self._handle_result(result, None) # Account-level actions elif action == 'setRole': result = DbAdapterHolder.common_block_processing_db().query_row( @@ -429,19 +408,7 @@ class CommunityOp: mod_role_threshold=Role.mod, **params ) - - if result and result['success']: - self._notify('set_role', payload=Role(self.role_id).name) - elif result: - Notify( - block_num=self.block_num, - type_id='error', - src_id=self.community_id, - community_id=self.community_id, - dst_id=self.actor_id, - when=self.date, - payload=result['error_message'] - ) + self._handle_result(result, 'set_role', payload=Role(self.role_id).name) elif action == 'setUserTitle': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.set_user_title( @@ -449,21 +416,7 @@ class CommunityOp: )""", **params, ) - - if result and result['success']: - self._notify('set_title', payload=self.title) - elif result: - Notify( - block_num=self.block_num, - type_id='error', - dst_id=self.actor_id, - when=self.date, - payload=result['error_message'], - community_id=self.community_id, - src_id=self.community_id - ) - return False - + self._handle_result(result, 'set_title', payload=self.title) # Post-level actions elif action == 'mutePost': DbAdapterHolder.common_block_processing_db().query( @@ -501,6 +454,24 @@ class CommunityOp: FSM.flush_stat('Community', perf_counter() - time_start, 1) return True + def _handle_result(self, result, success_op, payload=None): + """Handle result from SQL operations with success/error_message pattern.""" + if result and result['success']: + self._notify(success_op, payload=payload) + return True + elif result: + Notify( + block_num=self.block_num, + type_id='error', + dst_id=self.actor_id, + when=self.date, + payload=result['error_message'], + community_id=self.community_id, + src_id=self.community_id + ) + return False + return True + def _notify(self, op, **kwargs): dst_id = None score = 35 -- GitLab From bd54827b6bf3c5c09031a7c2b80173d3cc47b046 Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 18:36:31 -0500 Subject: [PATCH 13/36] Fix handleResult not supporting empty ops and add support for mutePost --- hive/db/sql_scripts/community.sql | 33 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 20 ++++++++++--------- 2 files changed, 44 insertions(+), 9 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index d02516b76..ecdbe3e9f 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -235,4 +235,37 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.mute_post; +CREATE OR REPLACE FUNCTION hivemind_app.mute_post( + _actor_id INTEGER, + _community_id INTEGER, + _post_id INTEGER, + _muted_reasons INTEGER +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _is_muted BOOLEAN; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role < 4 THEN + RETURN QUERY SELECT FALSE, 'only mods and above can mute posts'::TEXT; + RETURN; + END IF; + + SELECT is_muted INTO _is_muted FROM hivemind_app.hive_posts WHERE id = _post_id; + + IF _is_muted THEN + RETURN QUERY SELECT FALSE, 'post is already muted'::TEXT; + RETURN; + END IF; + + UPDATE hivemind_app.hive_posts + SET is_muted = true, muted_reasons = _muted_reasons + WHERE id = _post_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 1b638fbcf..464347841 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -390,13 +390,13 @@ class CommunityOp: f"""SELECT * FROM {SCHEMA_NAME}.community_subscribe(:actor_id, :community_id, :date, :block_num, :counter)""", **params, ) - self._handle_result(result, None) + self._handle_result(result) elif action == 'unsubscribe': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.community_unsubscribe(:actor_id, :community_id)""", **params, ) - self._handle_result(result, None) + self._handle_result(result) # Account-level actions elif action == 'setRole': result = DbAdapterHolder.common_block_processing_db().query_row( @@ -419,12 +419,13 @@ class CommunityOp: self._handle_result(result, 'set_title', payload=self.title) # Post-level actions elif action == 'mutePost': - DbAdapterHolder.common_block_processing_db().query( - f"""UPDATE {SCHEMA_NAME}.hive_posts SET is_muted = '1', muted_reasons = :muted_reasons - WHERE id = :post_id""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.mute_post( + :actor_id, :community_id, :post_id, :muted_reasons + )""", **params, ) - self._notify('mute_post', payload=self.notes) + self._handle_result(result, 'mute_post', payload=self.notes) elif action == 'unmutePost': DbAdapterHolder.common_block_processing_db().query( @@ -454,10 +455,11 @@ class CommunityOp: FSM.flush_stat('Community', perf_counter() - time_start, 1) return True - def _handle_result(self, result, success_op, payload=None): + def _handle_result(self, result, success_op=None, payload=None): """Handle result from SQL operations with success/error_message pattern.""" if result and result['success']: - self._notify(success_op, payload=payload) + if success_op: + self._notify(success_op, payload=payload) return True elif result: Notify( @@ -646,7 +648,7 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost'): return actor_role = Community.get_user_role(community_id, self.actor_id) -- GitLab From d259bdd0dd0560278d7ebff1e62dc77f7d2da664 Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 18:47:12 -0500 Subject: [PATCH 14/36] Unmute post --- hive/db/sql_scripts/community.sql | 43 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 18 +++++-------- 2 files changed, 49 insertions(+), 12 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index ecdbe3e9f..78c867636 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -268,4 +268,47 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.unmute_post; +CREATE OR REPLACE FUNCTION hivemind_app.unmute_post( + _actor_id INTEGER, + _community_id INTEGER, + _post_id INTEGER +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _is_muted BOOLEAN; + _parent_id INTEGER; + _parent_is_muted BOOLEAN; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role < 4 THEN + RETURN QUERY SELECT FALSE, 'only mods and above can unmute posts'::TEXT; + RETURN; + END IF; + + SELECT is_muted, parent_id INTO _is_muted, _parent_id FROM hivemind_app.hive_posts WHERE id = _post_id; + + IF NOT _is_muted THEN + RETURN QUERY SELECT FALSE, 'post is not muted'::TEXT; + RETURN; + END IF; + + IF _parent_id IS NOT NULL THEN + -- TODO maybe it would be faster to fetch parent at the same time as we fetch the child in one query vs two ? + SELECT is_muted INTO _parent_is_muted FROM hivemind_app.hive_posts WHERE id = _parent_id; + IF _parent_is_muted THEN + RETURN QUERY SELECT FALSE, 'parent post is muted'::TEXT; + RETURN; + END IF; + END IF; + + UPDATE hivemind_app.hive_posts + SET is_muted = false, muted_reasons = 0 + WHERE id = _post_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 464347841..ad394d16f 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -428,12 +428,13 @@ class CommunityOp: self._handle_result(result, 'mute_post', payload=self.notes) elif action == 'unmutePost': - DbAdapterHolder.common_block_processing_db().query( - f"""UPDATE {SCHEMA_NAME}.hive_posts SET is_muted = '0', muted_reasons = 0 - WHERE id = :post_id""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.unmute_post( + :actor_id, :community_id, :post_id + )""", **params, ) - self._notify('unmute_post', payload=self.notes) + self._handle_result(result, 'unmute_post', payload=self.notes) elif action == 'pinPost': DbAdapterHolder.common_block_processing_db().query( @@ -648,20 +649,13 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost'): return actor_role = Community.get_user_role(community_id, self.actor_id) if action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' - elif action == 'mutePost': - assert not self._muted(), 'post is already muted' - assert actor_role >= Role.mod, 'only mods can mute posts' - elif action == 'unmutePost': - assert self._muted(), 'post is already not muted' - assert not self._parent_muted(), 'parent post is muted' - assert actor_role >= Role.mod, 'only mods can unmute posts' elif action == 'pinPost': assert not self._pinned(), 'post is already pinned' assert actor_role >= Role.mod, 'only mods can pin posts' -- GitLab From ee4c1f01accd05ea14fba4f54f18b43064d5c409 Mon Sep 17 00:00:00 2001 From: Howo Date: Mon, 24 Nov 2025 18:53:15 -0500 Subject: [PATCH 15/36] Pin post --- hive/db/sql_scripts/community.sql | 32 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 14 ++++++-------- 2 files changed, 38 insertions(+), 8 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 78c867636..0b647d68e 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -311,4 +311,36 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.pin_post; +CREATE OR REPLACE FUNCTION hivemind_app.pin_post( + _actor_id INTEGER, + _community_id INTEGER, + _post_id INTEGER +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _is_pinned BOOLEAN; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role < 4 THEN + RETURN QUERY SELECT FALSE, 'only mods and above can pin posts'::TEXT; + RETURN; + END IF; + + SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; + + IF _is_pinned THEN + RETURN QUERY SELECT FALSE, 'post is already pinned'::TEXT; + RETURN; + END IF; + + UPDATE hivemind_app.hive_posts + SET is_pinned = true + WHERE id = _post_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index ad394d16f..7fe5fe5c8 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -437,12 +437,13 @@ class CommunityOp: self._handle_result(result, 'unmute_post', payload=self.notes) elif action == 'pinPost': - DbAdapterHolder.common_block_processing_db().query( - f"""UPDATE {SCHEMA_NAME}.hive_posts SET is_pinned = '1' - WHERE id = :post_id""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.pin_post( + :actor_id, :community_id, :post_id + )""", **params, ) - self._notify('pin_post', payload=self.notes) + self._handle_result(result, 'pin_post', payload=self.notes) elif action == 'unpinPost': DbAdapterHolder.common_block_processing_db().query( f"""UPDATE {SCHEMA_NAME}.hive_posts SET is_pinned = '0' @@ -649,16 +650,13 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost'): return actor_role = Community.get_user_role(community_id, self.actor_id) if action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' - elif action == 'pinPost': - assert not self._pinned(), 'post is already pinned' - assert actor_role >= Role.mod, 'only mods can pin posts' elif action == 'unpinPost': assert self._pinned(), 'post is already not pinned' assert actor_role >= Role.mod, 'only mods can unpin posts' -- GitLab From 8303248efb7efb2bf6ad0a0f5fec8b9f14f57666 Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 10:33:42 -0500 Subject: [PATCH 16/36] unPin post --- hive/db/sql_scripts/community.sql | 32 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 14 ++++++-------- 2 files changed, 38 insertions(+), 8 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 0b647d68e..77370705c 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -343,4 +343,36 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.unpin_post; +CREATE OR REPLACE FUNCTION hivemind_app.unpin_post( + _actor_id INTEGER, + _community_id INTEGER, + _post_id INTEGER +) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +DECLARE + _actor_role INTEGER; + _is_pinned BOOLEAN; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role < 4 THEN + RETURN QUERY SELECT FALSE, 'only mods and above can unpin posts'::TEXT; + RETURN; + END IF; + + SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; + + IF NOT _is_pinned THEN + RETURN QUERY SELECT FALSE, 'post is not pinned'::TEXT; + RETURN; + END IF; + + UPDATE hivemind_app.hive_posts + SET is_pinned = false + WHERE id = _post_id; + + RETURN QUERY SELECT TRUE, ''::TEXT; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 7fe5fe5c8..b53d6a1a8 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -445,12 +445,13 @@ class CommunityOp: ) self._handle_result(result, 'pin_post', payload=self.notes) elif action == 'unpinPost': - DbAdapterHolder.common_block_processing_db().query( - f"""UPDATE {SCHEMA_NAME}.hive_posts SET is_pinned = '0' - WHERE id = :post_id""", + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.unpin_post( + :actor_id, :community_id, :post_id + )""", **params, ) - self._notify('unpin_post', payload=self.notes) + self._handle_result(result, 'unpin_post', payload=self.notes) elif action == 'flagPost': self._notify_team('flag_post', payload=self.notes) @@ -650,16 +651,13 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost'): return actor_role = Community.get_user_role(community_id, self.actor_id) if action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' - elif action == 'unpinPost': - assert self._pinned(), 'post is already not pinned' - assert actor_role >= Role.mod, 'only mods can unpin posts' elif action == 'flagPost': assert actor_role > Role.muted, 'muted users cannot flag posts' assert not self._flagged(), 'user already flagged this post' -- GitLab From 422674cb7a1044dfef76f3b48eb4ae9020858e1a Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 13:17:23 -0500 Subject: [PATCH 17/36] flag_post --- hive/db/sql_scripts/community.sql | 41 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 31 +++++++++++++---------- 2 files changed, 59 insertions(+), 13 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 77370705c..19c3aa1ba 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -375,4 +375,45 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.flag_post; +CREATE OR REPLACE FUNCTION hivemind_app.flag_post( + _actor_id INTEGER, + _community_id INTEGER, + _post_id INTEGER, + _community_name VARCHAR +) RETURNS TABLE(success BOOLEAN, error_message TEXT, team_members INTEGER[]) AS $$ +DECLARE + _actor_role INTEGER; + _already_flagged BOOLEAN; + _team_members INTEGER[]; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role <= -2 THEN + RETURN QUERY SELECT FALSE, 'muted users cannot flag posts'::TEXT, NULL::INTEGER[]; + RETURN; + END IF; + + SELECT EXISTS( + SELECT 1 FROM hivemind_app.hive_notification_cache + WHERE community = _community_name + AND post_id = _post_id + AND type_id = 9 -- flag_post + AND src = _actor_id + ) INTO _already_flagged; + + IF _already_flagged THEN + RETURN QUERY SELECT FALSE, 'user already flagged this post'::TEXT, NULL::INTEGER[]; + RETURN; + END IF; + + SELECT ARRAY_AGG(account_id) INTO _team_members + FROM hivemind_app.hive_roles + WHERE community_id = _community_id + AND role_id >= 4; + + RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index b53d6a1a8..e969506bb 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -453,7 +453,14 @@ class CommunityOp: ) self._handle_result(result, 'unpin_post', payload=self.notes) elif action == 'flagPost': - self._notify_team('flag_post', payload=self.notes) + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.flag_post( + :actor_id, :community_id, :post_id, :community + )""", + **params, + ) + if self._handle_result(result): + self._notify_team('flag_post', team_members=result['team_members'], payload=self.notes) FSM.flush_stat('Community', perf_counter() - time_start, 1) return True @@ -498,16 +505,17 @@ class CommunityOp: **kwargs, ) - def _notify_team(self, op, **kwargs): + def _notify_team(self, op, team_members=None, **kwargs): """Send notifications to all team members (mod, admin, owner) in a community.""" - team_members = DbAdapterHolder.common_block_processing_db().query_col( - f"""SELECT account_id FROM {SCHEMA_NAME}.hive_roles - WHERE community_id = :community_id - AND role_id >= :min_role_id""", - community_id=self.community_id, - min_role_id=Role.mod.value # 4 - ) + if team_members is None: + team_members = DbAdapterHolder.common_block_processing_db().query_col( + f"""SELECT account_id FROM {SCHEMA_NAME}.hive_roles + WHERE community_id = :community_id + AND role_id >= :min_role_id""", + community_id=self.community_id, + min_role_id=Role.mod.value # 4 + ) for member_id in team_members: # Skip sending notification to the source user (the one triggering the notification) @@ -651,16 +659,13 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost', 'flagPost'): return actor_role = Community.get_user_role(community_id, self.actor_id) if action == 'updateProps': assert actor_role >= Role.admin, 'only admins can update props' - elif action == 'flagPost': - assert actor_role > Role.muted, 'muted users cannot flag posts' - assert not self._flagged(), 'user already flagged this post' # TODO drop this, functions should return if user is subscribed or not if they result in a notification def _subscribed(self, account_id): -- GitLab From 7246b94ecda6401799aaa5ec335fe8c260a420bd Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 13:58:59 -0500 Subject: [PATCH 18/36] UpdateProps --- hive/db/sql_scripts/community.sql | 38 +++++++++++++++++++++++++++++++ hive/indexer/community.py | 18 ++++++++------- 2 files changed, 48 insertions(+), 8 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 19c3aa1ba..d59649abd 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -416,4 +416,42 @@ BEGIN RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; END; +$$ LANGUAGE plpgsql; + +DROP FUNCTION IF EXISTS hivemind_app.update_community_props; +CREATE OR REPLACE FUNCTION hivemind_app.update_community_props( + _actor_id INTEGER, + _community_id INTEGER, + _props JSONB +) RETURNS TABLE(success BOOLEAN, error_message TEXT, team_members INTEGER[]) AS $$ +DECLARE + _actor_role INTEGER; + _team_members INTEGER[]; +BEGIN + _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); + + IF _actor_role < 6 THEN + RETURN QUERY SELECT FALSE, 'only admins can update props'::TEXT, NULL::INTEGER[]; + RETURN; + END IF; + + UPDATE hivemind_app.hive_communities + SET + title = CASE WHEN jsonb_exists(_props, 'title') THEN _props->>'title' ELSE title END, + about = CASE WHEN jsonb_exists(_props, 'about') THEN _props->>'about' ELSE about END, + lang = CASE WHEN jsonb_exists(_props, 'lang') THEN _props->>'lang' ELSE lang END, + is_nsfw = CASE WHEN jsonb_exists(_props, 'is_nsfw') THEN (_props->>'is_nsfw')::BOOLEAN ELSE is_nsfw END, + description = CASE WHEN jsonb_exists(_props, 'description') THEN _props->>'description' ELSE description END, + flag_text = CASE WHEN jsonb_exists(_props, 'flag_text') THEN _props->>'flag_text' ELSE flag_text END, + settings = CASE WHEN jsonb_exists(_props, 'settings') THEN (_props->>'settings')::JSONB ELSE settings END, + type_id = CASE WHEN jsonb_exists(_props, 'type_id') THEN (_props->>'type_id')::INTEGER ELSE type_id END + WHERE id = _community_id; + + SELECT ARRAY_AGG(account_id) INTO _team_members + FROM hivemind_app.hive_roles + WHERE community_id = _community_id + AND role_id >= 4; + + RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; +END; $$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/hive/indexer/community.py b/hive/indexer/community.py index e969506bb..54c3a0185 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -378,11 +378,16 @@ class CommunityOp: # Community-level commands if action == 'updateProps': - bind = ', '.join([k + " = :" + k for k in list(self.props.keys())]) - DbAdapterHolder.common_block_processing_db().query( - f"UPDATE {SCHEMA_NAME}.hive_communities SET {bind} WHERE id = :id", id=self.community_id, **self.props + result = DbAdapterHolder.common_block_processing_db().query_row( + f"""SELECT * FROM {SCHEMA_NAME}.update_community_props( + :actor_id, :community_id, :props + )""", + actor_id=self.actor_id, + community_id=self.community_id, + props=json.dumps(self.props) ) - self._notify_team('set_props', payload=json.dumps(read_key_dict(self.op, 'props'))) + if self._handle_result(result): + self._notify_team('set_props', team_members=result['team_members'], payload=json.dumps(read_key_dict(self.op, 'props'))) elif action == 'subscribe': params['counter'] = CommunityOp._counter.increment(self.block_num) @@ -659,14 +664,11 @@ class CommunityOp: action = self.action # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost', 'flagPost'): + if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost', 'flagPost', 'updateProps'): return actor_role = Community.get_user_role(community_id, self.actor_id) - if action == 'updateProps': - assert actor_role >= Role.admin, 'only admins can update props' - # TODO drop this, functions should return if user is subscribed or not if they result in a notification def _subscribed(self, account_id): """Check an account's subscription status.""" -- GitLab From 2579935b17235558d1dcd1eb2ad5485e4367a35e Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 15:21:33 -0500 Subject: [PATCH 19/36] clean unused functions and added TODOs --- hive/db/sql_scripts/community.sql | 4 +-- hive/indexer/community.py | 60 ++----------------------------- 2 files changed, 4 insertions(+), 60 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index d59649abd..39a2acc3f 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -412,7 +412,7 @@ BEGIN SELECT ARRAY_AGG(account_id) INTO _team_members FROM hivemind_app.hive_roles WHERE community_id = _community_id - AND role_id >= 4; + AND role_id >= 4; -- better or equal to mod RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; END; @@ -450,7 +450,7 @@ BEGIN SELECT ARRAY_AGG(account_id) INTO _team_members FROM hivemind_app.hive_roles WHERE community_id = _community_id - AND role_id >= 4; + AND role_id >= 4; -- better or equal to mod RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; END; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 54c3a0185..32f3e747b 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -341,8 +341,7 @@ class CommunityOp: # validate and read schema self._read_schema() - # validate permissions - self._validate_permissions() + # permissions are validated directly in SQL self.valid = True @@ -512,16 +511,6 @@ class CommunityOp: def _notify_team(self, op, team_members=None, **kwargs): """Send notifications to all team members (mod, admin, owner) in a community.""" - - if team_members is None: - team_members = DbAdapterHolder.common_block_processing_db().query_col( - f"""SELECT account_id FROM {SCHEMA_NAME}.hive_roles - WHERE community_id = :community_id - AND role_id >= :min_role_id""", - community_id=self.community_id, - min_role_id=Role.mod.value # 4 - ) - for member_id in team_members: # Skip sending notification to the source user (the one triggering the notification) if member_id == self.actor_id: @@ -556,7 +545,7 @@ class CommunityOp: if 'account' in schema: self._read_account() if 'permlink' in schema: - self._read_permlink() + self._read_permlink() # TODO remove this and manage the pid/permlink read in SQL when needed if 'role' in schema: self._read_role() if 'notes' in schema: @@ -659,16 +648,6 @@ class CommunityOp: assert out, 'props were blank' self.props = out - def _validate_permissions(self): - community_id = self.community_id - action = self.action - - # Skip validation as it's handled in SQL - if action in ('subscribe', 'unsubscribe', 'setUserTitle', 'setRole', 'mutePost', 'unmutePost', 'pinPost', 'unpinPost', 'flagPost', 'updateProps'): - return - - actor_role = Community.get_user_role(community_id, self.actor_id) - # TODO drop this, functions should return if user is subscribed or not if they result in a notification def _subscribed(self, account_id): """Check an account's subscription status.""" @@ -678,38 +657,3 @@ class CommunityOp: AND account_id = :account_id )""" return DbAdapterHolder.common_block_processing_db().query_one(sql, community_id=self.community_id, account_id=account_id) - - def _muted(self): - """Check post's muted status.""" - sql = f"SELECT is_muted FROM {SCHEMA_NAME}.hive_posts WHERE id = :id" - return bool(DbAdapterHolder.common_block_processing_db().query_one(sql, id=self.post_id)) - - def _parent_muted(self): - """Check parent post's muted status.""" - parent_id = f"SELECT parent_id FROM {SCHEMA_NAME}.hive_posts WHERE id = :id" - sql = f"SELECT is_muted FROM {SCHEMA_NAME}.hive_posts WHERE id = ({parent_id})" - return bool(DbAdapterHolder.common_block_processing_db().query_one(sql, id=self.post_id)) - - def _pinned(self): - """Check post's pinned status.""" - sql = f"SELECT is_pinned FROM {SCHEMA_NAME}.hive_posts WHERE id = :id" - return bool(DbAdapterHolder.common_block_processing_db().query_one(sql, id=self.post_id)) - - def _flagged(self): - """Check user's flag status. Note that because hive_notification_cache gets flushed every 90 days, this means you can re-flag every 90 days""" - from hive.indexer.notify import NotifyType - - sql = f"""SELECT 1 FROM {SCHEMA_NAME}.hive_notification_cache - WHERE community = :community - AND post_id = :post_id - AND type_id = :type_id - AND src = :src""" - return bool( - DbAdapterHolder.common_block_processing_db().query_one( - sql, - community=self.community, - post_id=self.post_id, - type_id=NotifyType['flag_post'], - src=self.actor_id, - ) - ) -- GitLab From f1301285870d80ec4254d9915c2861508989a26b Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 15:58:22 -0500 Subject: [PATCH 20/36] Process permlink validation in pgsql --- hive/db/sql_scripts/community.sql | 118 +++++++++++++++++------- hive/db/sql_scripts/community_utils.sql | 29 ++++++ hive/indexer/community.py | 70 +++++++------- 3 files changed, 150 insertions(+), 67 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 39a2acc3f..f7a7cd4b8 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -51,8 +51,8 @@ BEGIN _date, r.id, hc.id, - 0, - 0, + NULL, + NULL, COALESCE(rep.rep, 25), '', hc.name, @@ -196,8 +196,8 @@ BEGIN _block_date, 0, _account_id, - 0, - 0, + NULL, + NULL, 35, '', _name, @@ -241,24 +241,35 @@ DROP FUNCTION IF EXISTS hivemind_app.mute_post; CREATE OR REPLACE FUNCTION hivemind_app.mute_post( _actor_id INTEGER, _community_id INTEGER, - _post_id INTEGER, + _account_id INTEGER, + _permlink VARCHAR, _muted_reasons INTEGER -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ DECLARE _actor_role INTEGER; _is_muted BOOLEAN; + _post_id INTEGER; + _post_error TEXT; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can mute posts'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods and above can mute posts'::TEXT, NULL::INTEGER; + RETURN; + END IF; + + SELECT p.post_id, p.error_message INTO _post_id, _post_error + FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; RETURN; END IF; SELECT is_muted INTO _is_muted FROM hivemind_app.hive_posts WHERE id = _post_id; IF _is_muted THEN - RETURN QUERY SELECT FALSE, 'post is already muted'::TEXT; + RETURN QUERY SELECT FALSE, 'post is already muted'::TEXT, NULL::INTEGER; RETURN; END IF; @@ -266,7 +277,7 @@ BEGIN SET is_muted = true, muted_reasons = _muted_reasons WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT; + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; END; $$ LANGUAGE plpgsql; @@ -274,33 +285,43 @@ DROP FUNCTION IF EXISTS hivemind_app.unmute_post; CREATE OR REPLACE FUNCTION hivemind_app.unmute_post( _actor_id INTEGER, _community_id INTEGER, - _post_id INTEGER -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ + _account_id INTEGER, + _permlink VARCHAR +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ DECLARE _actor_role INTEGER; _is_muted BOOLEAN; _parent_id INTEGER; _parent_is_muted BOOLEAN; + _post_id INTEGER; + _post_error TEXT; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can unmute posts'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods and above can unmute posts'::TEXT, NULL::INTEGER; + RETURN; + END IF; + + SELECT p.post_id, p.error_message INTO _post_id, _post_error + FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; RETURN; END IF; SELECT is_muted, parent_id INTO _is_muted, _parent_id FROM hivemind_app.hive_posts WHERE id = _post_id; IF NOT _is_muted THEN - RETURN QUERY SELECT FALSE, 'post is not muted'::TEXT; + RETURN QUERY SELECT FALSE, 'post is not muted'::TEXT, NULL::INTEGER; RETURN; END IF; IF _parent_id IS NOT NULL THEN - -- TODO maybe it would be faster to fetch parent at the same time as we fetch the child in one query vs two ? SELECT is_muted INTO _parent_is_muted FROM hivemind_app.hive_posts WHERE id = _parent_id; IF _parent_is_muted THEN - RETURN QUERY SELECT FALSE, 'parent post is muted'::TEXT; + RETURN QUERY SELECT FALSE, 'parent post is muted'::TEXT, NULL::INTEGER; RETURN; END IF; END IF; @@ -309,7 +330,7 @@ BEGIN SET is_muted = false, muted_reasons = 0 WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT; + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; END; $$ LANGUAGE plpgsql; @@ -317,23 +338,34 @@ DROP FUNCTION IF EXISTS hivemind_app.pin_post; CREATE OR REPLACE FUNCTION hivemind_app.pin_post( _actor_id INTEGER, _community_id INTEGER, - _post_id INTEGER -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ + _account_id INTEGER, + _permlink VARCHAR +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ DECLARE _actor_role INTEGER; _is_pinned BOOLEAN; + _post_id INTEGER; + _post_error TEXT; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can pin posts'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods and above can pin posts'::TEXT, NULL::INTEGER; + RETURN; + END IF; + + SELECT p.post_id, p.error_message INTO _post_id, _post_error + FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; RETURN; END IF; SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; IF _is_pinned THEN - RETURN QUERY SELECT FALSE, 'post is already pinned'::TEXT; + RETURN QUERY SELECT FALSE, 'post is already pinned'::TEXT, NULL::INTEGER; RETURN; END IF; @@ -341,7 +373,7 @@ BEGIN SET is_pinned = true WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT; + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; END; $$ LANGUAGE plpgsql; @@ -349,23 +381,34 @@ DROP FUNCTION IF EXISTS hivemind_app.unpin_post; CREATE OR REPLACE FUNCTION hivemind_app.unpin_post( _actor_id INTEGER, _community_id INTEGER, - _post_id INTEGER -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ + _account_id INTEGER, + _permlink VARCHAR +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ DECLARE _actor_role INTEGER; _is_pinned BOOLEAN; + _post_id INTEGER; + _post_error TEXT; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can unpin posts'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods and above can unpin posts'::TEXT, NULL::INTEGER; + RETURN; + END IF; + + SELECT p.post_id, p.error_message INTO _post_id, _post_error + FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; RETURN; END IF; SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; IF NOT _is_pinned THEN - RETURN QUERY SELECT FALSE, 'post is not pinned'::TEXT; + RETURN QUERY SELECT FALSE, 'post is not pinned'::TEXT, NULL::INTEGER; RETURN; END IF; @@ -373,7 +416,7 @@ BEGIN SET is_pinned = false WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT; + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; END; $$ LANGUAGE plpgsql; @@ -381,31 +424,42 @@ DROP FUNCTION IF EXISTS hivemind_app.flag_post; CREATE OR REPLACE FUNCTION hivemind_app.flag_post( _actor_id INTEGER, _community_id INTEGER, - _post_id INTEGER, + _account_id INTEGER, + _permlink VARCHAR, _community_name VARCHAR -) RETURNS TABLE(success BOOLEAN, error_message TEXT, team_members INTEGER[]) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, team_members INTEGER[]) AS $$ DECLARE _actor_role INTEGER; _already_flagged BOOLEAN; _team_members INTEGER[]; + _post_id INTEGER; + _post_error TEXT; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role <= -2 THEN - RETURN QUERY SELECT FALSE, 'muted users cannot flag posts'::TEXT, NULL::INTEGER[]; + RETURN QUERY SELECT FALSE, 'muted users cannot flag posts'::TEXT, NULL::INTEGER, NULL::INTEGER[]; + RETURN; + END IF; + + SELECT p.post_id, p.error_message INTO _post_id, _post_error + FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, NULL::INTEGER[]; RETURN; END IF; SELECT EXISTS( SELECT 1 FROM hivemind_app.hive_notification_cache WHERE community = _community_name - AND post_id = _post_id + AND hive_notification_cache.post_id = _post_id AND type_id = 9 -- flag_post AND src = _actor_id ) INTO _already_flagged; IF _already_flagged THEN - RETURN QUERY SELECT FALSE, 'user already flagged this post'::TEXT, NULL::INTEGER[]; + RETURN QUERY SELECT FALSE, 'user already flagged this post'::TEXT, NULL::INTEGER, NULL::INTEGER[]; RETURN; END IF; @@ -414,7 +468,7 @@ BEGIN WHERE community_id = _community_id AND role_id >= 4; -- better or equal to mod - RETURN QUERY SELECT TRUE, ''::TEXT, _team_members; + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _team_members; END; $$ LANGUAGE plpgsql; diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 7801b9cc8..71c507a54 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -26,3 +26,32 @@ BEGIN ); END; $$ LANGUAGE plpgsql STABLE; + +DROP FUNCTION IF EXISTS hivemind_app.get_post_id_by_permlink; +CREATE OR REPLACE FUNCTION hivemind_app.get_post_id_by_permlink( + _account_id INTEGER, + _permlink VARCHAR, + _community_id INTEGER +) RETURNS TABLE(post_id INTEGER, error_message TEXT) AS $$ +DECLARE + _post_id INTEGER; + _post_community_id INTEGER; +BEGIN + SELECT hp.id, hp.community_id INTO _post_id, _post_community_id + FROM hivemind_app.live_posts_comments_view hp + JOIN hivemind_app.hive_permlink_data hpd ON hp.permlink_id = hpd.id + WHERE hp.author_id = _account_id AND hpd.permlink = _permlink; + + IF _post_id IS NULL THEN + RETURN QUERY SELECT NULL::INTEGER, 'post does not exist'::TEXT; + RETURN; + END IF; + + IF _post_community_id != _community_id THEN + RETURN QUERY SELECT NULL::INTEGER, 'post does not belong to community'::TEXT; + RETURN; + END IF; + + RETURN QUERY SELECT _post_id, ''::TEXT; +END; +$$ LANGUAGE plpgsql STABLE; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 32f3e747b..fa2e6f778 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -425,46 +425,63 @@ class CommunityOp: elif action == 'mutePost': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.mute_post( - :actor_id, :community_id, :post_id, :muted_reasons + :actor_id, :community_id, :account_id, :permlink, :muted_reasons )""", - **params, + actor_id=self.actor_id, + community_id=self.community_id, + account_id=self.account_id, + permlink=self.permlink, + muted_reasons=params['muted_reasons'] ) self._handle_result(result, 'mute_post', payload=self.notes) elif action == 'unmutePost': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.unmute_post( - :actor_id, :community_id, :post_id + :actor_id, :community_id, :account_id, :permlink )""", - **params, + actor_id=self.actor_id, + community_id=self.community_id, + account_id=self.account_id, + permlink=self.permlink ) self._handle_result(result, 'unmute_post', payload=self.notes) elif action == 'pinPost': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.pin_post( - :actor_id, :community_id, :post_id + :actor_id, :community_id, :account_id, :permlink )""", - **params, + actor_id=self.actor_id, + community_id=self.community_id, + account_id=self.account_id, + permlink=self.permlink ) self._handle_result(result, 'pin_post', payload=self.notes) elif action == 'unpinPost': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.unpin_post( - :actor_id, :community_id, :post_id + :actor_id, :community_id, :account_id, :permlink )""", - **params, + actor_id=self.actor_id, + community_id=self.community_id, + account_id=self.account_id, + permlink=self.permlink ) self._handle_result(result, 'unpin_post', payload=self.notes) elif action == 'flagPost': result = DbAdapterHolder.common_block_processing_db().query_row( f"""SELECT * FROM {SCHEMA_NAME}.flag_post( - :actor_id, :community_id, :post_id, :community + :actor_id, :community_id, :account_id, :permlink, :community )""", - **params, + actor_id=self.actor_id, + community_id=self.community_id, + account_id=self.account_id, + permlink=self.permlink, + community=self.community ) if self._handle_result(result): - self._notify_team('flag_post', team_members=result['team_members'], payload=self.notes) + self._notify_team('flag_post', team_members=result['team_members'], post_id=result['post_id'], payload=self.notes) FSM.flush_stat('Community', perf_counter() - time_start, 1) return True @@ -473,7 +490,8 @@ class CommunityOp: """Handle result from SQL operations with success/error_message pattern.""" if result and result['success']: if success_op: - self._notify(success_op, payload=payload) + post_id = result['post_id'] if 'post_id' in result.keys() else None + self._notify(success_op, post_id=post_id, payload=payload) return True elif result: Notify( @@ -488,7 +506,7 @@ class CommunityOp: return False return True - def _notify(self, op, **kwargs): + def _notify(self, op, post_id=None, **kwargs): dst_id = None score = 35 @@ -502,14 +520,14 @@ class CommunityOp: type_id=op, src_id=self.actor_id, dst_id=dst_id, - post_id=self.post_id, + post_id=post_id, when=self.date, community_id=self.community_id, score=score, **kwargs, ) - def _notify_team(self, op, team_members=None, **kwargs): + def _notify_team(self, op, team_members=None, post_id=None, **kwargs): """Send notifications to all team members (mod, admin, owner) in a community.""" for member_id in team_members: # Skip sending notification to the source user (the one triggering the notification) @@ -521,7 +539,7 @@ class CommunityOp: type_id=op, src_id=self.actor_id, dst_id=member_id, - post_id=self.post_id, + post_id=post_id, when=self.date, community_id=self.community_id, score=35, @@ -545,7 +563,7 @@ class CommunityOp: if 'account' in schema: self._read_account() if 'permlink' in schema: - self._read_permlink() # TODO remove this and manage the pid/permlink read in SQL when needed + self._read_permlink() if 'role' in schema: self._read_role() if 'notes' in schema: @@ -574,25 +592,7 @@ class CommunityOp: assert self.account, 'permlink requires named account' _permlink = read_key_str(self.op, 'permlink', 256) assert _permlink, 'must name a permlink' - - sql = f""" - SELECT hp.id, community_id - FROM {SCHEMA_NAME}.live_posts_comments_view hp - JOIN {SCHEMA_NAME}.hive_permlink_data hpd ON hp.permlink_id=hpd.id - WHERE author_id=:_author AND hpd.permlink=:_permlink - """ - result = DbAdapterHolder.common_block_processing_db().query_row(sql, _author=self.account_id, _permlink=_permlink) - assert result, f'post does not exists {self.account}/{_permlink}' - result = dict(result) - - _pid = result.get('id', None) - assert _pid, f'post does not exists {self.account}/{_permlink}' - - _comm = result.get('community_id', None) - assert self.community_id == _comm, 'post does not belong to community' - self.permlink = _permlink - self.post_id = _pid def _read_role(self): _role = read_key_str(self.op, 'role', 16) -- GitLab From 9cc52cc1d9c6a4f3743265e6a9f6005fa8be739a Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 16:37:44 -0500 Subject: [PATCH 21/36] removed more functions that are no longer used --- hive/indexer/community.py | 38 -------------------------------------- 1 file changed, 38 deletions(-) diff --git a/hive/indexer/community.py b/hive/indexer/community.py index fa2e6f778..c7528398b 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -214,44 +214,6 @@ class Community: cls._names[cid] = name return cid - @classmethod - def _get_name(cls, cid): - if cid in cls._names: - return cls._names[cid] - sql = f"SELECT name FROM {SCHEMA_NAME}.hive_communities WHERE id = :id" - name = DbAdapterHolder.common_block_processing_db().query_one(sql, id=cid) - if cid: - cls._ids[name] = cid - cls._names[cid] = name - return name - - @classmethod - def get_all_muted(cls, community_id): - """Return a list of all muted accounts.""" - return DbAdapterHolder.common_block_processing_db().query_col( - f"""SELECT name FROM {SCHEMA_NAME}.hive_accounts - WHERE id IN (SELECT account_id FROM {SCHEMA_NAME}.hive_roles - WHERE community_id = :community_id - AND role_id < 0)""", - community_id=community_id, - ) - - @classmethod - def get_user_role(cls, community_id, account_id): - """Get user role within a specific community.""" - - return ( - DbAdapterHolder.common_block_processing_db().query_one( - f"""SELECT role_id FROM {SCHEMA_NAME}.hive_roles - WHERE community_id = :community_id - AND account_id = :account_id - LIMIT 1""", - community_id=community_id, - account_id=account_id, - ) - or Role.guest.value - ) - @classmethod def is_post_valid(cls, role): """Given a new post/comment, check if valid as per community rules -- GitLab From 970fc984bbfa3e08c6e2ccb8da5b59e20c46d78a Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 17:28:48 -0500 Subject: [PATCH 22/36] renamed communities sql functions to be more accurate --- hive/db/sql_scripts/community.sql | 24 ++++++++++++------------ hive/indexer/community.py | 12 ++++++------ 2 files changed, 18 insertions(+), 18 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index f7a7cd4b8..cbf9bf8ca 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -207,8 +207,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.set_user_title; -CREATE OR REPLACE FUNCTION hivemind_app.set_user_title( +DROP FUNCTION IF EXISTS hivemind_app.community_set_user_title; +CREATE OR REPLACE FUNCTION hivemind_app.community_set_user_title( _actor_id INTEGER, _account_id INTEGER, _community_id INTEGER, @@ -237,8 +237,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.mute_post; -CREATE OR REPLACE FUNCTION hivemind_app.mute_post( +DROP FUNCTION IF EXISTS hivemind_app.community_mute_post; +CREATE OR REPLACE FUNCTION hivemind_app.community_mute_post( _actor_id INTEGER, _community_id INTEGER, _account_id INTEGER, @@ -281,8 +281,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.unmute_post; -CREATE OR REPLACE FUNCTION hivemind_app.unmute_post( +DROP FUNCTION IF EXISTS hivemind_app.community_unmute_post; +CREATE OR REPLACE FUNCTION hivemind_app.community_unmute_post( _actor_id INTEGER, _community_id INTEGER, _account_id INTEGER, @@ -334,8 +334,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.pin_post; -CREATE OR REPLACE FUNCTION hivemind_app.pin_post( +DROP FUNCTION IF EXISTS hivemind_app.community_pin_post; +CREATE OR REPLACE FUNCTION hivemind_app.community_pin_post( _actor_id INTEGER, _community_id INTEGER, _account_id INTEGER, @@ -377,8 +377,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.unpin_post; -CREATE OR REPLACE FUNCTION hivemind_app.unpin_post( +DROP FUNCTION IF EXISTS hivemind_app.community_unpin_post; +CREATE OR REPLACE FUNCTION hivemind_app.community_unpin_post( _actor_id INTEGER, _community_id INTEGER, _account_id INTEGER, @@ -420,8 +420,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.flag_post; -CREATE OR REPLACE FUNCTION hivemind_app.flag_post( +DROP FUNCTION IF EXISTS hivemind_app.community_flag_post; +CREATE OR REPLACE FUNCTION hivemind_app.community_flag_post( _actor_id INTEGER, _community_id INTEGER, _account_id INTEGER, diff --git a/hive/indexer/community.py b/hive/indexer/community.py index c7528398b..12dcb42e1 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -377,7 +377,7 @@ class CommunityOp: self._handle_result(result, 'set_role', payload=Role(self.role_id).name) elif action == 'setUserTitle': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.set_user_title( + f"""SELECT * FROM {SCHEMA_NAME}.community_set_user_title( :actor_id, :account_id, :community_id, :title, :date )""", **params, @@ -386,7 +386,7 @@ class CommunityOp: # Post-level actions elif action == 'mutePost': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.mute_post( + f"""SELECT * FROM {SCHEMA_NAME}.community_mute_post( :actor_id, :community_id, :account_id, :permlink, :muted_reasons )""", actor_id=self.actor_id, @@ -399,7 +399,7 @@ class CommunityOp: elif action == 'unmutePost': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.unmute_post( + f"""SELECT * FROM {SCHEMA_NAME}.community_unmute_post( :actor_id, :community_id, :account_id, :permlink )""", actor_id=self.actor_id, @@ -411,7 +411,7 @@ class CommunityOp: elif action == 'pinPost': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.pin_post( + f"""SELECT * FROM {SCHEMA_NAME}.community_pin_post( :actor_id, :community_id, :account_id, :permlink )""", actor_id=self.actor_id, @@ -422,7 +422,7 @@ class CommunityOp: self._handle_result(result, 'pin_post', payload=self.notes) elif action == 'unpinPost': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.unpin_post( + f"""SELECT * FROM {SCHEMA_NAME}.community_unpin_post( :actor_id, :community_id, :account_id, :permlink )""", actor_id=self.actor_id, @@ -433,7 +433,7 @@ class CommunityOp: self._handle_result(result, 'unpin_post', payload=self.notes) elif action == 'flagPost': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.flag_post( + f"""SELECT * FROM {SCHEMA_NAME}.community_flag_post( :actor_id, :community_id, :account_id, :permlink, :community )""", actor_id=self.actor_id, -- GitLab From aba6a5f9e0cec0543801137ae88f4bc806aa1e6b Mon Sep 17 00:00:00 2001 From: Howo Date: Tue, 25 Nov 2025 18:10:43 -0500 Subject: [PATCH 23/36] slight optimization but cutting off is_subscribed --- hive/db/sql_scripts/community.sql | 67 +++++++++++++++++++------------ hive/indexer/community.py | 25 ++++-------- 2 files changed, 49 insertions(+), 43 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index cbf9bf8ca..6a3217660 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -244,17 +244,18 @@ CREATE OR REPLACE FUNCTION hivemind_app.community_mute_post( _account_id INTEGER, _permlink VARCHAR, _muted_reasons INTEGER -) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _is_muted BOOLEAN; _post_id INTEGER; _post_error TEXT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can mute posts'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'only mods and above can mute posts'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -262,14 +263,14 @@ BEGIN FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; IF _post_id IS NULL THEN - RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, FALSE; RETURN; END IF; SELECT is_muted INTO _is_muted FROM hivemind_app.hive_posts WHERE id = _post_id; IF _is_muted THEN - RETURN QUERY SELECT FALSE, 'post is already muted'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'post is already muted'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -277,7 +278,9 @@ BEGIN SET is_muted = true, muted_reasons = _muted_reasons WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _is_subscribed; END; $$ LANGUAGE plpgsql; @@ -287,7 +290,7 @@ CREATE OR REPLACE FUNCTION hivemind_app.community_unmute_post( _community_id INTEGER, _account_id INTEGER, _permlink VARCHAR -) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _is_muted BOOLEAN; @@ -295,11 +298,12 @@ DECLARE _parent_is_muted BOOLEAN; _post_id INTEGER; _post_error TEXT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can unmute posts'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'only mods and above can unmute posts'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -307,21 +311,21 @@ BEGIN FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; IF _post_id IS NULL THEN - RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, FALSE; RETURN; END IF; SELECT is_muted, parent_id INTO _is_muted, _parent_id FROM hivemind_app.hive_posts WHERE id = _post_id; IF NOT _is_muted THEN - RETURN QUERY SELECT FALSE, 'post is not muted'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'post is not muted'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; IF _parent_id IS NOT NULL THEN SELECT is_muted INTO _parent_is_muted FROM hivemind_app.hive_posts WHERE id = _parent_id; IF _parent_is_muted THEN - RETURN QUERY SELECT FALSE, 'parent post is muted'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'parent post is muted'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; END IF; @@ -330,7 +334,9 @@ BEGIN SET is_muted = false, muted_reasons = 0 WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _is_subscribed; END; $$ LANGUAGE plpgsql; @@ -340,17 +346,18 @@ CREATE OR REPLACE FUNCTION hivemind_app.community_pin_post( _community_id INTEGER, _account_id INTEGER, _permlink VARCHAR -) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _is_pinned BOOLEAN; _post_id INTEGER; _post_error TEXT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can pin posts'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'only mods and above can pin posts'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -358,14 +365,14 @@ BEGIN FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; IF _post_id IS NULL THEN - RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, FALSE; RETURN; END IF; SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; IF _is_pinned THEN - RETURN QUERY SELECT FALSE, 'post is already pinned'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'post is already pinned'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -373,7 +380,9 @@ BEGIN SET is_pinned = true WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _is_subscribed; END; $$ LANGUAGE plpgsql; @@ -383,17 +392,18 @@ CREATE OR REPLACE FUNCTION hivemind_app.community_unpin_post( _community_id INTEGER, _account_id INTEGER, _permlink VARCHAR -) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _is_pinned BOOLEAN; _post_id INTEGER; _post_error TEXT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods and above can unpin posts'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'only mods and above can unpin posts'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -401,14 +411,14 @@ BEGIN FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; IF _post_id IS NULL THEN - RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER; + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, FALSE; RETURN; END IF; SELECT is_pinned INTO _is_pinned FROM hivemind_app.hive_posts WHERE id = _post_id; IF NOT _is_pinned THEN - RETURN QUERY SELECT FALSE, 'post is not pinned'::TEXT, NULL::INTEGER; + RETURN QUERY SELECT FALSE, 'post is not pinned'::TEXT, NULL::INTEGER, FALSE; RETURN; END IF; @@ -416,7 +426,9 @@ BEGIN SET is_pinned = false WHERE id = _post_id; - RETURN QUERY SELECT TRUE, ''::TEXT, _post_id; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _is_subscribed; END; $$ LANGUAGE plpgsql; @@ -427,18 +439,19 @@ CREATE OR REPLACE FUNCTION hivemind_app.community_flag_post( _account_id INTEGER, _permlink VARCHAR, _community_name VARCHAR -) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, team_members INTEGER[]) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, post_id INTEGER, team_members INTEGER[], is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _already_flagged BOOLEAN; _team_members INTEGER[]; _post_id INTEGER; _post_error TEXT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role <= -2 THEN - RETURN QUERY SELECT FALSE, 'muted users cannot flag posts'::TEXT, NULL::INTEGER, NULL::INTEGER[]; + RETURN QUERY SELECT FALSE, 'muted users cannot flag posts'::TEXT, NULL::INTEGER, NULL::INTEGER[], FALSE; RETURN; END IF; @@ -446,7 +459,7 @@ BEGIN FROM hivemind_app.get_post_id_by_permlink(_account_id, _permlink, _community_id) p; IF _post_id IS NULL THEN - RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, NULL::INTEGER[]; + RETURN QUERY SELECT FALSE, _post_error, NULL::INTEGER, NULL::INTEGER[], FALSE; RETURN; END IF; @@ -459,7 +472,7 @@ BEGIN ) INTO _already_flagged; IF _already_flagged THEN - RETURN QUERY SELECT FALSE, 'user already flagged this post'::TEXT, NULL::INTEGER, NULL::INTEGER[]; + RETURN QUERY SELECT FALSE, 'user already flagged this post'::TEXT, NULL::INTEGER, NULL::INTEGER[], FALSE; RETURN; END IF; @@ -468,7 +481,9 @@ BEGIN WHERE community_id = _community_id AND role_id >= 4; -- better or equal to mod - RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _team_members; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _post_id, _team_members, _is_subscribed; END; $$ LANGUAGE plpgsql; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 12dcb42e1..6f964da79 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -448,12 +448,13 @@ class CommunityOp: FSM.flush_stat('Community', perf_counter() - time_start, 1) return True - def _handle_result(self, result, success_op=None, payload=None): - """Handle result from SQL operations with success/error_message pattern.""" + def _handle_result(self, result, operation_name=None, payload=None): + """Handle result from SQL operations with success/error_messages as notifications""" if result and result['success']: - if success_op: + if operation_name: post_id = result['post_id'] if 'post_id' in result.keys() else None - self._notify(success_op, post_id=post_id, payload=payload) + is_subscribed = result['is_subscribed'] if 'is_subscribed' in result.keys() else False + self._notify(operation_name, post_id=post_id, is_subscribed=is_subscribed, payload=payload) return True elif result: Notify( @@ -468,13 +469,13 @@ class CommunityOp: return False return True - def _notify(self, op, post_id=None, **kwargs): + def _notify(self, op, post_id=None, is_subscribed=None, **kwargs): dst_id = None score = 35 if self.account_id: dst_id = self.account_id - if not self._subscribed(self.account_id): + if is_subscribed == False: score = 15 Notify( @@ -608,14 +609,4 @@ class CommunityOp: assert community_type in valid_types, 'invalid community type' out['type_id'] = community_type assert out, 'props were blank' - self.props = out - - # TODO drop this, functions should return if user is subscribed or not if they result in a notification - def _subscribed(self, account_id): - """Check an account's subscription status.""" - sql = f"""SELECT EXISTS( - SELECT 1 FROM {SCHEMA_NAME}.hive_subscriptions - WHERE community_id = :community_id - AND account_id = :account_id - )""" - return DbAdapterHolder.common_block_processing_db().query_one(sql, community_id=self.community_id, account_id=account_id) + self.props = out \ No newline at end of file -- GitLab From 0a1a46f930a66d21c290a63caff235e2fddf3844 Mon Sep 17 00:00:00 2001 From: Howo Date: Wed, 26 Nov 2025 11:48:42 -0500 Subject: [PATCH 24/36] Fix missing subscription return in community_set_role --- hive/db/sql_scripts/community.sql | 23 +++++++++++++---------- hive/indexer/community.py | 2 +- 2 files changed, 14 insertions(+), 11 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 6a3217660..31841e739 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -94,8 +94,8 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.set_community_role; -CREATE OR REPLACE FUNCTION hivemind_app.set_community_role( +DROP FUNCTION IF EXISTS hivemind_app.community_set_role; +CREATE OR REPLACE FUNCTION hivemind_app.community_set_role( _actor_id INTEGER, _account_id INTEGER, _community_id INTEGER, @@ -103,40 +103,41 @@ CREATE OR REPLACE FUNCTION hivemind_app.set_community_role( _date TIMESTAMP, _max_mod_nb INTEGER, -- maximum number of roles >= to mod in a community _mod_role_threshold INTEGER -- minimum role id to be counted as -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; _account_role INTEGER; _mod_count BIGINT; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); IF _actor_role < 4 THEN -- 4 = Role.mod - RETURN QUERY SELECT FALSE, 'only mods and up can alter roles'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods and up can alter roles'::TEXT, FALSE; RETURN; END IF; IF _actor_role <= _role_id THEN - RETURN QUERY SELECT FALSE, 'cannot promote to or above own rank'::TEXT; + RETURN QUERY SELECT FALSE, 'cannot promote to or above own rank'::TEXT, FALSE; RETURN; END IF; _account_role := hivemind_app.get_community_role(_account_id, _community_id); IF _account_role = 8 THEN -- 8 = Role.owner - RETURN QUERY SELECT FALSE, 'cant modify owner role'::TEXT; + RETURN QUERY SELECT FALSE, 'cant modify owner role'::TEXT, FALSE; RETURN; END IF; IF _actor_id != _account_id THEN IF _account_role >= _actor_role THEN - RETURN QUERY SELECT FALSE, 'cant modify a user with a higher role'::TEXT; + RETURN QUERY SELECT FALSE, 'cant modify a user with a higher role'::TEXT, FALSE; RETURN; END IF; IF _account_role = _role_id THEN - RETURN QUERY SELECT FALSE, 'role would not change'::TEXT; + RETURN QUERY SELECT FALSE, 'role would not change'::TEXT, FALSE; RETURN; END IF; END IF; @@ -150,7 +151,7 @@ BEGIN AND account_id != _account_id; IF _mod_count >= _max_mod_nb THEN - RETURN QUERY SELECT FALSE, 'moderator limit exceeded'::TEXT; + RETURN QUERY SELECT FALSE, 'moderator limit exceeded'::TEXT, FALSE; RETURN; END IF; END IF; @@ -160,7 +161,9 @@ BEGIN ON CONFLICT (account_id, community_id) DO UPDATE SET role_id = _role_id; - RETURN QUERY SELECT TRUE, ''::TEXT; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _is_subscribed; END; $$ LANGUAGE plpgsql; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index 6f964da79..f5e11d49b 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -366,7 +366,7 @@ class CommunityOp: # Account-level actions elif action == 'setRole': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.set_community_role( + f"""SELECT * FROM {SCHEMA_NAME}.community_set_role( :actor_id, :account_id, :community_id, :role_id, :date, :max_mod_nb, :mod_role_threshold )""", -- GitLab From ea3f284fa5e525a4b2116ffd4f897ae3d17ea137 Mon Sep 17 00:00:00 2001 From: Howo Date: Wed, 26 Nov 2025 13:30:19 -0500 Subject: [PATCH 25/36] Fix forgotten set title subscribe bool --- hive/db/sql_scripts/community.sql | 15 ++++++++------- hive/indexer/community.py | 2 +- 2 files changed, 9 insertions(+), 8 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 31841e739..784339a4d 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -210,24 +210,23 @@ BEGIN END; $$ LANGUAGE plpgsql; -DROP FUNCTION IF EXISTS hivemind_app.community_set_user_title; -CREATE OR REPLACE FUNCTION hivemind_app.community_set_user_title( +DROP FUNCTION IF EXISTS hivemind_app.community_set_title; +CREATE OR REPLACE FUNCTION hivemind_app.community_set_title( _actor_id INTEGER, _account_id INTEGER, _community_id INTEGER, _title VARCHAR, _date TIMESTAMP -) RETURNS TABLE(success BOOLEAN, error_message TEXT) AS $$ +) RETURNS TABLE(success BOOLEAN, error_message TEXT, is_subscribed BOOLEAN) AS $$ DECLARE _actor_role INTEGER; - _community_name VARCHAR; - _community_title VARCHAR; + _is_subscribed BOOLEAN; BEGIN _actor_role := hivemind_app.get_community_role(_actor_id, _community_id); -- 4 is mod IF _actor_role < 4 THEN - RETURN QUERY SELECT FALSE, 'only mods can set user titles'::TEXT; + RETURN QUERY SELECT FALSE, 'only mods can set user titles'::TEXT, FALSE; RETURN; END IF; @@ -236,7 +235,9 @@ BEGIN ON CONFLICT (account_id, community_id) DO UPDATE SET title = _title; - RETURN QUERY SELECT TRUE, ''::TEXT; + _is_subscribed := hivemind_app.community_is_subscribed(_account_id, _community_id); + + RETURN QUERY SELECT TRUE, ''::TEXT, _is_subscribed; END; $$ LANGUAGE plpgsql; diff --git a/hive/indexer/community.py b/hive/indexer/community.py index f5e11d49b..8d72f08e6 100644 --- a/hive/indexer/community.py +++ b/hive/indexer/community.py @@ -377,7 +377,7 @@ class CommunityOp: self._handle_result(result, 'set_role', payload=Role(self.role_id).name) elif action == 'setUserTitle': result = DbAdapterHolder.common_block_processing_db().query_row( - f"""SELECT * FROM {SCHEMA_NAME}.community_set_user_title( + f"""SELECT * FROM {SCHEMA_NAME}.community_set_title( :actor_id, :account_id, :community_id, :title, :date )""", **params, -- GitLab From ea45dedacad1ea0597c74d0d46d2df009c4058e8 Mon Sep 17 00:00:00 2001 From: Howo Date: Wed, 26 Nov 2025 14:46:36 -0500 Subject: [PATCH 26/36] fixed get_post_by_permlink --- hive/db/sql_scripts/community_utils.sql | 4 +++- 1 file changed, 3 insertions(+), 1 deletion(-) diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 71c507a54..7628f5366 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -36,6 +36,7 @@ CREATE OR REPLACE FUNCTION hivemind_app.get_post_id_by_permlink( DECLARE _post_id INTEGER; _post_community_id INTEGER; + _account_name VARCHAR; BEGIN SELECT hp.id, hp.community_id INTO _post_id, _post_community_id FROM hivemind_app.live_posts_comments_view hp @@ -43,7 +44,8 @@ BEGIN WHERE hp.author_id = _account_id AND hpd.permlink = _permlink; IF _post_id IS NULL THEN - RETURN QUERY SELECT NULL::INTEGER, 'post does not exist'::TEXT; + SELECT name INTO _account_name FROM hivemind_app.hive_accounts WHERE id = _account_id; + RETURN QUERY SELECT NULL::INTEGER, ('post does not exist: @' || _account_name || '/' || _permlink)::TEXT; RETURN; END IF; -- GitLab From 5eb59c396f52ce77cc6999720b49c9c81b70dce8 Mon Sep 17 00:00:00 2001 From: Howo Date: Wed, 26 Nov 2025 19:22:36 -0500 Subject: [PATCH 27/36] fixed get_post_by_permlink error text --- hive/db/sql_scripts/community_utils.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 7628f5366..18c8a0333 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -45,7 +45,7 @@ BEGIN IF _post_id IS NULL THEN SELECT name INTO _account_name FROM hivemind_app.hive_accounts WHERE id = _account_id; - RETURN QUERY SELECT NULL::INTEGER, ('post does not exist: @' || _account_name || '/' || _permlink)::TEXT; + RETURN QUERY SELECT NULL::INTEGER, ('post does not exists ' || _account_name || '/' || _permlink)::TEXT; RETURN; END IF; -- GitLab From f7e6300a3d37ffc5074eed96400f28f1049ef641 Mon Sep 17 00:00:00 2001 From: Howo Date: Thu, 27 Nov 2025 13:21:56 -0500 Subject: [PATCH 28/36] remove redundant check --- hive/db/sql_scripts/community.sql | 5 ++--- 1 file changed, 2 insertions(+), 3 deletions(-) diff --git a/hive/db/sql_scripts/community.sql b/hive/db/sql_scripts/community.sql index 784339a4d..8491f5f47 100644 --- a/hive/db/sql_scripts/community.sql +++ b/hive/db/sql_scripts/community.sql @@ -61,7 +61,6 @@ BEGIN JOIN hivemind_app.hive_communities AS hc ON hc.id = _community_id LEFT JOIN final_rep AS rep ON r.haf_id = rep.account_id WHERE r.id = _actor_id - AND _block_num > hivemind_app.block_before_irreversible('90 days') AND COALESCE(rep.rep, 25) > 0 AND r.id IS DISTINCT FROM hc.id ON CONFLICT (src, dst, type_id, post_id, block_num) DO NOTHING; @@ -192,7 +191,7 @@ BEGIN IF _block_num > _notification_first_block THEN INSERT INTO hivemind_app.hive_notification_cache (id, block_num, type_id, created_at, src, dst, dst_post_id, post_id, score, payload, community, community_title) - SELECT + VALUES ( hivemind_app.notification_id(_block_date, 1, _counter), _block_num, 1, @@ -205,7 +204,7 @@ BEGIN '', _name, '' - WHERE _block_num > hivemind_app.block_before_irreversible('90 days'); + ); END IF; END; $$ LANGUAGE plpgsql; -- GitLab From 378aa4b307635bd0d5cdd9f262331740fb0c559d Mon Sep 17 00:00:00 2001 From: Howo Date: Thu, 27 Nov 2025 13:23:43 -0500 Subject: [PATCH 29/36] fix typo --- hive/db/sql_scripts/community_utils.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hive/db/sql_scripts/community_utils.sql b/hive/db/sql_scripts/community_utils.sql index 18c8a0333..4984f84a0 100644 --- a/hive/db/sql_scripts/community_utils.sql +++ b/hive/db/sql_scripts/community_utils.sql @@ -50,7 +50,7 @@ BEGIN END IF; IF _post_community_id != _community_id THEN - RETURN QUERY SELECT NULL::INTEGER, 'post does not belong to community'::TEXT; + RETURN QUERY SELECT NULL::INTEGER, 'post does not belong to a community'::TEXT; RETURN; END IF; -- GitLab From e99e22a9a0452488db91f84f1e7cf58c4d2aa34c Mon Sep 17 00:00:00 2001 From: Howo Date: Thu, 27 Nov 2025 14:38:21 -0500 Subject: [PATCH 30/36] change error test to be better --- .../account_notifications/test-safari.pat.json | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/tests/api_tests/hivemind/tavern/bridge_api_patterns/account_notifications/test-safari.pat.json b/tests/api_tests/hivemind/tavern/bridge_api_patterns/account_notifications/test-safari.pat.json index 0576a2432..d8e866cec 100644 --- a/tests/api_tests/hivemind/tavern/bridge_api_patterns/account_notifications/test-safari.pat.json +++ b/tests/api_tests/hivemind/tavern/bridge_api_patterns/account_notifications/test-safari.pat.json @@ -2,7 +2,7 @@ { "date": "2016-09-15T19:47:48", "id": "4062413112475650", - "msg": "error: post does not belong to community", + "msg": "error: post does not belong to a community", "score": 35, "type": "error", "url": "c/hive-198723" -- GitLab From 18a78354d1750f869b19354f20e75397bb550436 Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 18:22:05 -0500 Subject: [PATCH 31/36] Fix AttributeError: list has no .items() method in set_logged_table_attribute MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit logged_config is a list, not a dict, so iterating with .items() would crash. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- hive/db/schema.py | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/hive/db/schema.py b/hive/db/schema.py index 215833a92..a7b239672 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -860,7 +860,7 @@ def set_logged_table_attribute(db, logged): 'hive_votes', ] - for table in logged_config.items(): + for table in logged_config: log.info(f"Setting {'LOGGED' if logged else 'UNLOGGED'} attribute on a table: {table}") sql = """ALTER TABLE {} SET {}""" db.query_no_return(sql.format(table, 'LOGGED' if logged else 'UNLOGGED')) -- GitLab From e54067761fba939c3c867676788f3d146479092a Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 19:06:04 -0500 Subject: [PATCH 32/36] Remove advisory lock contention between votes and posts flush MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit The advisory lock (777) was being used by both votes.py and posts.py during parallel flush operations, causing serialization that defeated the purpose of parallel flushing. Analysis showed that: - votes.py updates: rshares, abs_rshares, sc_hot, sc_trend, total_votes, net_votes - posts.py updates: total_payout_value, curator_payout_value, author_rewards, etc. These update completely disjoint columns of hive_posts, so PostgreSQL's native row-level locking is sufficient. The advisory lock was unnecessary and was causing ~15-25% performance degradation during massive sync. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- hive/indexer/posts.py | 4 +++- hive/indexer/votes.py | 4 +++- 2 files changed, 6 insertions(+), 2 deletions(-) diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index 10a2fd2f4..eae43fea6 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -220,7 +220,9 @@ class Posts(DbAdapterHolder): for chunk in chunks(cls._comment_payout_ops, 1000): cls.beginTx() - cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update_posts_rshares in votes + # Advisory lock removed: posts payout updates and votes rshares updates affect + # disjoint columns of hive_posts, so PostgreSQL row-level locking is sufficient. + # Lock was causing serialization between parallel flush operations. values_str = ','.join(chunk) actual_query = sql.format(values_str) cls.db.query_prepared(actual_query) diff --git a/hive/indexer/votes.py b/hive/indexer/votes.py index 4044b52ff..a9f5ffcab 100644 --- a/hive/indexer/votes.py +++ b/hive/indexer/votes.py @@ -193,7 +193,9 @@ class Votes(DbAdapterHolder): ) actual_query = sql.format(values_str) post_ids = cls.db.query_prepared_all(actual_query) - cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update hive_posts in posts + # Advisory lock removed: votes and posts update disjoint columns of hive_posts, + # so PostgreSQL row-level locking is sufficient. Lock was causing serialization + # between parallel flush operations. cls.db.query_no_return("SELECT * FROM hivemind_app.update_posts_rshares(:post_ids)", post_ids=[id[0] for id in post_ids]) cls.commitTx() -- GitLab From f81d6d772d4eb3c1c2f623d226c92253bb72afe4 Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 20:14:10 -0500 Subject: [PATCH 33/36] Restore advisory lock to prevent deadlock in hive_posts updates MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit The previous commit removed the advisory lock (777) between votes and posts flush operations, reasoning that they update disjoint columns. However, CI testing revealed this causes deadlocks: psycopg2.errors.DeadlockDetected: deadlock detected DETAIL: Process 581 waits for ShareLock on transaction 71798; blocked by process 579. Process 579 waits for ShareLock on transaction 71796; blocked by process 581. CONTEXT: while updating tuple (74,28) in relation "hive_posts" While the columns are disjoint, both operations acquire row-level locks on the same rows in hive_posts. When the same post receives both a vote and a payout operation in the same batch, the two parallel transactions can acquire locks in different orders, causing deadlock. The advisory lock ensures serialization and prevents this deadlock scenario. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- hive/indexer/posts.py | 4 +--- hive/indexer/votes.py | 4 +--- 2 files changed, 2 insertions(+), 6 deletions(-) diff --git a/hive/indexer/posts.py b/hive/indexer/posts.py index eae43fea6..10a2fd2f4 100644 --- a/hive/indexer/posts.py +++ b/hive/indexer/posts.py @@ -220,9 +220,7 @@ class Posts(DbAdapterHolder): for chunk in chunks(cls._comment_payout_ops, 1000): cls.beginTx() - # Advisory lock removed: posts payout updates and votes rshares updates affect - # disjoint columns of hive_posts, so PostgreSQL row-level locking is sufficient. - # Lock was causing serialization between parallel flush operations. + cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update_posts_rshares in votes values_str = ','.join(chunk) actual_query = sql.format(values_str) cls.db.query_prepared(actual_query) diff --git a/hive/indexer/votes.py b/hive/indexer/votes.py index a9f5ffcab..4044b52ff 100644 --- a/hive/indexer/votes.py +++ b/hive/indexer/votes.py @@ -193,9 +193,7 @@ class Votes(DbAdapterHolder): ) actual_query = sql.format(values_str) post_ids = cls.db.query_prepared_all(actual_query) - # Advisory lock removed: votes and posts update disjoint columns of hive_posts, - # so PostgreSQL row-level locking is sufficient. Lock was causing serialization - # between parallel flush operations. + cls.db.query_no_return('SELECT pg_advisory_xact_lock(777)') # synchronise with update hive_posts in posts cls.db.query_no_return("SELECT * FROM hivemind_app.update_posts_rshares(:post_ids)", post_ids=[id[0] for id in post_ids]) cls.commitTx() -- GitLab From da2f7f3557f7f82a37f2dde915e2725248a01532 Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 20:29:05 -0500 Subject: [PATCH 34/36] Re-enable UNLOGGED tables during massive sync for faster inserts MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit This re-enables a feature originally implemented by Bartek Wrona in Sept 2020 that was disabled in June 2024. During massive sync, the following tables are set to UNLOGGED to avoid WAL writes: - hive_accounts - hive_permlink_data - hive_post_tags - hive_posts - hive_post_data - hive_votes Tables are converted back to LOGGED before entering live sync mode. Trade-off: Significantly faster inserts during massive sync, but data would be lost on crash (requiring resync from scratch). This is acceptable for initial sync scenarios. Also fixed: Added SCHEMA_NAME prefix to table names in set_logged_table_attribute(). 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- hive/db/db_state.py | 8 +++++++- hive/db/schema.py | 8 ++++---- 2 files changed, 11 insertions(+), 5 deletions(-) diff --git a/hive/db/db_state.py b/hive/db/db_state.py index a2b9a0ed7..d6f9681c2 100644 --- a/hive/db/db_state.py +++ b/hive/db/db_state.py @@ -320,6 +320,10 @@ class DbState: # is_pre_process, drop, create cls.processing_indexes(True, True, False) + # Set tables to UNLOGGED for faster inserts (no WAL writes) + from hive.db.schema import set_logged_table_attribute + set_logged_table_attribute(cls.db(), False) + cls._indexes_were_disabled = True cls._indexes_were_enabled = False log.info("[MASSIVE] Indexes are disabled") @@ -367,7 +371,9 @@ class DbState: if cls._fk_were_enabled: return - from hive.db.schema import create_fk + # Set tables back to LOGGED before going live (generates WAL for durability) + from hive.db.schema import set_logged_table_attribute, create_fk + set_logged_table_attribute(cls.db(), True) start_time_foreign_keys = perf_counter() log.info("Recreating foreign keys") diff --git a/hive/db/schema.py b/hive/db/schema.py index a7b239672..6bb6638b5 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -849,7 +849,7 @@ def set_fillfactor(db): def set_logged_table_attribute(db, logged): - """Initializes/resets LOGGED/UNLOGGED attribute for tables which are intesively updated""" + """Initializes/resets LOGGED/UNLOGGED attribute for tables which are intensively updated""" logged_config = [ 'hive_accounts', @@ -861,9 +861,9 @@ def set_logged_table_attribute(db, logged): ] for table in logged_config: - log.info(f"Setting {'LOGGED' if logged else 'UNLOGGED'} attribute on a table: {table}") - sql = """ALTER TABLE {} SET {}""" - db.query_no_return(sql.format(table, 'LOGGED' if logged else 'UNLOGGED')) + log.info(f"Setting {'LOGGED' if logged else 'UNLOGGED'} attribute on table: {SCHEMA_NAME}.{table}") + sql = f"ALTER TABLE {SCHEMA_NAME}.{table} SET {'LOGGED' if logged else 'UNLOGGED'}" + db.query_no_return(sql) def execute_sql_script(query_executor, path_to_script): -- GitLab From 47e18e1e3328e6fbaa222e96cd3af1a2ff99c6fb Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 20:34:37 -0500 Subject: [PATCH 35/36] Parallelize LOGGED/UNLOGGED table conversion for faster sync transitions MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Convert tables to LOGGED/UNLOGGED in parallel using ThreadPoolExecutor, with each table getting its own database connection. This significantly reduces the time needed to transition between massive sync and live mode. Table sizes (on full sync): - hive_votes: ~319 GB (bottleneck) - hive_post_data: ~127 GB - hive_posts: ~83 GB - hive_permlink_data: ~27 GB - hive_post_tags: ~12 GB - hive_accounts: ~748 MB Sequential conversion: ~45-90 minutes Parallel conversion: ~25-50 minutes (limited by largest table) Tables are now ordered by size descending so the largest tables start first, maximizing parallelism benefit. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- hive/db/schema.py | 57 ++++++++++++++++++++++++++++++++++++++--------- 1 file changed, 46 insertions(+), 11 deletions(-) diff --git a/hive/db/schema.py b/hive/db/schema.py index 6bb6638b5..7e855d6a0 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -849,21 +849,56 @@ def set_fillfactor(db): def set_logged_table_attribute(db, logged): - """Initializes/resets LOGGED/UNLOGGED attribute for tables which are intensively updated""" + """Initializes/resets LOGGED/UNLOGGED attribute for tables which are intensively updated. + Tables are converted in parallel to minimize total conversion time. + The largest table (hive_votes at ~319GB) is the bottleneck. + """ + from concurrent.futures import ThreadPoolExecutor, as_completed + from time import perf_counter + + # Ordered by size descending - largest tables start first for better parallelism logged_config = [ - 'hive_accounts', - 'hive_permlink_data', - 'hive_post_tags', - 'hive_posts', - 'hive_post_data', - 'hive_votes', + 'hive_votes', # ~319 GB + 'hive_post_data', # ~127 GB + 'hive_posts', # ~83 GB + 'hive_permlink_data', # ~27 GB + 'hive_post_tags', # ~12 GB + 'hive_accounts', # ~748 MB ] - for table in logged_config: - log.info(f"Setting {'LOGGED' if logged else 'UNLOGGED'} attribute on table: {SCHEMA_NAME}.{table}") - sql = f"ALTER TABLE {SCHEMA_NAME}.{table} SET {'LOGGED' if logged else 'UNLOGGED'}" - db.query_no_return(sql) + mode = 'LOGGED' if logged else 'UNLOGGED' + log.info(f"Converting {len(logged_config)} tables to {mode} in parallel...") + start_time = perf_counter() + + def convert_table(table): + """Convert a single table - runs in separate thread with own connection.""" + table_start = perf_counter() + thread_db = db.clone(f'logged_convert_{table}') + try: + sql = f"ALTER TABLE {SCHEMA_NAME}.{table} SET {mode}" + thread_db.query_no_return(sql) + elapsed = perf_counter() - table_start + return (table, elapsed, None) + except Exception as e: + elapsed = perf_counter() - table_start + return (table, elapsed, e) + finally: + thread_db.close() + + with ThreadPoolExecutor(max_workers=len(logged_config)) as executor: + futures = {executor.submit(convert_table, table): table for table in logged_config} + + for future in as_completed(futures): + table, elapsed, error = future.result() + if error: + log.error(f"Failed to set {mode} on {SCHEMA_NAME}.{table} after {elapsed:.1f}s: {error}") + raise error + else: + log.info(f"Set {mode} on {SCHEMA_NAME}.{table} in {elapsed:.1f}s") + + total_elapsed = perf_counter() - start_time + log.info(f"All {len(logged_config)} tables converted to {mode} in {total_elapsed:.1f}s") def execute_sql_script(query_executor, path_to_script): -- GitLab From e4f7763431fa7150ebe0c0607d72031952e38606 Mon Sep 17 00:00:00 2001 From: Dan Notestein Date: Thu, 27 Nov 2025 22:07:00 -0500 Subject: [PATCH 36/36] Parallelize reputation_tracker and hivemind sync in CI MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Run reputation_tracker in the background while hivemind syncs, then wait for it to complete. This eliminates running reputation_tracker twice (before and after hivemind) and reduces total CI sync time. Both processes write to separate schemas (hivemind_app vs reptracker_app) so there are no database conflicts. Hivemind uses LEFT JOIN with COALESCE for reputation data, so missing data during sync is handled gracefully. 🤖 Generated with [Claude Code](https://claude.com/claude-code) Co-Authored-By: Claude --- .gitlab-ci.yaml | 11 ++++++----- 1 file changed, 6 insertions(+), 5 deletions(-) diff --git a/.gitlab-ci.yaml b/.gitlab-ci.yaml index 587bdced8..0ab8b90f8 100644 --- a/.gitlab-ci.yaml +++ b/.gitlab-ci.yaml @@ -524,9 +524,11 @@ sync: --database-admin-url="${HAF_ADMIN_POSTGRES_URL}" \ --with-apps \ --add-mocks=${ADD_MOCKS} + # Run reputation_tracker in background (parallel with hivemind sync) ${WORKING_DIR}/app/reputation_tracker/scripts/process_blocks.sh \ - --stop-at-block="${RUNNER_HIVEMIND_SYNC_IRREVERSIBLE_MAX_BLOCK}" \ - --postgres-url="${HAF_POSTGRES_URL}" + --stop-at-block="${RUNNER_HIVEMIND_SYNC_MAX_BLOCK}" \ + --postgres-url="${HAF_POSTGRES_URL}" & + REP_TRACKER_PID=$! ${WORKING_DIR}/docker_entrypoint.sh sync \ --log-mask-sensitive-data \ --pid-file hive_sync.pid \ @@ -535,11 +537,10 @@ sync: --prometheus-port 11011 \ --database-url="${HAF_POSTGRES_URL}" \ --community-start-block 4998000 + # Wait for reputation_tracker to complete before proceeding + wait $REP_TRACKER_PID pushd +2 ${WORKING_DIR}/app/ci/collect-db-stats.sh - ${WORKING_DIR}/app/reputation_tracker/scripts/process_blocks.sh \ - --stop-at-block="${RUNNER_HIVEMIND_SYNC_MAX_BLOCK}" \ - --postgres-url="${HAF_POSTGRES_URL}" after_script: - cp "$DATA_CACHE_HIVEMIND_DATADIR/$CI_JOB_NAME.log" "haf-$CI_JOB_NAME.log" || true # in after_script, so it's done even if the job fails -- GitLab