diff --git a/hive/db/db_state.py b/hive/db/db_state.py
index a823d01cc4d825ba6c00230a7c3438bcb704ceb1..2f23629e625e52ba9538e45b310c13eda5b5c947 100644
--- a/hive/db/db_state.py
+++ b/hive/db/db_state.py
@@ -92,6 +92,8 @@ class DbState:
     @classmethod
     def _disableable_indexes(cls):
         to_locate = [
+            'hive_blocks_created_at_idx',
+
             'hive_follows_ix5a', # (following, state, created_at, follower)
             'hive_follows_ix5b', # (follower, state, created_at, following)
             'hive_follows_block_num_idx',
diff --git a/hive/db/schema.py b/hive/db/schema.py
index ab60d456ace0094cadb33a843c8e3c45ecba76bf..40460ad3d93f0eeebc30aa07c93e236723a304ee 100644
--- a/hive/db/schema.py
+++ b/hive/db/schema.py
@@ -31,6 +31,7 @@ def build_metadata():
 
         sa.UniqueConstraint('hash', name='hive_blocks_ux1'),
         sa.ForeignKeyConstraint(['prev'], ['hive_blocks.hash'], name='hive_blocks_fk1'),
+        sa.Index('hive_blocks_created_at_idx', 'created_at')
     )
 
     sa.Table(
diff --git a/hive/db/sql_scripts/notifications_api.sql b/hive/db/sql_scripts/notifications_api.sql
index bea933da082f01e00ca4e4986200cfa02504b8a9..46090298d02d0abaa0248fe3fcc156641dd35908 100644
--- a/hive/db/sql_scripts/notifications_api.sql
+++ b/hive/db/sql_scripts/notifications_api.sql
@@ -24,6 +24,7 @@ $BODY$
 DECLARE
     __account_id INT := 0;
     __last_read_at TIMESTAMP;
+    __last_read_at_block hive_blocks.num%TYPE;
     __limit_block hive_blocks.num%TYPE = block_before_head( '90 days' );
 BEGIN
   __account_id = find_account_id( _account, True );
@@ -32,11 +33,19 @@ BEGIN
   FROM hive_accounts ha
   WHERE ha.id = __account_id;
 
+  --- Warning given account can have no last_read_at set, so lets fallback to the block limit to avoid comparison to NULL.
+  SELECT COALESCE((SELECT hb.num 
+                   FROM hive_blocks hb
+                   WHERE hb.created_at <= __last_read_at
+                   ORDER by hb.created_at desc
+                   LIMIT 1), __limit_block)
+    INTO __last_read_at_block;
+
   RETURN QUERY SELECT
     __last_read_at as lastread_at,
     count(1) as unread
   FROM hive_raw_notifications_view hnv
-  WHERE hnv.dst = __account_id  AND hnv.block_num > __limit_block AND hnv.created_at > __last_read_at AND hnv.score >= _minimum_score
+  WHERE hnv.dst = __account_id  AND hnv.block_num > __limit_block AND hnv.block_num > __last_read_at_block AND hnv.score >= _minimum_score
   ;
 END
 $BODY$
diff --git a/hive/db/sql_scripts/upgrade/upgrade_runtime_migration.sql b/hive/db/sql_scripts/upgrade/upgrade_runtime_migration.sql
index 6478198460c6fae90056a54ef80f9cfe6b2d6409..c7fb77d69973d5bee31f6be13046baf88907b975 100644
--- a/hive/db/sql_scripts/upgrade/upgrade_runtime_migration.sql
+++ b/hive/db/sql_scripts/upgrade/upgrade_runtime_migration.sql
@@ -147,6 +147,7 @@ values
 ,(now(), '033619277eccea70118a5b8dc0c73b913da0025f') -- https://gitlab.syncad.com/hive/hivemind/-/merge_requests/326 https://gitlab.syncad.com/hive/hivemind/-/merge_requests/322 posts rshares recalc
 ,(now(), '1847c75702384c7e34c624fc91f24d2ef20df91d') -- latest version of develop containing included changes.
 ,(now(), '1f23e1326f3010bc84353aba82d4aa7ff2f999e4') -- hive_posts_author_id_created_at_idx index def. to speedup hive_accounts_info_view.
+,(now(), '2a274e586454968a4f298a855a7e60394ed90bde') -- get_number_of_unread_notifications speedup https://gitlab.syncad.com/hive/hivemind/-/merge_requests/348/diffs
 ) ds (patch_date, patch_revision)
 where not exists (select null from hive_db_patch_level hpl where hpl.patched_to_revision = ds.patch_revision);
 
diff --git a/hive/db/sql_scripts/upgrade/upgrade_table_schema.sql b/hive/db/sql_scripts/upgrade/upgrade_table_schema.sql
index 149829cc24fb357c7b93af77fe16d48d0bfa1157..23e37c22ab80ac5afa89400f70b10764169af805 100644
--- a/hive/db/sql_scripts/upgrade/upgrade_table_schema.sql
+++ b/hive/db/sql_scripts/upgrade/upgrade_table_schema.sql
@@ -293,3 +293,5 @@ DROP INDEX IF EXISTS public.hive_posts_created_at_author_id_idx;
 
 CREATE INDEX IF NOT EXISTS hive_posts_author_id_created_at_idx ON public.hive_posts ( author_id DESC, created_at DESC);
 
+CREATE INDEX IF NOT EXISTS hive_blocks_created_at_idx ON hive_blocks (created_at);
+