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 23 kB

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