diff --git a/hive/db/db_state.py b/hive/db/db_state.py index 6fde19f50e327908ae42d3488710e91302aeacbd..aa721e3140661b913f854cd1e95016bbf89a2b3e 100644 --- a/hive/db/db_state.py +++ b/hive/db/db_state.py @@ -174,6 +174,12 @@ class DbState: index.create(engine) + # Update count of all child posts (what was hold during initial sync) + sql = """ + select update_hive_posts_children_count() + """ + row = DbState.db().query_row(sql) + # TODO: #111 #for key in cls._all_foreign_keys(): # log.info("Create fk %s", key.name) diff --git a/hive/db/schema.py b/hive/db/schema.py index 0611c4c130877f129472b914ca13a0af4e359fb5..cad12ca99e0594ff342dd6d4434f36408bb5012c 100644 --- a/hive/db/schema.py +++ b/hive/db/schema.py @@ -650,6 +650,44 @@ def setup(db): """ db.query_no_return(sql) + sql = """ + DROP FUNCTION if exists update_hive_posts_children_count() + ; + CREATE OR REPLACE FUNCTION update_hive_posts_children_count() + RETURNS VOID + LANGUAGE plpgsql + AS + $function$ + BEGIN + + update hive_posts uhp + set children = data_source.childrencount + from + ( + WITH RECURSIVE ChildrenCTE AS ( + SELECT ID as RootId, ID + FROM hive_posts hp + where hp.parent_id != 0 + UNION ALL + SELECT cte.RootID, d.ID + FROM ChildrenCTE cte + INNER JOIN hive_posts d ON d.parent_id = cte.ID + ) + SELECT d.ID, d.parent_id, cnt.ChildrenCount + FROM hive_posts d + INNER JOIN ( + SELECT RootID as ID, COUNT(*) - 1 as ChildrenCount + FROM ChildrenCTE + GROUP BY RootID + ) cnt ON cnt.ID = d.ID + ) as data_source + where uhp.id = data_source.id + ; + END + $function$ + """ + db.query_no_return(sql) + def reset_autovac(db): """Initializes/resets per-table autovacuum/autoanalyze params.