From 835eeedf1a43ad4c26aad467b5a37941ac0ff195 Mon Sep 17 00:00:00 2001
From: ABW <andrzejl@syncad.com>
Date: Tue, 3 Nov 2020 20:14:07 +0100
Subject: [PATCH] [ABW]: reimplemented get_trending_tags (as SQL function, also
 changed paging so now it works)

---
 hive/db/schema.py                      |  1 +
 hive/db/sql_scripts/condenser_tags.sql | 50 ++++++++++++++++++++++++++
 hive/server/condenser_api/tags.py      | 37 ++-----------------
 tests/tests_api                        |  2 +-
 4 files changed, 55 insertions(+), 35 deletions(-)
 create mode 100644 hive/db/sql_scripts/condenser_tags.sql

diff --git a/hive/db/schema.py b/hive/db/schema.py
index 9410a8e30..4fffe4c35 100644
--- a/hive/db/schema.py
+++ b/hive/db/schema.py
@@ -1605,6 +1605,7 @@ def setup(db):
       "condenser_get_blog.sql",
       "condenser_get_content.sql",
       "condenser_get_discussions_by_blog.sql",
+      "condenser_tags.sql",
       "hot_and_trends.sql",
       "update_hive_posts_children_count.sql"
     ]
diff --git a/hive/db/sql_scripts/condenser_tags.sql b/hive/db/sql_scripts/condenser_tags.sql
new file mode 100644
index 000000000..0812832b4
--- /dev/null
+++ b/hive/db/sql_scripts/condenser_tags.sql
@@ -0,0 +1,50 @@
+DROP FUNCTION IF EXISTS condenser_get_top_trending_tags_summary;
+CREATE FUNCTION condenser_get_top_trending_tags_summary( in _limit INT )
+RETURNS SETOF VARCHAR
+AS
+$function$
+BEGIN
+  RETURN QUERY SELECT
+      hcd.category
+  FROM
+      hive_category_data hcd
+      JOIN hive_posts hp ON hp.category_id = hcd.id
+  WHERE hp.counter_deleted = 0 AND NOT hp.is_paidout
+  GROUP BY hcd.category
+  ORDER BY SUM(hp.payout + hp.pending_payout) DESC
+  LIMIT _limit;
+END
+$function$
+language plpgsql STABLE;
+
+DROP FUNCTION IF EXISTS condenser_get_trending_tags;
+CREATE FUNCTION condenser_get_trending_tags( in _category VARCHAR, in _limit INT )
+RETURNS TABLE( category VARCHAR, total_posts BIGINT, top_posts BIGINT, total_payouts hive_posts.payout%TYPE )
+AS
+$function$
+DECLARE
+  __category_id INT;
+  __payout_limit hive_posts.payout%TYPE;
+BEGIN
+  __category_id = find_category_id( _category, _category <> '' );
+  IF __category_id <> 0 THEN
+      SELECT SUM(hp.payout + hp.pending_payout) INTO __payout_limit
+      FROM hive_posts hp
+      WHERE hp.category_id = __category_id AND hp.counter_deleted = 0 AND NOT hp.is_paidout;
+  END IF;
+  RETURN QUERY SELECT
+      hcd.category,
+      COUNT(*) AS total_posts,
+      SUM(CASE WHEN hp.depth = 0 THEN 1 ELSE 0 END) AS top_posts,
+      SUM(hp.payout + hp.pending_payout) AS total_payouts
+  FROM
+      hive_posts hp
+      JOIN hive_category_data hcd ON hcd.id = hp.category_id
+  WHERE NOT hp.is_paidout AND counter_deleted = 0
+  GROUP BY hcd.category
+  HAVING __category_id = 0 OR SUM(hp.payout + hp.pending_payout) < __payout_limit OR ( SUM(hp.payout + hp.pending_payout) = __payout_limit AND hcd.category > _category )
+  ORDER BY SUM(hp.payout + hp.pending_payout) DESC, hcd.category ASC
+  LIMIT _limit;
+END
+$function$
+language plpgsql STABLE;
diff --git a/hive/server/condenser_api/tags.py b/hive/server/condenser_api/tags.py
index 0e6535888..d6f05ca2b 100644
--- a/hive/server/condenser_api/tags.py
+++ b/hive/server/condenser_api/tags.py
@@ -7,16 +7,7 @@ from hive.server.common.helpers import (return_error_info, valid_tag, valid_limi
 @cached(ttl=7200, timeout=1200)
 async def get_top_trending_tags_summary(context):
     """Get top 50 trending tags among pending posts."""
-    # Same results, more overhead:
-    #return [tag['name'] for tag in await get_trending_tags('', 50)]
-    sql = """
-        SELECT (SELECT category FROM hive_category_data WHERE id = category_id) as category
-          FROM hive_posts
-         WHERE counter_deleted = 0 AND NOT is_paidout
-      GROUP BY category
-      ORDER BY SUM(payout + pending_payout) DESC
-         LIMIT 50
-    """
+    sql = "SELECT condenser_get_top_trending_tags_summary(50)"
     return await context['db'].query_col(sql)
 
 @return_error_info
@@ -27,32 +18,10 @@ async def get_trending_tags(context, start_tag: str = '', limit: int = 250):
     limit = valid_limit(limit, 250, 250)
     start_tag = valid_tag(start_tag or '', allow_empty=True)
 
-    if start_tag:
-        seek = """
-          HAVING SUM(payout + pending_payout) <= (
-            SELECT SUM(payout + pending_payout)
-              FROM hive_posts hp
-              JOIN hive_category_data hcd ON hcd.id = hp.category_id
-             WHERE NOT is_paidout AND counter_deleted = 0 AND hcd.category = :start_tag)
-        """
-    else:
-        seek = ''
-
-    sql = """
-      SELECT hcd.category,
-             COUNT(*) AS total_posts,
-             SUM(CASE WHEN hp.depth = 0 THEN 1 ELSE 0 END) AS top_posts,
-             SUM(hp.payout + hp.pending_payout) AS total_payouts
-        FROM hive_posts hp
-        JOIN hive_category_data hcd ON hcd.id = hp.category_id
-       WHERE NOT hp.is_paidout AND counter_deleted = 0
-    GROUP BY hcd.category %s
-    ORDER BY SUM(hp.payout + hp.pending_payout) DESC, hcd.category ASC
-       LIMIT :limit
-    """ % seek
+    sql = "SELECT * FROM condenser_get_trending_tags( (:tag)::VARCHAR, :limit )"
 
     out = []
-    for row in await context['db'].query_all(sql, limit=limit, start_tag=start_tag):
+    for row in await context['db'].query_all(sql, limit=limit, tag=start_tag):
         out.append({
             'name': row['category'],
             'comments': row['total_posts'] - row['top_posts'],
diff --git a/tests/tests_api b/tests/tests_api
index ef358b5ae..fbc0c9724 160000
--- a/tests/tests_api
+++ b/tests/tests_api
@@ -1 +1 @@
-Subproject commit ef358b5ae508326e56e69de1c0aafda2bd4cddab
+Subproject commit fbc0c97245465eb46377a642b57ae1f9fce770ae
-- 
GitLab