Skip to content

Commit 1805184

Browse files
authored
FIX: Multiple topics may have the same post as its solution (#348)
We are seeing some errors when migrating and adding indexes on `answer_post_id`. ``` #<StandardError:"An error has occurred, all later migrations canceled:\n\nPG::UniqueViolation: ERROR: could not create unique index \"index_discourse_solved_solved_topics_on_answer_post_id\"\nDETAIL: Key (answer_post_id)=(13006) is duplicated.\n"> ``` This PR modifies the earlier migration, and also adds one before the addition of indexes to remove duplicates.
1 parent a8a3554 commit 1805184

5 files changed

+169
-28
lines changed

db/migrate/20250318024953_copy_solved_topic_custom_field_to_discourse_solved_solved_topics.rb

+22-14
Original file line numberDiff line numberDiff line change
@@ -23,23 +23,31 @@ def up
2323
created_at,
2424
updated_at
2525
)
26-
SELECT DISTINCT ON (tc.topic_id)
26+
SELECT
2727
tc.topic_id,
28-
CAST(tc.value AS INTEGER),
29-
CAST(tc2.value AS INTEGER),
30-
COALESCE(ua.acting_user_id, -1),
28+
tc.answer_post_id,
29+
tc.topic_timer_id,
30+
tc.accepter_user_id,
3131
tc.created_at,
3232
tc.updated_at
33-
FROM topic_custom_fields tc
34-
LEFT JOIN topic_custom_fields tc2
35-
ON tc2.topic_id = tc.topic_id
36-
AND tc2.name = 'solved_auto_close_topic_timer_id'
37-
LEFT JOIN user_actions ua
38-
ON ua.target_topic_id = tc.topic_id
39-
AND ua.action_type = 15
40-
WHERE tc.name = 'accepted_answer_post_id'
41-
AND tc.id > :last_id
42-
AND tc.id <= :last_id + :batch_size
33+
FROM (
34+
SELECT
35+
tc.topic_id,
36+
CAST(tc.value AS INTEGER) AS answer_post_id,
37+
CAST(tc2.value AS INTEGER) AS topic_timer_id,
38+
COALESCE(ua.acting_user_id, -1) AS accepter_user_id,
39+
tc.created_at,
40+
tc.updated_at,
41+
ROW_NUMBER() OVER (PARTITION BY tc.topic_id ORDER BY tc.created_at ASC) AS rn_topic,
42+
ROW_NUMBER() OVER (PARTITION BY CAST(tc.value AS INTEGER) ORDER BY tc.created_at ASC) AS rn_answer
43+
FROM topic_custom_fields tc
44+
LEFT JOIN topic_custom_fields tc2 ON tc2.topic_id = tc.topic_id AND tc2.name = 'solved_auto_close_topic_timer_id'
45+
LEFT JOIN user_actions ua ON ua.target_topic_id = tc.topic_id AND ua.action_type = 15
46+
WHERE tc.name = 'accepted_answer_post_id'
47+
AND tc.id > :last_id
48+
AND tc.id <= :last_id + :batch_size
49+
) tc
50+
WHERE tc.rn_topic = 1 AND tc.rn_answer = 1
4351
ON CONFLICT DO NOTHING
4452
SQL
4553

