@@ -113,18 +113,6 @@ LEFT JOIN playlists p ON
113
113
n.data ? 'playlist_id' AND
114
114
p.playlist_id = (n.data->>'playlist_id')::integer AND
115
115
p.is_current = true
116
- -- Join with users table to filter out deactivated users
117
- LEFT JOIN users u ON
118
- (
119
- (n.data ? 'user_id' AND u.user_id = (n.data->>'user_id')::integer)
120
- OR
121
- (n.data ? 'entity_user_id' AND u.user_id = (n.data->>'entity_user_id')::integer)
122
- OR
123
- (n.data ? 'follower_user_id' AND u.user_id = (n.data->>'follower_user_id')::integer)
124
- )
125
- AND u.is_current = true
126
- -- Join with aggregate_user table to filter out users with low score
127
- LEFT JOIN aggregate_user a ON u.user_id = a.user_id
128
116
WHERE
129
117
((ARRAY[@user_id] && n.user_ids) OR (n.type = 'announcement' AND n.timestamp > (SELECT created_at FROM user_created_at)))
130
118
AND (n.type = ANY(@types) OR @types IS NULL)
@@ -134,18 +122,66 @@ WHERE
134
122
AND (n.type != 'create' OR NOT (n.data ? 'track_id') OR t.is_delete = false)
135
123
-- Filter out notifications for deleted playlists (only for create notifications that have playlist_id)
136
124
AND (n.type != 'create' OR NOT (n.data ? 'playlist_id') OR p.is_delete = false)
137
- -- Filter out notifications from deleted users
125
+ -- Filter out notifications from deleted/low score users
138
126
AND (
139
- (
140
- (n.data ? 'user_id' OR n.data ? 'entity_user_id')
141
- AND u.is_deactivated = false
142
- AND a.score >= 0
127
+ -- If notification has no user data fields, allow it through
128
+ NOT (
129
+ n.data ? 'user_id'
130
+ OR n.data ? 'follower_user_id'
131
+ OR n.data ? 'comment_user_id'
132
+ OR n.data ? 'entity_user_id'
143
133
)
144
134
OR (
145
- NOT (
135
+ -- If notification has user data fields, ensure ALL referenced users are valid and active with good score
136
+ (
146
137
n.data ? 'user_id'
147
- OR n.data ? 'entity_user_id'
148
138
OR n.data ? 'follower_user_id'
139
+ OR n.data ? 'comment_user_id'
140
+ OR n.data ? 'entity_user_id'
141
+ )
142
+ AND (
143
+ -- Check user_id if present
144
+ NOT (n.data ? 'user_id') OR EXISTS (
145
+ SELECT 1 FROM users u2
146
+ JOIN aggregate_user a2 ON u2.user_id = a2.user_id
147
+ WHERE u2.user_id = (n.data->>'user_id')::integer
148
+ AND u2.is_current = true
149
+ AND u2.is_deactivated = false
150
+ AND a2.score >= 0
151
+ )
152
+ )
153
+ AND (
154
+ -- Check follower_user_id if present
155
+ NOT (n.data ? 'follower_user_id') OR EXISTS (
156
+ SELECT 1 FROM users u2
157
+ JOIN aggregate_user a2 ON u2.user_id = a2.user_id
158
+ WHERE u2.user_id = (n.data->>'follower_user_id')::integer
159
+ AND u2.is_current = true
160
+ AND u2.is_deactivated = false
161
+ AND a2.score >= 0
162
+ )
163
+ )
164
+ AND (
165
+ -- Check comment_user_id if present
166
+ NOT (n.data ? 'comment_user_id') OR EXISTS (
167
+ SELECT 1 FROM users u2
168
+ JOIN aggregate_user a2 ON u2.user_id = a2.user_id
169
+ WHERE u2.user_id = (n.data->>'comment_user_id')::integer
170
+ AND u2.is_current = true
171
+ AND u2.is_deactivated = false
172
+ AND a2.score >= 0
173
+ )
174
+ )
175
+ AND (
176
+ -- Check entity_user_id if present
177
+ NOT (n.data ? 'entity_user_id') OR EXISTS (
178
+ SELECT 1 FROM users u2
179
+ JOIN aggregate_user a2 ON u2.user_id = a2.user_id
180
+ WHERE u2.user_id = (n.data->>'entity_user_id')::integer
181
+ AND u2.is_current = true
182
+ AND u2.is_deactivated = false
183
+ AND a2.score >= 0
184
+ )
149
185
)
150
186
)
151
187
)
0 commit comments