logo

pleroma

My custom branche(s) on git.pleroma.social/pleroma/pleroma git clone https://hacktivis.me/git/pleroma.git

20200508092434_update_counter_cache_table.exs (5795B)


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