Fork of Pleroma with site-specific changes and feature branches https://git.pleroma.social/pleroma/pleroma
您最多选择25个主题 主题必须以字母或数字开头,可以包含连字符 (-),并且长度不得超过35个字符

144 行
5.5KB

  1. defmodule Pleroma.Repo.Migrations.UpdateCounterCacheTable do
  2. use Ecto.Migration
  3. @function_name "update_status_visibility_counter_cache"
  4. @trigger_name "status_visibility_counter_cache_trigger"
  5. def up do
  6. execute("drop trigger if exists #{@trigger_name} on activities")
  7. execute("drop function if exists #{@function_name}()")
  8. drop_if_exists(unique_index(:counter_cache, [:name]))
  9. drop_if_exists(table(:counter_cache))
  10. create_if_not_exists table(:counter_cache) do
  11. add(:instance, :string, null: false)
  12. add(:direct, :bigint, null: false, default: 0)
  13. add(:private, :bigint, null: false, default: 0)
  14. add(:unlisted, :bigint, null: false, default: 0)
  15. add(:public, :bigint, null: false, default: 0)
  16. end
  17. create_if_not_exists(unique_index(:counter_cache, [:instance]))
  18. """
  19. CREATE OR REPLACE FUNCTION #{@function_name}()
  20. RETURNS TRIGGER AS
  21. $$
  22. DECLARE
  23. hostname character varying(255);
  24. visibility_new character varying(64);
  25. visibility_old character varying(64);
  26. actor character varying(255);
  27. BEGIN
  28. IF TG_OP = 'DELETE' THEN
  29. actor := OLD.actor;
  30. ELSE
  31. actor := NEW.actor;
  32. END IF;
  33. hostname := split_part(actor, '/', 3);
  34. IF TG_OP = 'INSERT' THEN
  35. visibility_new := activity_visibility(NEW.actor, NEW.recipients, NEW.data);
  36. IF NEW.data->>'type' = 'Create'
  37. AND visibility_new IN ('public', 'unlisted', 'private', 'direct') THEN
  38. EXECUTE format('INSERT INTO "counter_cache" ("instance", %1$I) VALUES ($1, 1)
  39. ON CONFLICT ("instance") DO
  40. UPDATE SET %1$I = "counter_cache".%1$I + 1', visibility_new)
  41. USING hostname;
  42. END IF;
  43. RETURN NEW;
  44. ELSIF TG_OP = 'UPDATE' THEN
  45. visibility_new := activity_visibility(NEW.actor, NEW.recipients, NEW.data);
  46. visibility_old := activity_visibility(OLD.actor, OLD.recipients, OLD.data);
  47. IF (NEW.data->>'type' = 'Create')
  48. AND (OLD.data->>'type' = 'Create')
  49. AND visibility_new != visibility_old
  50. AND visibility_new IN ('public', 'unlisted', 'private', 'direct') THEN
  51. EXECUTE format('UPDATE "counter_cache" SET
  52. %1$I = greatest("counter_cache".%1$I - 1, 0),
  53. %2$I = "counter_cache".%2$I + 1
  54. WHERE "instance" = $1', visibility_old, visibility_new)
  55. USING hostname;
  56. END IF;
  57. RETURN NEW;
  58. ELSIF TG_OP = 'DELETE' THEN
  59. IF OLD.data->>'type' = 'Create' THEN
  60. visibility_old := activity_visibility(OLD.actor, OLD.recipients, OLD.data);
  61. EXECUTE format('UPDATE "counter_cache" SET
  62. %1$I = greatest("counter_cache".%1$I - 1, 0)
  63. WHERE "instance" = $1', visibility_old)
  64. USING hostname;
  65. END IF;
  66. RETURN OLD;
  67. END IF;
  68. END;
  69. $$
  70. LANGUAGE 'plpgsql';
  71. """
  72. |> execute()
  73. execute("DROP TRIGGER IF EXISTS #{@trigger_name} ON activities")
  74. """
  75. CREATE TRIGGER #{@trigger_name}
  76. BEFORE
  77. INSERT
  78. OR UPDATE of recipients, data
  79. OR DELETE
  80. ON activities
  81. FOR EACH ROW
  82. EXECUTE PROCEDURE #{@function_name}();
  83. """
  84. |> execute()
  85. end
  86. def down do
  87. execute("DROP TRIGGER IF EXISTS #{@trigger_name} ON activities")
  88. execute("DROP FUNCTION IF EXISTS #{@function_name}()")
  89. drop_if_exists(unique_index(:counter_cache, [:instance]))
  90. drop_if_exists(table(:counter_cache))
  91. create_if_not_exists table(:counter_cache) do
  92. add(:name, :string, null: false)
  93. add(:count, :bigint, null: false, default: 0)
  94. end
  95. create_if_not_exists(unique_index(:counter_cache, [:name]))
  96. """
  97. CREATE OR REPLACE FUNCTION #{@function_name}()
  98. RETURNS TRIGGER AS
  99. $$
  100. DECLARE
  101. BEGIN
  102. IF TG_OP = 'INSERT' THEN
  103. IF NEW.data->>'type' = 'Create' THEN
  104. EXECUTE 'INSERT INTO counter_cache (name, count) VALUES (''status_visibility_' || activity_visibility(NEW.actor, NEW.recipients, NEW.data) || ''', 1) ON CONFLICT (name) DO UPDATE SET count = counter_cache.count + 1';
  105. END IF;
  106. RETURN NEW;
  107. ELSIF TG_OP = 'UPDATE' THEN
  108. IF (NEW.data->>'type' = 'Create') and (OLD.data->>'type' = 'Create') and activity_visibility(NEW.actor, NEW.recipients, NEW.data) != activity_visibility(OLD.actor, OLD.recipients, OLD.data) THEN
  109. EXECUTE 'INSERT INTO counter_cache (name, count) VALUES (''status_visibility_' || activity_visibility(NEW.actor, NEW.recipients, NEW.data) || ''', 1) ON CONFLICT (name) DO UPDATE SET count = counter_cache.count + 1';
  110. EXECUTE 'update counter_cache SET count = counter_cache.count - 1 where count > 0 and name = ''status_visibility_' || activity_visibility(OLD.actor, OLD.recipients, OLD.data) || ''';';
  111. END IF;
  112. RETURN NEW;
  113. ELSIF TG_OP = 'DELETE' THEN
  114. IF OLD.data->>'type' = 'Create' THEN
  115. EXECUTE 'update counter_cache SET count = counter_cache.count - 1 where count > 0 and name = ''status_visibility_' || activity_visibility(OLD.actor, OLD.recipients, OLD.data) || ''';';
  116. END IF;
  117. RETURN OLD;
  118. END IF;
  119. END;
  120. $$
  121. LANGUAGE 'plpgsql';
  122. """
  123. |> execute()
  124. """
  125. CREATE TRIGGER #{@trigger_name} BEFORE INSERT OR UPDATE of recipients, data OR DELETE ON activities
  126. FOR EACH ROW
  127. EXECUTE PROCEDURE #{@function_name}();
  128. """
  129. |> execute()
  130. end
  131. end