Change follow recommendation materialized view to be faster in most cases (#26545)
Co-authored-by: Renaud Chaput <renchap@gmail.com>
This commit is contained in:
parent
e7bea8f004
commit
ee702e36e5
5 changed files with 65 additions and 10 deletions
|
@ -2,7 +2,7 @@
|
|||
|
||||
# == Schema Information
|
||||
#
|
||||
# Table name: follow_recommendations
|
||||
# Table name: global_follow_recommendations
|
||||
#
|
||||
# account_id :bigint(8) primary key
|
||||
# rank :decimal(, )
|
||||
|
@ -11,6 +11,7 @@
|
|||
|
||||
class FollowRecommendation < ApplicationRecord
|
||||
self.primary_key = :account_id
|
||||
self.table_name = :global_follow_recommendations
|
||||
|
||||
belongs_to :account_summary, foreign_key: :account_id, inverse_of: false
|
||||
belongs_to :account
|
||||
|
|
|
@ -0,0 +1,8 @@
|
|||
# frozen_string_literal: true
|
||||
|
||||
class CreateGlobalFollowRecommendations < ActiveRecord::Migration[7.0]
|
||||
def change
|
||||
create_view :global_follow_recommendations, materialized: { no_data: true }
|
||||
safety_assured { add_index :global_follow_recommendations, :account_id, unique: true }
|
||||
end
|
||||
end
|
|
@ -0,0 +1,12 @@
|
|||
# frozen_string_literal: true
|
||||
|
||||
class DropFollowRecommendations < ActiveRecord::Migration[7.0]
|
||||
def up
|
||||
drop_view :follow_recommendations, materialized: true
|
||||
end
|
||||
|
||||
def down
|
||||
create_view :follow_recommendations, version: 2, materialized: { no_data: true }
|
||||
safety_assured { add_index :follow_recommendations, :account_id, unique: true }
|
||||
end
|
||||
end
|
20
db/schema.rb
20
db/schema.rb
|
@ -10,7 +10,7 @@
|
|||
#
|
||||
# It's strongly recommended that you check this file into your version control system.
|
||||
|
||||
ActiveRecord::Schema[7.0].define(version: 2023_08_14_223300) do
|
||||
ActiveRecord::Schema[7.0].define(version: 2023_08_18_142253) do
|
||||
# These are extensions that must be enabled in order to support this database
|
||||
enable_extension "plpgsql"
|
||||
|
||||
|
@ -1331,34 +1331,36 @@ ActiveRecord::Schema[7.0].define(version: 2023_08_14_223300) do
|
|||
SQL
|
||||
add_index "account_summaries", ["account_id"], name: "index_account_summaries_on_account_id", unique: true
|
||||
|
||||
create_view "follow_recommendations", materialized: true, sql_definition: <<-SQL
|
||||
create_view "global_follow_recommendations", materialized: true, sql_definition: <<-SQL
|
||||
SELECT t0.account_id,
|
||||
sum(t0.rank) AS rank,
|
||||
array_agg(t0.reason) AS reason
|
||||
FROM ( SELECT account_summaries.account_id,
|
||||
((count(follows.id))::numeric / (1.0 + (count(follows.id))::numeric)) AS rank,
|
||||
'most_followed'::text AS reason
|
||||
FROM (((follows
|
||||
FROM ((follows
|
||||
JOIN account_summaries ON ((account_summaries.account_id = follows.target_account_id)))
|
||||
JOIN users ON ((users.account_id = follows.account_id)))
|
||||
LEFT JOIN follow_recommendation_suppressions ON ((follow_recommendation_suppressions.account_id = follows.target_account_id)))
|
||||
WHERE ((users.current_sign_in_at >= (now() - 'P30D'::interval)) AND (account_summaries.sensitive = false) AND (follow_recommendation_suppressions.id IS NULL))
|
||||
WHERE ((users.current_sign_in_at >= (now() - 'P30D'::interval)) AND (account_summaries.sensitive = false) AND (NOT (EXISTS ( SELECT 1
|
||||
FROM follow_recommendation_suppressions
|
||||
WHERE (follow_recommendation_suppressions.account_id = follows.target_account_id)))))
|
||||
GROUP BY account_summaries.account_id
|
||||
HAVING (count(follows.id) >= 5)
|
||||
UNION ALL
|
||||
SELECT account_summaries.account_id,
|
||||
(sum((status_stats.reblogs_count + status_stats.favourites_count)) / (1.0 + sum((status_stats.reblogs_count + status_stats.favourites_count)))) AS rank,
|
||||
'most_interactions'::text AS reason
|
||||
FROM (((status_stats
|
||||
FROM ((status_stats
|
||||
JOIN statuses ON ((statuses.id = status_stats.status_id)))
|
||||
JOIN account_summaries ON ((account_summaries.account_id = statuses.account_id)))
|
||||
LEFT JOIN follow_recommendation_suppressions ON ((follow_recommendation_suppressions.account_id = statuses.account_id)))
|
||||
WHERE ((statuses.id >= (((date_part('epoch'::text, (now() - 'P30D'::interval)) * (1000)::double precision))::bigint << 16)) AND (account_summaries.sensitive = false) AND (follow_recommendation_suppressions.id IS NULL))
|
||||
WHERE ((statuses.id >= (((date_part('epoch'::text, (now() - 'P30D'::interval)) * (1000)::double precision))::bigint << 16)) AND (account_summaries.sensitive = false) AND (NOT (EXISTS ( SELECT 1
|
||||
FROM follow_recommendation_suppressions
|
||||
WHERE (follow_recommendation_suppressions.account_id = statuses.account_id)))))
|
||||
GROUP BY account_summaries.account_id
|
||||
HAVING (sum((status_stats.reblogs_count + status_stats.favourites_count)) >= (5)::numeric)) t0
|
||||
GROUP BY t0.account_id
|
||||
ORDER BY (sum(t0.rank)) DESC;
|
||||
SQL
|
||||
add_index "follow_recommendations", ["account_id"], name: "index_follow_recommendations_on_account_id", unique: true
|
||||
add_index "global_follow_recommendations", ["account_id"], name: "index_global_follow_recommendations_on_account_id", unique: true
|
||||
|
||||
end
|
||||
|
|
32
db/views/global_follow_recommendations_v01.sql
Normal file
32
db/views/global_follow_recommendations_v01.sql
Normal file
|
@ -0,0 +1,32 @@
|
|||
SELECT
|
||||
account_id,
|
||||
sum(rank) AS rank,
|
||||
array_agg(reason) AS reason
|
||||
FROM (
|
||||
SELECT
|
||||
account_summaries.account_id AS account_id,
|
||||
count(follows.id) / (1.0 + count(follows.id)) AS rank,
|
||||
'most_followed' AS reason
|
||||
FROM follows
|
||||
INNER JOIN account_summaries ON account_summaries.account_id = follows.target_account_id
|
||||
INNER JOIN users ON users.account_id = follows.account_id
|
||||
WHERE users.current_sign_in_at >= (now() - interval '30 days')
|
||||
AND account_summaries.sensitive = 'f'
|
||||
AND NOT EXISTS (SELECT 1 FROM follow_recommendation_suppressions WHERE follow_recommendation_suppressions.account_id = follows.target_account_id)
|
||||
GROUP BY account_summaries.account_id
|
||||
HAVING count(follows.id) >= 5
|
||||
UNION ALL
|
||||
SELECT account_summaries.account_id AS account_id,
|
||||
sum(status_stats.reblogs_count + status_stats.favourites_count) / (1.0 + sum(status_stats.reblogs_count + status_stats.favourites_count)) AS rank,
|
||||
'most_interactions' AS reason
|
||||
FROM status_stats
|
||||
INNER JOIN statuses ON statuses.id = status_stats.status_id
|
||||
INNER JOIN account_summaries ON account_summaries.account_id = statuses.account_id
|
||||
WHERE statuses.id >= ((date_part('epoch', now() - interval '30 days') * 1000)::bigint << 16)
|
||||
AND account_summaries.sensitive = 'f'
|
||||
AND NOT EXISTS (SELECT 1 FROM follow_recommendation_suppressions WHERE follow_recommendation_suppressions.account_id = statuses.account_id)
|
||||
GROUP BY account_summaries.account_id
|
||||
HAVING sum(status_stats.reblogs_count + status_stats.favourites_count) >= 5
|
||||
) t0
|
||||
GROUP BY account_id
|
||||
ORDER BY rank DESC
|
Loading…
Reference in a new issue