From beae876620aa679fd8901cef7c2e38647e510a29 Mon Sep 17 00:00:00 2001
From: Bartek Wrona <wrona@syncad.com>
Date: Wed, 14 Oct 2020 17:14:51 +0200
Subject: [PATCH] Fixed bug in mentions update ignoring posts having creation
 time earlier than block they have processed by blockchain

---
 .../update_hive_posts_mentions.sql            | 21 +++++++------------
 1 file changed, 7 insertions(+), 14 deletions(-)

diff --git a/hive/db/sql_scripts/update_hive_posts_mentions.sql b/hive/db/sql_scripts/update_hive_posts_mentions.sql
index 6b15f6181..c88998e8d 100644
--- a/hive/db/sql_scripts/update_hive_posts_mentions.sql
+++ b/hive/db/sql_scripts/update_hive_posts_mentions.sql
@@ -6,15 +6,11 @@ LANGUAGE 'plpgsql'
 AS
 $function$
 DECLARE
-  FIRST_BLOCK_TIME TIMESTAMP;
-  LAST_BLOCK_TIME TIMESTAMP;
+  __block_limit INT := 1200*24*90; --- 1200 blocks is equal to 1hr, so 90 days
 BEGIN
 
-  FIRST_BLOCK_TIME = ( SELECT created_at FROM hive_blocks WHERE num = _first_block );
-  LAST_BLOCK_TIME = ( SELECT created_at FROM hive_blocks WHERE num = _last_block );
-
-  IF (LAST_BLOCK_TIME - '90 days'::interval) > FIRST_BLOCK_TIME THEN
-    FIRST_BLOCK_TIME = LAST_BLOCK_TIME - '90 days'::interval;
+  IF (_last_block - __block_limit) > _first_block THEN
+    _first_block = _last_block - __block_limit;
   END IF;
 
   INSERT INTO hive_mentions( post_id, account_id, block_num )
@@ -23,17 +19,14 @@ BEGIN
       hive_accounts ha
     INNER JOIN
     (
-      SELECT T.id_post, LOWER( ( SELECT trim( T.mention::text, '{""}') ) ) mention, T.author_id, T.block_num
+      SELECT T.id_post, LOWER( ( SELECT trim( T.mention::text, '{""}') ) ) AS mention, T.author_id, T.block_num
       FROM
       (
         SELECT
-          hp.id, REGEXP_MATCHES( hpd.body, '(?:^|[^a-zA-Z0-9_!#$%&*@\\/])(?:@)([a-zA-Z0-9\\.-]{1,16}[a-zA-Z0-9])(?![a-z])', 'g') mention, hp.author_id, hp.block_num
+          hp.id, REGEXP_MATCHES( hpd.body, '(?:^|[^a-zA-Z0-9_!#$%&*@\\/])(?:@)([a-zA-Z0-9\\.-]{1,16}[a-zA-Z0-9])(?![a-z])', 'g') AS mention, hp.author_id, hp.block_num
         FROM hive_posts hp
-          INNER JOIN hive_post_data hpd ON hp.id = hpd.id
-        WHERE
-        (
-          hp.created_at >= FIRST_BLOCK_TIME
-        )
+        INNER JOIN hive_post_data hpd ON hp.id = hpd.id
+        WHERE hp.block_num >= _first_block
       )T( id_post, mention, author_id, block_num )
     )T( id_post, mention, author_id, block_num ) ON ha.name = T.mention
     WHERE ha.id != T.author_id
-- 
GitLab