Original file line numberDiff line numberDiff line change
@@ -0,0 +1,31 @@
1+
# frozen_string_literal: true
2+
3+
class RemoveDuplicatesFromDiscourseSolvedSolvedTopics < ActiveRecord::Migration[7.2]
4+
def up
5+
# remove duplicates on answer_post_id based on earliest created_at
6+
DB.exec(<<~SQL)
7+
DELETE FROM discourse_solved_solved_topics
8+
WHERE id NOT IN (
9+
SELECT id FROM (
10+
SELECT id, ROW_NUMBER() OVER (PARTITION BY answer_post_id ORDER BY created_at) as row_num
11+
FROM discourse_solved_solved_topics
12+
) t WHERE row_num = 1
13+
)
14+
SQL
15+
16+
# remove duplicates on topic_id based on earliest created_at
17+
DB.exec(<<~SQL)
18+
DELETE FROM discourse_solved_solved_topics
19+
WHERE id NOT IN (
20+
SELECT id FROM (
21+
SELECT id, ROW_NUMBER() OVER (PARTITION BY topic_id ORDER BY created_at) as row_num
22+
FROM discourse_solved_solved_topics
23+
) t WHERE row_num = 1
24+
)
25+
SQL
26+
end
27+
28+
def down
29+
raise ActiveRecord::IrreversibleMigration
30+
end
31+
end

db/migrate/20250325074111_copy_remaining_solved_topic_custom_field_to_discourse_solved_solved_topics.rb

+22-14
Original file line numberDiff line numberDiff line change
@@ -25,23 +25,31 @@ def up
2525
created_at,
2626
updated_at
2727
)
28-
SELECT DISTINCT ON (tc.topic_id)
28+
SELECT
2929
tc.topic_id,
30-
CAST(tc.value AS INTEGER),
31-
CAST(tc2.value AS INTEGER),
32-
COALESCE(ua.acting_user_id, -1),
30+
tc.answer_post_id,
31+
tc.topic_timer_id,
32+
tc.accepter_user_id,
3333
tc.created_at,
3434
tc.updated_at
35-
FROM topic_custom_fields tc
36-
LEFT JOIN topic_custom_fields tc2
37-
ON tc2.topic_id = tc.topic_id
38-
AND tc2.name = 'solved_auto_close_topic_timer_id'
39-
LEFT JOIN user_actions ua
40-
ON ua.target_topic_id = tc.topic_id
41-
AND ua.action_type = 15
42-
WHERE tc.name = 'accepted_answer_post_id'
43-
AND tc.id > :last_id
44-
AND tc.id <= :last_id + :batch_size
35+
FROM (
36+
SELECT
37+
tc.topic_id,
38+
CAST(tc.value AS INTEGER) AS answer_post_id,
39+
CAST(tc2.value AS INTEGER) AS topic_timer_id,
40+
COALESCE(ua.acting_user_id, -1) AS accepter_user_id,
41+
tc.created_at,
42+
tc.updated_at,
43+
ROW_NUMBER() OVER (PARTITION BY tc.topic_id ORDER BY tc.created_at ASC) AS rn_topic,
44+
ROW_NUMBER() OVER (PARTITION BY CAST(tc.value AS INTEGER) ORDER BY tc.created_at ASC) AS rn_answer
45+
FROM topic_custom_fields tc
46+
LEFT JOIN topic_custom_fields tc2 ON tc2.topic_id = tc.topic_id AND tc2.name = 'solved_auto_close_topic_timer_id'
47+
LEFT JOIN user_actions ua ON ua.target_topic_id = tc.topic_id AND ua.action_type = 15
48+
WHERE tc.name = 'accepted_answer_post_id'
49+
AND tc.id > :last_id
50+
AND tc.id <= :last_id + :batch_size
51+
) tc
52+
WHERE tc.rn_topic = 1 AND tc.rn_answer = 1
4553
ON CONFLICT DO NOTHING
4654
SQL
4755

