2018-01-17 12:49:35 +08:00
|
|
|
# frozen_string_literal: true
|
2013-09-12 02:50:26 +08:00
|
|
|
class UserStat < ActiveRecord::Base
|
|
|
|
|
|
|
|
belongs_to :user
|
2014-07-23 09:42:24 +08:00
|
|
|
after_save :trigger_badges
|
2013-09-12 02:50:26 +08:00
|
|
|
|
2020-05-15 06:42:00 +08:00
|
|
|
# TODO(2021-05-13): Remove
|
|
|
|
self.ignored_columns = ["topic_reply_count"]
|
|
|
|
|
2016-05-03 05:15:32 +08:00
|
|
|
def self.ensure_consistency!(last_seen = 1.hour.ago)
|
|
|
|
reset_bounce_scores
|
2019-12-30 19:19:59 +08:00
|
|
|
update_distinct_badge_count
|
2016-05-03 05:15:32 +08:00
|
|
|
update_view_counts(last_seen)
|
2019-04-05 09:44:36 +08:00
|
|
|
update_first_unread(last_seen)
|
2020-09-03 14:02:15 +08:00
|
|
|
update_first_unread_pm(last_seen)
|
2019-04-05 09:44:36 +08:00
|
|
|
end
|
|
|
|
|
2020-09-03 14:02:15 +08:00
|
|
|
UPDATE_UNREAD_MINUTES_AGO = 10
|
|
|
|
UPDATE_UNREAD_USERS_LIMIT = 10_000
|
|
|
|
|
|
|
|
def self.update_first_unread_pm(last_seen, limit: UPDATE_UNREAD_USERS_LIMIT)
|
|
|
|
DB.exec(<<~SQL, archetype: Archetype.private_message, now: UPDATE_UNREAD_MINUTES_AGO.minutes.ago, last_seen: last_seen, limit: limit)
|
|
|
|
UPDATE user_stats us
|
|
|
|
SET first_unread_pm_at = COALESCE(Z.min_date, :now)
|
|
|
|
FROM (
|
|
|
|
SELECT
|
|
|
|
Y.user_id,
|
|
|
|
Y.min_date
|
|
|
|
FROM (
|
|
|
|
SELECT
|
|
|
|
u1.id user_id,
|
|
|
|
X.min_date
|
|
|
|
FROM users u1
|
|
|
|
LEFT JOIN (
|
|
|
|
SELECT
|
|
|
|
tau.user_id,
|
|
|
|
MIN(t.updated_at) min_date
|
|
|
|
FROM topic_allowed_users tau
|
|
|
|
INNER JOIN topics t ON t.id = tau.topic_id
|
|
|
|
INNER JOIN users u ON u.id = tau.user_id
|
|
|
|
LEFT JOIN topic_users tu ON t.id = tu.topic_id AND tu.user_id = tau.user_id
|
|
|
|
WHERE t.deleted_at IS NULL
|
|
|
|
AND t.archetype = :archetype
|
|
|
|
AND tu.last_read_post_number < CASE
|
|
|
|
WHEN u.admin OR u.moderator
|
|
|
|
THEN t.highest_staff_post_number
|
|
|
|
ELSE t.highest_post_number
|
|
|
|
END
|
|
|
|
AND (COALESCE(tu.notification_level, 1) >= 2)
|
|
|
|
GROUP BY tau.user_id
|
|
|
|
) AS X ON X.user_id = u1.id
|
|
|
|
) AS Y
|
|
|
|
WHERE Y.user_id IN (
|
|
|
|
SELECT id
|
|
|
|
FROM users
|
|
|
|
WHERE last_seen_at IS NOT NULL
|
|
|
|
AND last_seen_at > :last_seen
|
|
|
|
ORDER BY last_seen_at DESC
|
|
|
|
LIMIT :limit
|
|
|
|
)
|
|
|
|
) AS Z
|
|
|
|
WHERE us.user_id = Z.user_id
|
|
|
|
SQL
|
|
|
|
end
|
|
|
|
|
|
|
|
def self.update_first_unread(last_seen, limit: UPDATE_UNREAD_USERS_LIMIT)
|
|
|
|
DB.exec(<<~SQL, min_date: last_seen, limit: limit, now: UPDATE_UNREAD_MINUTES_AGO.minutes.ago)
|
2019-04-05 09:44:36 +08:00
|
|
|
UPDATE user_stats us
|
2019-04-05 10:42:41 +08:00
|
|
|
SET first_unread_at = COALESCE(Y.min_date, :now)
|
2019-04-05 09:44:36 +08:00
|
|
|
FROM (
|
|
|
|
SELECT u1.id user_id,
|
|
|
|
X.min min_date
|
|
|
|
FROM users u1
|
|
|
|
LEFT JOIN
|
|
|
|
(SELECT u.id AS user_id,
|
|
|
|
min(topics.updated_at) min
|
|
|
|
FROM users u
|
|
|
|
LEFT JOIN topic_users tu ON tu.user_id = u.id
|
|
|
|
LEFT JOIN topics ON tu.topic_id = topics.id
|
|
|
|
JOIN user_stats AS us ON us.user_id = u.id
|
|
|
|
JOIN user_options AS uo ON uo.user_id = u.id
|
|
|
|
JOIN categories c ON c.id = topics.category_id
|
|
|
|
WHERE u.id IN (
|
|
|
|
SELECT id
|
|
|
|
FROM users
|
|
|
|
WHERE last_seen_at IS NOT NULL
|
|
|
|
AND last_seen_at > :min_date
|
|
|
|
ORDER BY last_seen_at DESC
|
|
|
|
LIMIT :limit
|
|
|
|
)
|
|
|
|
AND topics.archetype <> 'private_message'
|
|
|
|
AND (("topics"."deleted_at" IS NULL
|
|
|
|
AND tu.last_read_post_number < CASE
|
|
|
|
WHEN u.admin
|
|
|
|
OR u.moderator THEN topics.highest_staff_post_number
|
|
|
|
ELSE topics.highest_post_number
|
|
|
|
END
|
|
|
|
AND COALESCE(tu.notification_level, 1) >= 2)
|
|
|
|
OR (1=0))
|
|
|
|
AND (topics.visible
|
|
|
|
OR u.admin
|
|
|
|
OR u.moderator)
|
|
|
|
AND topics.deleted_at IS NULL
|
|
|
|
AND (NOT c.read_restricted
|
|
|
|
OR u.admin
|
|
|
|
OR category_id IN
|
|
|
|
(SELECT c2.id
|
|
|
|
FROM categories c2
|
|
|
|
JOIN category_groups cg ON cg.category_id = c2.id
|
|
|
|
JOIN group_users gu ON gu.user_id = u.id
|
|
|
|
AND cg.group_id = gu.group_id
|
|
|
|
WHERE c2.read_restricted ))
|
|
|
|
AND NOT EXISTS
|
|
|
|
(SELECT 1
|
|
|
|
FROM category_users cu
|
|
|
|
WHERE last_read_post_number IS NULL
|
|
|
|
AND cu.user_id = u.id
|
|
|
|
AND cu.category_id = topics.category_id
|
|
|
|
AND cu.notification_level = 0)
|
|
|
|
GROUP BY u.id,
|
|
|
|
u.username) AS X ON X.user_id = u1.id
|
|
|
|
WHERE u1.id IN
|
|
|
|
(
|
|
|
|
SELECT id
|
|
|
|
FROM users
|
|
|
|
WHERE last_seen_at IS NOT NULL
|
|
|
|
AND last_seen_at > :min_date
|
|
|
|
ORDER BY last_seen_at DESC
|
|
|
|
LIMIT :limit
|
|
|
|
)
|
|
|
|
) Y
|
|
|
|
WHERE Y.user_id = us.user_id
|
|
|
|
SQL
|
2016-05-03 05:15:32 +08:00
|
|
|
end
|
|
|
|
|
|
|
|
def self.reset_bounce_scores
|
|
|
|
UserStat.where("reset_bounce_score_after < now()")
|
|
|
|
.where("bounce_score > 0")
|
|
|
|
.update_all(bounce_score: 0)
|
|
|
|
end
|
|
|
|
|
2013-10-04 11:28:49 +08:00
|
|
|
# Updates the denormalized view counts for all users
|
2014-08-07 12:20:42 +08:00
|
|
|
def self.update_view_counts(last_seen = 1.hour.ago)
|
2013-10-04 11:28:49 +08:00
|
|
|
|
|
|
|
# NOTE: we only update the counts for users we have seen in the last hour
|
|
|
|
# this avoids a very expensive query that may run on the entire user base
|
|
|
|
# we also ensure we only touch the table if data changes
|
|
|
|
|
|
|
|
# Update denormalized topics_entered
|
2018-06-19 14:13:14 +08:00
|
|
|
DB.exec(<<~SQL, seen_at: last_seen)
|
|
|
|
UPDATE user_stats SET topics_entered = X.c
|
|
|
|
FROM
|
|
|
|
(SELECT v.user_id, COUNT(topic_id) AS c
|
|
|
|
FROM topic_views AS v
|
|
|
|
WHERE v.user_id IN (
|
|
|
|
SELECT u1.id FROM users u1 where u1.last_seen_at > :seen_at
|
|
|
|
)
|
|
|
|
GROUP BY v.user_id) AS X
|
|
|
|
WHERE
|
|
|
|
X.user_id = user_stats.user_id AND
|
|
|
|
X.c <> topics_entered
|
|
|
|
SQL
|
2013-10-04 11:28:49 +08:00
|
|
|
|
|
|
|
# Update denormalzied posts_read_count
|
2018-06-19 14:13:14 +08:00
|
|
|
DB.exec(<<~SQL, seen_at: last_seen)
|
|
|
|
UPDATE user_stats SET posts_read_count = X.c
|
|
|
|
FROM
|
|
|
|
(SELECT pt.user_id,
|
|
|
|
COUNT(*) AS c
|
|
|
|
FROM users AS u
|
|
|
|
JOIN post_timings AS pt ON pt.user_id = u.id
|
|
|
|
JOIN topics t ON t.id = pt.topic_id
|
|
|
|
WHERE u.last_seen_at > :seen_at AND
|
|
|
|
t.archetype = 'regular' AND
|
|
|
|
t.deleted_at IS NULL
|
|
|
|
GROUP BY pt.user_id) AS X
|
|
|
|
WHERE X.user_id = user_stats.user_id AND
|
|
|
|
X.c <> posts_read_count
|
|
|
|
SQL
|
2013-10-04 11:28:49 +08:00
|
|
|
end
|
|
|
|
|
2019-12-30 19:19:59 +08:00
|
|
|
def self.update_distinct_badge_count(user_id = nil)
|
|
|
|
sql = <<~SQL
|
|
|
|
UPDATE user_stats
|
|
|
|
SET distinct_badge_count = x.distinct_badge_count
|
|
|
|
FROM (
|
|
|
|
SELECT users.id user_id, COUNT(distinct user_badges.badge_id) distinct_badge_count
|
|
|
|
FROM users
|
|
|
|
LEFT JOIN user_badges ON user_badges.user_id = users.id
|
|
|
|
AND (user_badges.badge_id IN (SELECT id FROM badges WHERE enabled))
|
|
|
|
GROUP BY users.id
|
|
|
|
) x
|
|
|
|
WHERE user_stats.user_id = x.user_id AND user_stats.distinct_badge_count <> x.distinct_badge_count
|
|
|
|
SQL
|
|
|
|
|
|
|
|
sql = sql + " AND user_stats.user_id = #{user_id.to_i}" if user_id
|
|
|
|
|
|
|
|
DB.exec sql
|
|
|
|
end
|
|
|
|
|
|
|
|
def update_distinct_badge_count
|
|
|
|
self.class.update_distinct_badge_count(self.user_id)
|
|
|
|
end
|
|
|
|
|
2017-11-03 03:33:40 +08:00
|
|
|
# topic_reply_count is a count of posts in other users' topics
|
2020-08-12 22:28:34 +08:00
|
|
|
def calc_topic_reply_count!(start_time = nil)
|
2020-05-15 06:42:00 +08:00
|
|
|
sql = <<~SQL
|
2020-08-12 22:28:34 +08:00
|
|
|
SELECT COUNT(DISTINCT posts.topic_id) AS count
|
2020-05-15 06:42:00 +08:00
|
|
|
FROM posts
|
|
|
|
INNER JOIN topics ON topics.id = posts.topic_id
|
|
|
|
WHERE posts.user_id = ?
|
|
|
|
AND topics.user_id <> posts.user_id
|
|
|
|
AND posts.deleted_at IS NULL AND topics.deleted_at IS NULL
|
|
|
|
AND topics.archetype <> 'private_message'
|
|
|
|
#{start_time.nil? ? '' : 'AND posts.created_at > ?'}
|
|
|
|
SQL
|
|
|
|
if start_time.nil?
|
2020-08-12 22:28:34 +08:00
|
|
|
DB.query_single(sql, self.user_id).first
|
2020-05-15 06:42:00 +08:00
|
|
|
else
|
2020-08-12 22:28:34 +08:00
|
|
|
DB.query_single(sql, self.user_id, start_time).first
|
2020-05-15 06:42:00 +08:00
|
|
|
end
|
|
|
|
end
|
|
|
|
|
|
|
|
def any_posts
|
|
|
|
user.posts.exists?
|
2013-10-04 11:28:49 +08:00
|
|
|
end
|
|
|
|
|
|
|
|
MAX_TIME_READ_DIFF = 100
|
|
|
|
# attempt to add total read time to user based on previous time this was called
|
2018-01-17 12:49:35 +08:00
|
|
|
def self.update_time_read!(id)
|
|
|
|
if last_seen = last_seen_cached(id)
|
2013-10-04 11:28:49 +08:00
|
|
|
diff = (Time.now.to_f - last_seen.to_f).round
|
|
|
|
if diff > 0 && diff < MAX_TIME_READ_DIFF
|
2017-11-15 05:39:07 +08:00
|
|
|
update_args = ["time_read = time_read + ?", diff]
|
2018-01-17 12:49:35 +08:00
|
|
|
UserStat.where(user_id: id).update_all(update_args)
|
2017-11-15 05:39:07 +08:00
|
|
|
UserVisit.where(user_id: id, visited_at: Time.zone.now.to_date).update_all(update_args)
|
2013-10-04 11:28:49 +08:00
|
|
|
end
|
|
|
|
end
|
2018-01-17 12:49:35 +08:00
|
|
|
cache_last_seen(id, Time.now.to_f)
|
|
|
|
end
|
|
|
|
|
|
|
|
def update_time_read!
|
|
|
|
UserStat.update_time_read!(id)
|
2014-01-06 13:50:55 +08:00
|
|
|
end
|
|
|
|
|
2017-02-20 17:37:01 +08:00
|
|
|
def reset_bounce_score!
|
|
|
|
update_columns(reset_bounce_score_after: nil, bounce_score: 0)
|
|
|
|
end
|
|
|
|
|
2018-01-17 12:49:35 +08:00
|
|
|
def self.last_seen_key(id)
|
|
|
|
# frozen
|
|
|
|
-"user-last-seen:#{id}"
|
2014-07-23 09:42:24 +08:00
|
|
|
end
|
|
|
|
|
2018-01-17 12:49:35 +08:00
|
|
|
def self.last_seen_cached(id)
|
2019-12-03 17:05:53 +08:00
|
|
|
Discourse.redis.get(last_seen_key(id))
|
2014-01-06 13:50:55 +08:00
|
|
|
end
|
|
|
|
|
2018-01-17 12:49:35 +08:00
|
|
|
def self.cache_last_seen(id, val)
|
2019-12-03 17:05:53 +08:00
|
|
|
Discourse.redis.setex(last_seen_key(id), MAX_TIME_READ_DIFF, val)
|
2014-01-06 13:50:55 +08:00
|
|
|
end
|
|
|
|
|
2018-01-17 12:49:35 +08:00
|
|
|
protected
|
2013-10-04 11:28:49 +08:00
|
|
|
|
2018-01-17 12:49:35 +08:00
|
|
|
def trigger_badges
|
|
|
|
BadgeGranter.queue_badge_grant(Badge::Trigger::UserChange, user: self.user)
|
|
|
|
end
|
2013-09-12 02:50:26 +08:00
|
|
|
end
|
2013-10-04 11:28:49 +08:00
|
|
|
|
|
|
|
# == Schema Information
|
|
|
|
#
|
|
|
|
# Table name: user_stats
|
|
|
|
#
|
2016-05-30 08:45:32 +08:00
|
|
|
# user_id :integer not null, primary key
|
|
|
|
# topics_entered :integer default(0), not null
|
|
|
|
# time_read :integer default(0), not null
|
|
|
|
# days_visited :integer default(0), not null
|
|
|
|
# posts_read_count :integer default(0), not null
|
|
|
|
# likes_given :integer default(0), not null
|
|
|
|
# likes_received :integer default(0), not null
|
|
|
|
# new_since :datetime not null
|
|
|
|
# read_faq :datetime
|
|
|
|
# first_post_created_at :datetime
|
|
|
|
# post_count :integer default(0), not null
|
|
|
|
# topic_count :integer default(0), not null
|
2018-09-20 10:40:51 +08:00
|
|
|
# bounce_score :float default(0.0), not null
|
2016-05-30 08:45:32 +08:00
|
|
|
# reset_bounce_score_after :datetime
|
2018-11-07 11:11:19 +08:00
|
|
|
# flags_agreed :integer default(0), not null
|
|
|
|
# flags_disagreed :integer default(0), not null
|
|
|
|
# flags_ignored :integer default(0), not null
|
2019-04-05 17:13:12 +08:00
|
|
|
# first_unread_at :datetime not null
|
2020-01-10 00:08:55 +08:00
|
|
|
# distinct_badge_count :integer default(0), not null
|
2020-10-28 02:12:33 +08:00
|
|
|
# first_unread_pm_at :datetime not null
|
2020-10-07 22:30:38 +08:00
|
|
|
# digest_attempted_at :datetime
|
2013-10-04 11:28:49 +08:00
|
|
|
#
|