functions.py 3.1 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697
  1. GENERATE_ISSUE_TSVECTOR = """
  2. CREATE OR REPLACE FUNCTION generate_issue_tsvector(jsonb) RETURNS tsvector AS $$
  3. BEGIN
  4. RETURN strip(jsonb_to_tsvector($1, '["string"]'));
  5. EXCEPTION WHEN program_limit_exceeded THEN
  6. RETURN null;
  7. END;
  8. $$ LANGUAGE plpgsql;;
  9. """
  10. # https://stackoverflow.com/a/42998229/443457
  11. JSONB_RECURSIVE_MERGE = """
  12. create or replace function remove_dupes(p_array jsonb)
  13. returns jsonb
  14. as
  15. $$
  16. select jsonb_agg(distinct e)
  17. from jsonb_array_elements(p_array) as t(e);
  18. $$
  19. language sql;
  20. create or replace function jsonb_merge_deep(jsonb, jsonb)
  21. returns jsonb
  22. language sql
  23. immutable
  24. as $func$
  25. select case jsonb_typeof($1)
  26. when 'object' then case jsonb_typeof($2)
  27. when 'object' then (
  28. select jsonb_object_agg(k, case
  29. when e2.v is null then e1.v
  30. when e1.v is null then e2.v
  31. else jsonb_merge_deep(e1.v, e2.v)
  32. end)
  33. from jsonb_each($1) e1(k, v)
  34. full join jsonb_each($2) e2(k, v) using (k)
  35. )
  36. else $2
  37. end
  38. when 'array' then remove_dupes($1 || $2)
  39. else $2
  40. end
  41. $func$;
  42. """
  43. UPDATE_ISSUE_INDEX = """
  44. CREATE OR REPLACE FUNCTION concat_tsvector(tsvector, tsvector) RETURNS tsvector AS $$
  45. BEGIN
  46. RETURN $1 || $2;
  47. EXCEPTION WHEN program_limit_exceeded THEN
  48. RETURN $1;
  49. END;
  50. $$ LANGUAGE plpgsql;;
  51. DROP PROCEDURE IF EXISTS update_issue_index;
  52. CREATE OR REPLACE PROCEDURE update_issue_index(update_issue_id integer)
  53. LANGUAGE SQL
  54. AS $$
  55. WITH event_agg as (
  56. SELECT COUNT(events_event.event_id) as new_count,
  57. MAX(events_event.created) as new_last_seen,
  58. MAX(events_event.level) as new_level,
  59. (
  60. SELECT jsonb_object_agg(y.key, y.values) as new_tags FROM (
  61. SELECT (a).key, array_agg(distinct(a).value) as values
  62. FROM (
  63. SELECT each(events_event.tags) as a
  64. FROM events_event
  65. LEFT JOIN issues_issue ON issues_issue.id = events_event.issue_id
  66. WHERE events_event.issue_id=update_issue_id
  67. AND events_event.created > issues_issue.last_seen
  68. ) t GROUP by key
  69. ) y
  70. )
  71. FROM events_event
  72. LEFT JOIN issues_issue ON issues_issue.id = events_event.issue_id
  73. WHERE events_event.issue_id=update_issue_id
  74. AND events_event.created > issues_issue.last_seen
  75. ), event_vector as (
  76. SELECT strip(COALESCE(generate_issue_tsvector(data), ''::tsvector)) as vector
  77. FROM events_event
  78. LEFT JOIN issues_issue on issues_issue.id = events_event.issue_id
  79. WHERE events_event.issue_id=update_issue_id
  80. AND events_event.created > issues_issue.last_seen
  81. limit 1
  82. )
  83. UPDATE issues_issue
  84. SET
  85. count = event_agg.new_count + issues_issue.count,
  86. last_seen = GREATEST(event_agg.new_last_seen, issues_issue.last_seen),
  87. level = GREATEST(event_agg.new_level, issues_issue.level),
  88. search_vector = concat_tsvector(COALESCE(search_vector, ''::tsvector), event_vector.vector),
  89. tags = CASE WHEN event_agg.new_tags is not null THEN jsonb_merge_deep(event_agg.new_tags, tags) ELSE tags END
  90. FROM event_agg, event_vector
  91. WHERE issues_issue.id = update_issue_id;
  92. $$;
  93. """