Original file line numberDiff line numberDiff line change
@@ -0,0 +1,42 @@
1+
# frozen_string_literal: true
2+
3+
require_relative "../../db/migrate/20250318024953_copy_solved_topic_custom_field_to_discourse_solved_solved_topics"
4+
5+
RSpec.describe CopySolvedTopicCustomFieldToDiscourseSolvedSolvedTopics, type: :migration do
6+
let(:migration) { described_class.new }
7+
8+
describe "handling duplicates" do
9+
it "ensures only unique topic_id and answer_post_id are inserted" do
10+
topic = Fabricate(:topic)
11+
topic1 = Fabricate(:topic)
12+
post1 = Fabricate(:post, topic: topic)
13+
TopicCustomField.create!(
14+
topic_id: topic.id,
15+
name: "accepted_answer_post_id",
16+
value: post1.id.to_s,
17+
)
18+
# explicit duplicate
19+
TopicCustomField.create!(
20+
topic_id: topic1.id,
21+
name: "accepted_answer_post_id",
22+
value: post1.id.to_s,
23+
)
24+
25+
second_topic = Fabricate(:topic)
26+
post2 = Fabricate(:post, topic: second_topic)
27+
TopicCustomField.create!(
28+
topic_id: second_topic.id,
29+
name: "accepted_answer_post_id",
30+
value: post2.id.to_s,
31+
)
32+
33+
migration.up
34+
expected_count = DiscourseSolved::SolvedTopic.count
35+
36+
expect(expected_count).to eq(2)
37+
38+
expect(DiscourseSolved::SolvedTopic.where(topic_id: topic.id).count).to eq(1)
39+
expect(DiscourseSolved::SolvedTopic.where(answer_post_id: post1.id).count).to eq(1)
40+
end
41+
end
42+
end
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,52 @@
1+
# frozen_string_literal: true
2+
3+
require_relative "../../db/migrate/20250318024954_remove_duplicates_from_discourse_solved_solved_topics"
4+
5+
RSpec.describe RemoveDuplicatesFromDiscourseSolvedSolvedTopics, type: :migration do
6+
let(:migration) { described_class.new }
7+
8+
before do
9+
# temp drop unique constraints to allow testing duplicate entries
10+
ActiveRecord::Base.connection.execute(
11+
"DROP INDEX IF EXISTS index_discourse_solved_solved_topics_on_topic_id;",
12+
)
13+
ActiveRecord::Base.connection.execute(
14+
"DROP INDEX IF EXISTS index_discourse_solved_solved_topics_on_answer_post_id;",
15+
)
16+
end
17+
18+
after do
19+
DiscourseSolved::SolvedTopic.delete_all
20+
21+
# reapply unique indexes
22+
ActiveRecord::Base.connection.execute(
23+
"CREATE UNIQUE INDEX index_discourse_solved_solved_topics_on_topic_id ON discourse_solved_solved_topics (topic_id);",
24+
)
25+
ActiveRecord::Base.connection.execute(
26+
"CREATE UNIQUE INDEX index_discourse_solved_solved_topics_on_answer_post_id ON discourse_solved_solved_topics (answer_post_id);",
27+
)
28+
end
29+
30+
describe "removal of duplicate answer_post_ids" do
31+
it "keeps only the earliest record for each answer_post_id" do
32+
topic1 = Fabricate(:topic)
33+
post1 = Fabricate(:post, topic: topic1)
34+
topic2 = Fabricate(:topic)
35+
post2 = Fabricate(:post, topic: topic2)
36+
37+
earlier = Fabricate(:solved_topic, topic: topic1, answer_post: post1, created_at: 2.days.ago)
38+
Fabricate(:solved_topic, topic: topic1, answer_post: post1, created_at: 1.day.ago)
39+
Fabricate(:solved_topic, topic: topic1, answer_post: post1, created_at: Date.today)
40+
another = Fabricate(:solved_topic, topic: topic2, answer_post: post2, created_at: Date.today)
41+
42+
expect(DiscourseSolved::SolvedTopic.count).to eq(4)
43+
migration.up
44+
45+
expect(DiscourseSolved::SolvedTopic.count).to eq(2)
46+
expect(DiscourseSolved::SolvedTopic.pluck(:id, :answer_post_id)).to contain_exactly(
47+
[earlier.id, post1.id],
48+
[another.id, post2.id],
49+
)
50+
end
51+
end
52+
end

0 commit comments

Comments
 (0)