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.

repo_foreigntable_for_es.sql 22 kB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533
  1. -- 要处理项目从私有变为公有,并且从公有变成私有的情况
  2. DROP FOREIGN table if exists public.repository_es;
  3. CREATE FOREIGN TABLE public.repository_es (
  4. id bigint NOT NULL,
  5. owner_id bigint,
  6. owner_name character varying(255),
  7. lower_name character varying(255) NOT NULL,
  8. name character varying(255) NOT NULL,
  9. description text,
  10. website character varying(2048),
  11. original_service_type integer,
  12. original_url character varying(2048),
  13. default_branch character varying(255),
  14. num_watches integer,
  15. num_stars integer,
  16. num_forks integer,
  17. num_issues integer,
  18. num_closed_issues integer,
  19. num_pulls integer,
  20. num_closed_pulls integer,
  21. num_milestones integer DEFAULT 0 NOT NULL,
  22. num_closed_milestones integer DEFAULT 0 NOT NULL,
  23. is_private boolean,
  24. is_empty boolean,
  25. is_archived boolean,
  26. is_mirror boolean,
  27. status integer DEFAULT 0 NOT NULL,
  28. is_fork boolean DEFAULT false NOT NULL,
  29. fork_id bigint,
  30. is_template boolean DEFAULT false NOT NULL,
  31. template_id bigint,
  32. size bigint DEFAULT 0 NOT NULL,
  33. is_fsck_enabled boolean DEFAULT true NOT NULL,
  34. close_issues_via_commit_in_any_branch boolean DEFAULT false NOT NULL,
  35. topics text,
  36. avatar character varying(64),
  37. created_unix bigint,
  38. updated_unix bigint,
  39. contract_address character varying(255),
  40. block_chain_status integer DEFAULT 0 NOT NULL,
  41. balance character varying(255) DEFAULT '0'::character varying NOT NULL,
  42. clone_cnt bigint DEFAULT 0 NOT NULL,
  43. license character varying(100),
  44. download_cnt bigint DEFAULT 0 NOT NULL,
  45. num_commit bigint DEFAULT 0 NOT NULL,
  46. git_clone_cnt bigint DEFAULT 0 NOT NULL,
  47. lang character varying(2048)
  48. ) SERVER multicorn_es
  49. OPTIONS
  50. (
  51. host '192.168.207.94',
  52. port '9200',
  53. index 'repository-es-index',
  54. rowid_column 'id',
  55. default_sort '_id'
  56. )
  57. ;
  58. delete from public.repository_es;
  59. INSERT INTO public.repository_es (id,
  60. owner_id,
  61. owner_name,
  62. lower_name,
  63. name,
  64. description,
  65. website,
  66. original_service_type,
  67. original_url,
  68. default_branch,
  69. num_watches,
  70. num_stars,
  71. num_forks,
  72. num_issues,
  73. num_closed_issues,
  74. num_pulls,
  75. num_closed_pulls,
  76. num_milestones,
  77. num_closed_milestones,
  78. is_private,
  79. is_empty,
  80. is_archived,
  81. is_mirror,
  82. status,
  83. is_fork,
  84. fork_id,
  85. is_template,
  86. template_id,
  87. size,
  88. is_fsck_enabled,
  89. close_issues_via_commit_in_any_branch,
  90. topics,
  91. avatar,
  92. created_unix,
  93. updated_unix,
  94. contract_address,
  95. block_chain_status,
  96. balance,
  97. clone_cnt,
  98. num_commit,
  99. git_clone_cnt,lang)
  100. SELECT
  101. id,
  102. owner_id,
  103. owner_name,
  104. lower_name,
  105. name,
  106. description,
  107. website,
  108. original_service_type,
  109. original_url,
  110. default_branch,
  111. num_watches,
  112. num_stars,
  113. num_forks,
  114. num_issues,
  115. num_closed_issues,
  116. num_pulls,
  117. num_closed_pulls,
  118. num_milestones,
  119. num_closed_milestones,
  120. is_private,
  121. is_empty,
  122. is_archived,
  123. is_mirror,
  124. status,
  125. is_fork,
  126. fork_id,
  127. is_template,
  128. template_id,
  129. size,
  130. is_fsck_enabled,
  131. close_issues_via_commit_in_any_branch,
  132. topics,
  133. avatar,
  134. created_unix,
  135. updated_unix,
  136. contract_address,
  137. block_chain_status,
  138. balance,
  139. clone_cnt,
  140. num_commit,
  141. git_clone_cnt,(select string_agg(language, ',') from public.language_stat a where a.repo_id=b.id)
  142. FROM public.repository b where b.is_private=false;
  143. CREATE OR REPLACE FUNCTION public.insert_repository_data() RETURNS trigger AS
  144. $def$
  145. BEGIN
  146. if not NEW.is_private then
  147. INSERT INTO public.repository_es (id,
  148. owner_id,
  149. owner_name,
  150. lower_name,
  151. name,
  152. description,
  153. website,
  154. original_service_type,
  155. original_url,
  156. default_branch,
  157. num_watches,
  158. num_stars,
  159. num_forks,
  160. num_issues,
  161. num_closed_issues,
  162. num_pulls,
  163. num_closed_pulls,
  164. num_milestones,
  165. num_closed_milestones,
  166. is_private,
  167. is_empty,
  168. is_archived,
  169. is_mirror,
  170. status,
  171. is_fork,
  172. fork_id,
  173. is_template,
  174. template_id,
  175. size,
  176. is_fsck_enabled,
  177. close_issues_via_commit_in_any_branch,
  178. topics,
  179. avatar,
  180. created_unix,
  181. updated_unix,
  182. contract_address,
  183. block_chain_status,
  184. balance,
  185. clone_cnt,
  186. num_commit,
  187. git_clone_cnt) VALUES
  188. (NEW.id,
  189. NEW.owner_id,
  190. NEW.owner_name,
  191. NEW.lower_name,
  192. NEW.name,
  193. NEW.description,
  194. NEW.website,
  195. NEW.original_service_type,
  196. NEW.original_url,
  197. NEW.default_branch,
  198. NEW.num_watches,
  199. NEW.num_stars,
  200. NEW.num_forks,
  201. NEW.num_issues,
  202. NEW.num_closed_issues,
  203. NEW.num_pulls,
  204. NEW.num_closed_pulls,
  205. NEW.num_milestones,
  206. NEW.num_closed_milestones,
  207. NEW.is_private,
  208. NEW.is_empty,
  209. NEW.is_archived,
  210. NEW.is_mirror,
  211. NEW.status,
  212. NEW.is_fork,
  213. NEW.fork_id,
  214. NEW.is_template,
  215. NEW.template_id,
  216. NEW.size,
  217. NEW.is_fsck_enabled,
  218. NEW.close_issues_via_commit_in_any_branch,
  219. NEW.topics,
  220. NEW.avatar,
  221. NEW.created_unix,
  222. NEW.updated_unix,
  223. NEW.contract_address,
  224. NEW.block_chain_status,
  225. NEW.balance,
  226. NEW.clone_cnt,
  227. NEW.num_commit,
  228. NEW.git_clone_cnt);
  229. end if;
  230. RETURN NEW;
  231. END;
  232. $def$
  233. LANGUAGE plpgsql;
  234. DROP TRIGGER IF EXISTS es_insert_repository on public.repository;
  235. CREATE TRIGGER es_insert_repository
  236. AFTER INSERT ON public.repository
  237. FOR EACH ROW EXECUTE PROCEDURE insert_repository_data();
  238. ALTER TABLE public.repository ENABLE ALWAYS TRIGGER es_insert_repository;
  239. CREATE OR REPLACE FUNCTION public.update_repository() RETURNS trigger AS
  240. $def$
  241. BEGIN
  242. if OLD.is_private != NEW.is_private then
  243. if OLD.is_private and not NEW.is_private then
  244. --insert
  245. INSERT INTO public.repository_es (id,
  246. owner_id,
  247. owner_name,
  248. lower_name,
  249. name,
  250. description,
  251. website,
  252. original_service_type,
  253. original_url,
  254. default_branch,
  255. num_watches,
  256. num_stars,
  257. num_forks,
  258. num_issues,
  259. num_closed_issues,
  260. num_pulls,
  261. num_closed_pulls,
  262. num_milestones,
  263. num_closed_milestones,
  264. is_private,
  265. is_empty,
  266. is_archived,
  267. is_mirror,
  268. status,
  269. is_fork,
  270. fork_id,
  271. is_template,
  272. template_id,
  273. size,
  274. is_fsck_enabled,
  275. close_issues_via_commit_in_any_branch,
  276. topics,
  277. avatar,
  278. created_unix,
  279. updated_unix,
  280. contract_address,
  281. block_chain_status,
  282. balance,
  283. clone_cnt,
  284. num_commit,
  285. git_clone_cnt,lang)
  286. SELECT
  287. id,
  288. owner_id,
  289. owner_name,
  290. lower_name,
  291. name,
  292. description,
  293. website,
  294. original_service_type,
  295. original_url,
  296. default_branch,
  297. num_watches,
  298. num_stars,
  299. num_forks,
  300. num_issues,
  301. num_closed_issues,
  302. num_pulls,
  303. num_closed_pulls,
  304. num_milestones,
  305. num_closed_milestones,
  306. is_private,
  307. is_empty,
  308. is_archived,
  309. is_mirror,
  310. status,
  311. is_fork,
  312. fork_id,
  313. is_template,
  314. template_id,
  315. size,
  316. is_fsck_enabled,
  317. close_issues_via_commit_in_any_branch,
  318. topics,
  319. avatar,
  320. created_unix,
  321. updated_unix,
  322. contract_address,
  323. block_chain_status,
  324. balance,
  325. clone_cnt,
  326. num_commit,
  327. git_clone_cnt,(select string_agg(language, ',') from public.language_stat a where a.repo_id=b.id)
  328. FROM public.repository b where b.id=NEW.id;
  329. INSERT INTO public.dataset_es(
  330. id,
  331. title,
  332. status,
  333. category,
  334. description,
  335. download_times,
  336. license, task,
  337. release_id,
  338. user_id,
  339. repo_id,
  340. created_unix,
  341. updated_unix,file_name)
  342. SELECT
  343. b.id,
  344. b.title,
  345. b.status,
  346. b.category,
  347. b.description,
  348. b.download_times,
  349. b.license,
  350. b.task,
  351. b.release_id,
  352. b.user_id,
  353. b.repo_id,
  354. b.created_unix,
  355. b.updated_unix,(select array_to_string(array_agg(name order by created_unix desc),',') from public.attachment a where a.dataset_id=b.id)
  356. FROM public.dataset b where b.repo_id=NEW.id;
  357. INSERT INTO public.issue_es(
  358. id,
  359. repo_id,
  360. index,
  361. poster_id,
  362. original_author,
  363. original_author_id,
  364. name,
  365. content,
  366. milestone_id,
  367. priority,
  368. is_closed,
  369. is_pull,
  370. num_comments,
  371. ref,
  372. deadline_unix,
  373. created_unix,
  374. updated_unix,
  375. closed_unix,
  376. is_locked,
  377. amount,
  378. is_transformed,comment,pr_id)
  379. SELECT
  380. b.id,
  381. b.repo_id,
  382. b.index,
  383. b.poster_id,
  384. b.original_author,
  385. b.original_author_id,
  386. b.name,
  387. b.content,
  388. b.milestone_id,
  389. b.priority,
  390. b.is_closed,
  391. b.is_pull,
  392. b.num_comments,
  393. b.ref,
  394. b.deadline_unix,
  395. b.created_unix,
  396. b.updated_unix,
  397. b.closed_unix,
  398. b.is_locked,
  399. b.amount,
  400. b.is_transformed,
  401. (select array_to_string(array_agg(content order by created_unix desc),',') from public.comment a where a.issue_id=b.id),
  402. (select id from public.pull_request d where d.issue_id=b.id)
  403. FROM public.issue b where b.repo_id=NEW.id;
  404. INSERT INTO public.pull_request_es(
  405. id,
  406. type,
  407. status,
  408. conflicted_files,
  409. commits_ahead,
  410. commits_behind,
  411. issue_id,
  412. index,
  413. head_repo_id,
  414. base_repo_id,
  415. head_branch,
  416. base_branch,
  417. merge_base,
  418. has_merged,
  419. merged_commit_id,
  420. merger_id,
  421. merged_unix,
  422. is_transformed,
  423. amount)
  424. SELECT
  425. b.id,
  426. b.type,
  427. b.status,
  428. b.conflicted_files,
  429. b.commits_ahead,
  430. b.commits_behind,
  431. b.issue_id,
  432. b.index,
  433. b.head_repo_id,
  434. b.base_repo_id,
  435. b.head_branch,
  436. b.base_branch,
  437. b.merge_base,
  438. b.has_merged,
  439. b.merged_commit_id,
  440. b.merger_id,
  441. b.merged_unix,
  442. b.is_transformed,
  443. b.amount
  444. FROM public.pull_request b where b.base_repo_id=NEW.id;
  445. end if;
  446. if not OLD.is_private and NEW.is_private then
  447. delete from public.issue_es where repo_id=NEW.id;
  448. delete from public.dataset_es where repo_id=NEW.id;
  449. delete from public.pull_request_es where base_repo_id=NEW.id;
  450. delete from public.repository_es where id=NEW.id;
  451. end if;
  452. end if;
  453. if not NEW.is_private then
  454. update public.repository_es SET description=NEW.description,
  455. name=NEW.name,
  456. lower_name=NEW.lower_name,
  457. owner_name=NEW.owner_name,
  458. website=NEW.website,
  459. updated_unix=NEW.updated_unix,
  460. num_watches=NEW.num_watches,
  461. num_stars=NEW.num_stars,
  462. num_forks=NEW.num_forks,
  463. topics=NEW.topics
  464. where id=NEW.id;
  465. end if;
  466. return new;
  467. END
  468. $def$
  469. LANGUAGE plpgsql;
  470. DROP TRIGGER IF EXISTS es_update_repository on public.repository;
  471. CREATE TRIGGER es_update_repository
  472. AFTER UPDATE ON public.repository
  473. FOR EACH ROW EXECUTE PROCEDURE update_repository();
  474. ALTER TABLE public.repository ENABLE ALWAYS TRIGGER es_update_repository;
  475. CREATE OR REPLACE FUNCTION public.delete_repository() RETURNS trigger AS
  476. $def$
  477. declare
  478. BEGIN
  479. delete from public.issue_es where repo_id=OLD.id;
  480. delete from public.dataset_es where repo_id=OLD.id;
  481. delete from public.pull_request_es where base_repo_id=OLD.id;
  482. DELETE FROM public.repository_es where id=OLD.id;
  483. return new;
  484. END
  485. $def$
  486. LANGUAGE plpgsql;
  487. DROP TRIGGER IF EXISTS es_delete_repository on public.repository;
  488. CREATE TRIGGER es_delete_repository
  489. AFTER DELETE ON public.repository
  490. FOR EACH ROW EXECUTE PROCEDURE delete_repository();
  491. ALTER TABLE public.repository ENABLE ALWAYS TRIGGER es_delete_repository;
  492. CREATE OR REPLACE FUNCTION public.udpate_repository_lang() RETURNS trigger AS
  493. $def$
  494. BEGIN
  495. if (TG_OP = 'DELETE') then
  496. update public.repository_es SET lang=(select string_agg(language, ',') from public.language_stat where repo_id=OLD.repo_id) where id=OLD.repo_id;
  497. elsif (TG_OP = 'UPDATE') then
  498. update public.repository_es SET lang=(select string_agg(language, ',') from public.language_stat where repo_id=NEW.repo_id) where id=NEW.repo_id;
  499. elsif (TG_OP = 'INSERT') then
  500. update public.repository_es SET lang=(select string_agg(language, ',') from public.language_stat where repo_id=NEW.repo_id) where id=NEW.repo_id;
  501. end if;
  502. return null;
  503. END;
  504. $def$
  505. LANGUAGE plpgsql;
  506. DROP TRIGGER IF EXISTS es_udpate_repository_lang on public.language_stat;
  507. CREATE TRIGGER es_udpate_repository_lang
  508. AFTER INSERT OR UPDATE OR DELETE ON public.language_stat
  509. FOR EACH ROW EXECUTE PROCEDURE udpate_repository_lang();
  510. ALTER TABLE public.language_stat ENABLE ALWAYS TRIGGER es_udpate_repository_lang;