You can not select more than 25 topics Topics must start with a chinese character,a letter or number, can include dashes ('-') and can be up to 35 characters long.

dataset_foreigntable_for_es.sql 6.1 kB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186
  1. DROP FOREIGN TABLE public.dataset_es;
  2. CREATE FOREIGN TABLE public.dataset_es
  3. (
  4. id bigint NOT NULL,
  5. title character varying(255),
  6. status integer,
  7. category character varying(255),
  8. description text,
  9. download_times bigint,
  10. license character varying(255),
  11. task character varying(255),
  12. release_id bigint,
  13. user_id bigint,
  14. repo_id bigint,
  15. created_unix bigint,
  16. updated_unix bigint,
  17. file_name text,
  18. file_desc text
  19. )SERVER multicorn_es
  20. OPTIONS
  21. (
  22. host '192.168.207.94',
  23. port '9200',
  24. index 'dataset-es-index',
  25. rowid_column 'id',
  26. default_sort '_id'
  27. )
  28. ;
  29. DELETE FROM public.dataset_es;
  30. INSERT INTO public.dataset_es(
  31. id,
  32. title,
  33. status,
  34. category,
  35. description,
  36. download_times,
  37. license, task,
  38. release_id,
  39. user_id,
  40. repo_id,
  41. created_unix,
  42. updated_unix,
  43. file_name,
  44. file_desc
  45. )
  46. SELECT
  47. b.id,
  48. b.title,
  49. b.status,
  50. b.category,
  51. b.description,
  52. b.download_times,
  53. b.license,
  54. b.task,
  55. b.release_id,
  56. b.user_id,
  57. b.repo_id,
  58. b.created_unix,
  59. b.updated_unix,
  60. (select array_to_string(array_agg(name order by created_unix desc),'-#,#-') from public.attachment a where a.dataset_id=b.id and a.is_private=false),
  61. (select array_to_string(array_agg(description order by created_unix desc),'-#,#-') from public.attachment a where a.dataset_id=b.id and a.is_private=false)
  62. FROM public.dataset b,public.repository c where b.repo_id=c.id and c.is_private=false;
  63. DROP TRIGGER IF EXISTS es_insert_dataset on public.dataset;
  64. CREATE OR REPLACE FUNCTION public.insert_dataset_data() RETURNS trigger AS
  65. $def$
  66. DECLARE
  67. privateValue boolean=false;
  68. BEGIN
  69. select into privateValue is_private from public.repository where id=NEW.repo_id;
  70. if not privateValue then
  71. INSERT INTO public.dataset_es(
  72. id,
  73. title,
  74. status,
  75. category,
  76. description,
  77. download_times,
  78. license,
  79. task,
  80. release_id,
  81. user_id,
  82. repo_id,
  83. created_unix,
  84. updated_unix)
  85. VALUES (
  86. NEW.id,
  87. NEW.title,
  88. NEW.status,
  89. NEW.category,
  90. NEW.description,
  91. NEW.download_times,
  92. NEW.license,
  93. NEW.task,
  94. NEW.release_id,
  95. NEW.user_id,
  96. NEW.repo_id,
  97. NEW.created_unix,
  98. NEW.updated_unix
  99. );
  100. end if;
  101. RETURN NEW;
  102. END;
  103. $def$
  104. LANGUAGE plpgsql;
  105. CREATE TRIGGER es_insert_dataset
  106. AFTER INSERT ON public.dataset
  107. FOR EACH ROW EXECUTE PROCEDURE insert_dataset_data();
  108. ALTER TABLE public.dataset ENABLE ALWAYS TRIGGER es_insert_dataset;
  109. DROP TRIGGER IF EXISTS es_udpate_dataset_file_name on public.attachment;
  110. CREATE OR REPLACE FUNCTION public.udpate_dataset_file_name() RETURNS trigger AS
  111. $def$
  112. BEGIN
  113. if (TG_OP = 'UPDATE') then
  114. update public.dataset_es SET file_desc=(select array_to_string(array_agg(description order by created_unix desc),'-#,#-') from public.attachment where dataset_id=NEW.dataset_id and is_private=false) where id=NEW.dataset_id;
  115. elsif (TG_OP = 'INSERT') then
  116. update public.dataset_es SET file_name=(select array_to_string(array_agg(name order by created_unix desc),'-#,#-') from public.attachment where dataset_id=NEW.dataset_id and is_private=false) where id=NEW.dataset_id;
  117. elsif (TG_OP = 'DELETE') then
  118. update public.dataset_es SET file_name=(select array_to_string(array_agg(name order by created_unix desc),'-#,#-') from public.attachment where dataset_id=OLD.dataset_id and is_private=false) where id=OLD.dataset_id;
  119. update public.dataset_es SET file_desc=(select array_to_string(array_agg(description order by created_unix desc),'-#,#-') from public.attachment where dataset_id=OLD.dataset_id and is_private=false) where id=OLD.dataset_id;
  120. end if;
  121. return NEW;
  122. END;
  123. $def$
  124. LANGUAGE plpgsql;
  125. CREATE TRIGGER es_udpate_dataset_file_name
  126. AFTER INSERT OR UPDATE OR DELETE ON public.attachment
  127. FOR EACH ROW EXECUTE PROCEDURE udpate_dataset_file_name();
  128. ALTER TABLE public.attachment ENABLE ALWAYS TRIGGER es_udpate_dataset_file_name;
  129. DROP TRIGGER IF EXISTS es_update_dataset on public.dataset;
  130. CREATE OR REPLACE FUNCTION public.update_dataset() RETURNS trigger AS
  131. $def$
  132. BEGIN
  133. UPDATE public.dataset_es
  134. SET description=NEW.description,
  135. title=NEW.title,
  136. category=NEW.category,
  137. task=NEW.task,
  138. download_times=NEW.download_times,
  139. updated_unix=NEW.updated_unix,
  140. file_name=(select array_to_string(array_agg(name order by created_unix desc),'-#,#-') from public.attachment where dataset_id=NEW.id and is_private=false),
  141. file_desc=(select array_to_string(array_agg(description order by created_unix desc),'-#,#-') from public.attachment where dataset_id=NEW.id and is_private=false)
  142. where id=NEW.id;
  143. return new;
  144. END
  145. $def$
  146. LANGUAGE plpgsql;
  147. CREATE TRIGGER es_update_dataset
  148. AFTER UPDATE ON public.dataset
  149. FOR EACH ROW EXECUTE PROCEDURE update_dataset();
  150. ALTER TABLE public.dataset ENABLE ALWAYS TRIGGER es_update_dataset;
  151. DROP TRIGGER IF EXISTS es_delete_dataset on public.dataset;
  152. CREATE OR REPLACE FUNCTION public.delete_dataset() RETURNS trigger AS
  153. $def$
  154. declare
  155. BEGIN
  156. DELETE FROM public.dataset_es where id=OLD.id;
  157. return new;
  158. END
  159. $def$
  160. LANGUAGE plpgsql;
  161. CREATE TRIGGER es_delete_dataset
  162. AFTER DELETE ON public.dataset
  163. FOR EACH ROW EXECUTE PROCEDURE delete_dataset();
  164. ALTER TABLE public.dataset ENABLE ALWAYS TRIGGER es_delete_dataset;