dataPuller.dos 32 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010101110121013101410151016101710181019102010211022102310241025102610271028102910301031103210331034103510361037103810391040104110421043104410451046104710481049105010511052105310541055105610571058105910601061106210631064106510661067106810691070107110721073107410751076107710781079108010811082108310841085108610871088108910901091109210931094109510961097109810991100110111021103110411051106110711081109111011111112111311141115111611171118111911201121112211231124112511261127
  1. module fundit::dataPuller
  2. use fundit::sqlUtilities
  3. /*
  4. * 取所有一级策略
  5. *
  6. */
  7. def get_strategy_list() {
  8. s_query = "SELECT strategy_id, strategy, rasie_type AS raise_type FROM mfdb.d_strategy WHERE isvalid = 1";
  9. conn = connect_mysql()
  10. t = odbc::query(conn, s_query)
  11. conn.close()
  12. return t
  13. }
  14. /*
  15. * 取所有二级策略
  16. *
  17. */
  18. def get_substrategy_list() {
  19. s_query = "SELECT substrategy_id, substrategy, raise_type FROM mfdb.d_substrategy WHERE isvalid = 1";
  20. conn = connect_mysql()
  21. t = odbc::query(conn, s_query)
  22. conn.close()
  23. return t
  24. }
  25. /*
  26. * 取指数周收益
  27. *
  28. * Example: get_index_weekly_rets("'FA00000WKG','FA00000WKH','IN0000007G'", 1990.01.01, today());
  29. * get_index_weekly_rets("'IN0000000M'", 1990.01.01, 2024.10.31);
  30. */
  31. def get_index_weekly_rets(index_ids, start_date, end_date) {
  32. s_start_date = iif(start_date.isNull(), "", " AND price_date >= '" + start_date$STRING + "'")
  33. s_end_date = iif(end_date.isNull(), "", " AND price_date <= '" + end_date$STRING + "'")
  34. s_query = "SELECT factor_id AS index_id, year_week, price_date, factor_value AS cumulative_nav, ret_1w
  35. FROM pfdb.cm_factor_performance_weekly
  36. WHERE isvalid = 1
  37. AND factor_id IN (" + index_ids + ")" +
  38. s_start_date +
  39. s_end_date + "
  40. AND ret_1w IS NOT NULL
  41. UNION
  42. SELECT fund_id AS index_id, year_week, price_date, cumulative_nav, ret_1w
  43. FROM mfdb.fund_performance_weekly
  44. WHERE isvalid = 1
  45. AND fund_id IN (" + index_ids + ")" +
  46. s_start_date +
  47. s_end_date + "
  48. AND ret_1w IS NOT NULL
  49. ORDER BY year_week"
  50. conn = connect_mysql()
  51. t = odbc::query(conn, s_query)
  52. conn.close()
  53. return t
  54. }
  55. /*
  56. * 取基金周收益
  57. *
  58. *
  59. * get_fund_weekly_rets("'MF00003TMH','MF00003UQM'", 1990.01.01, null, true)
  60. */
  61. def get_fund_weekly_rets(fund_ids, start_date, end_date, isFromMySQL) {
  62. s_fund_id = iif(fund_ids.isNull(), "", " AND fund_id IN (" + fund_ids + ")")
  63. s_start_date = iif(start_date.isNull(), "", " AND price_date >= '" + start_date$STRING + "'")
  64. s_end_date = iif(end_date.isNull(), "", " AND price_date <= '" + end_date$STRING + "'")
  65. s_query = "SELECT fund_id, year_week, price_date, cumulative_nav, ret_1w
  66. FROM mfdb.fund_performance_weekly
  67. WHERE isvalid = 1 " +
  68. s_fund_id +
  69. s_start_date +
  70. s_end_date + "
  71. AND ret_1w IS NOT NULL
  72. ORDER BY fund_id, year_week"
  73. conn = connect_mysql()
  74. t = odbc::query(conn, s_query)
  75. conn.close()
  76. return t
  77. }
  78. /*
  79. * 通用取周收益
  80. *
  81. */
  82. def get_entity_weekly_rets(entity_type, entity_info) {
  83. rets = null;
  84. if(entity_info.isVoid() || entity_info.size() == 0) return rets;
  85. very_old_date = '1990.01.01';
  86. // 简单起见,取整个数据集的最新日期(month-end production时取上月最后一天即可
  87. end_day = entity_info.price_date.max();
  88. s_entity_ids = ids_to_string(entity_info.entity_id);
  89. if(entity_type == 'HF' || entity_type == 'MF') {
  90. rets = get_fund_weekly_rets(s_entity_ids, very_old_date, end_day, true);
  91. } else if(entity_type == 'MI' || entity_type == 'FA') {
  92. rets = get_index_weekly_rets(s_entity_ids, very_old_date, end_day);
  93. }
  94. return rets;
  95. }
  96. /*
  97. * 取组合周收益
  98. * TODO: 增加从本地取数据的功能
  99. *
  100. *
  101. * get_portfolio_weekly_rets("166002,364640", 1990.01.01, today(), true)
  102. */
  103. def get_portfolio_weekly_rets(portfolio_ids, start_date, end_date, isFromMySQL) {
  104. s_portfolio_id = iif(portfolio_ids.isNull(), "", " AND portfolio_id IN (" + portfolio_ids + ")")
  105. s_query = "SELECT portfolio_id, year_week, price_date, cumulative_nav, ret_1w
  106. FROM pfdb.pf_portfolio_performance_weekly
  107. WHERE isvalid = 1 " +
  108. s_portfolio_id + "
  109. AND ret_1w IS NOT NULL
  110. AND price_date BETWEEN '" + start_date$STRING + "' AND '" + end_date$STRING + "'
  111. ORDER BY portfolio_id, year_week"
  112. conn = connect_mysql()
  113. t = odbc::query(conn, s_query)
  114. conn.close()
  115. return t
  116. }
  117. /*
  118. * 通用取月收益
  119. *
  120. * @param entity_type <STRING>:
  121. * @param entity_ids <VECTOR|STRING>:
  122. * @param start_date <DATE>:
  123. * @param end_date <DATE>:
  124. * @param isFromMySQL <BOOL>:
  125. *
  126. *
  127. * Example: get_monthly_ret('HF', ['HF000004KN','HF000103EU','HF00018WXG'], 2000.01.01, 2024.03.01, true);
  128. */
  129. def get_monthly_ret(entity_type, entity_ids, start_date, end_date, isFromMySQL) {
  130. s_entity_ids = ids_to_string(entity_ids);
  131. if(s_entity_ids == null || s_entity_ids == '') return null;
  132. tmp = get_performance_table_description(entity_type);
  133. yyyymm_start = start_date.temporalFormat("yyyy-MM")
  134. yyyymm_end = end_date.temporalFormat("yyyy-MM")
  135. if(isFromMySQL == true) {
  136. s_query = "SELECT " + tmp.sec_id_col[0] + " AS entity_id, end_date, price_date, ret_1m AS ret, " + tmp.cumulative_nav_col[0] + " AS nav
  137. FROM " + tmp.table_name[0] + "
  138. WHERE " + tmp.sec_id_col[0] + " IN (" + s_entity_ids + ")
  139. AND isvalid = 1
  140. AND end_date BETWEEN '" + yyyymm_start + "' AND '" + yyyymm_end + "'
  141. ORDER BY " + tmp.sec_id_col[0] + ", end_date";
  142. conn = connect_mysql()
  143. t = odbc::query(conn, s_query)
  144. conn.close()
  145. } else {
  146. tb_local = load_table_from_local("fundit", tmp.table_name[0])
  147. s_col = (sqlCol(tmp.sec_id_col[0]), sqlCol("end_date"), sqlColAlias(<ret_1m>, "ret"), sqlColAlias(<cumulative_nav>, "nav"), sqlCol("ret_ytd_a"), sqlCol("ret_incep_a"))
  148. // TODO: how to make the "fund_id" dynamicly decided by tmp.sec_id_col[0], then rename to "entity_id"?
  149. s_where = expr(<fund_id>, in, s_entity_ids.strReplace("'", "").split(","))
  150. t = sql(s_col, tb_local, s_where).eval()
  151. }
  152. return t
  153. }
  154. /*
  155. * 取无风险月度利率
  156. *
  157. * get_risk_free_rate(1990.01.01, today())
  158. */
  159. def get_risk_free_rate(start_date, end_date) {
  160. return get_monthly_ret('MI', "'IN0000000M'", start_date, end_date, true);
  161. }
  162. /*
  163. * 取基金最新收益及净值
  164. *
  165. * get_fund_latest_nav_performance("'HF000004KN','HF00018WXG'")
  166. */
  167. def get_fund_latest_nav_performance(fund_ids, isFromMySQL) {
  168. if(isFromMySQL == true) {
  169. s_query = "SELECT *
  170. FROM mfdb.fund_latest_nav_performance
  171. WHERE fund_id IN (" + fund_ids + ")
  172. AND isvalid = 1
  173. ORDER BY fund_id"
  174. conn = connect_mysql()
  175. t = odbc::query(conn, s_query)
  176. conn.close()
  177. } else {
  178. tb_local = load_table_from_local("fundit", "mfdb.fund_latest_nav_performance")
  179. s_col = sqlCol("*")
  180. s_where = expr(<fund_id>, in, fund_ids.strReplace("'", "").split(","))
  181. t = sql(s_col, tb_local, s_where).eval()
  182. }
  183. return t
  184. }
  185. /*
  186. * 通用取净值
  187. *
  188. *
  189. * Create: 202408 Joey
  190. * TODO: add isvalid and nav > 0 for local version
  191. *
  192. *
  193. * Example: get_nav_by_price_date('HF', "'HF000004KN','HF00018WXG'", 2024.05.01, true);
  194. * get_nav_by_price_date('MI', "'IN00000008','IN0000000M'", 2024.05.01, true);
  195. */
  196. def get_nav_by_price_date(entity_type, entity_ids, price_date, isFromMySQL) {
  197. s_entity_ids = ids_to_string(entity_ids);
  198. if(s_entity_ids == null || s_entity_ids == '') return null;
  199. tmp = get_nav_table_description(entity_type);
  200. if(isFromMySQL == true) {
  201. nav_table_name = tmp.table_name[0];
  202. s_query = "SELECT " + tmp.sec_id_col[0] + " AS entity_id, price_date, " + tmp.cumulative_nav_col[0] + " AS cumulative_nav, " + tmp.nav_col[0] + " AS nav
  203. FROM " + tmp.table_name[0] + "
  204. WHERE " + tmp.sec_id_col[0] + " IN (" + s_entity_ids + ")
  205. AND isvalid = 1
  206. AND " + tmp.cumulative_nav_col[0] + " > 0
  207. AND price_date >= '" + price_date$STRING + "'
  208. ORDER BY " + tmp.sec_id_col[0] + ", price_date";
  209. conn = connect_mysql();
  210. t = odbc::query(conn, s_query);
  211. conn.close();
  212. } else {
  213. tb_local = load_table_from_local("fundit", tmp.table_name[0])
  214. s_col = sqlCol("*")
  215. // TODO: how to make the "fund_id" dynamicly decided by tmp.sec_id_col[0]?
  216. s_where = [expr(<fund_id>, in, s_entity_ids.strReplace("'", "").split(",")), <price_date >= price_date>]
  217. t = sql(s_col, tb_local, s_where).eval()
  218. }
  219. return t
  220. }
  221. /*
  222. * 取指数因子点位
  223. *
  224. * get_index_nav_by_price_date("'IN00000008','FA00000WKG'", 2024.06.01)
  225. */
  226. def get_index_nav_by_price_date(index_ids, price_date) {
  227. s_query = "SELECT index_id, price_date, close AS cumulative_nav
  228. FROM mfdb.market_indexes
  229. WHERE index_id IN (" + index_ids + ")
  230. AND isvalid = 1
  231. AND close > 0
  232. AND price_date >= '" + price_date + "'
  233. UNION
  234. SELECT index_id AS index_id, price_date, index_value AS cumulative_nav
  235. FROM mfdb.indexes_ty_index
  236. WHERE index_id IN (" + index_ids + ")
  237. AND isvalid = 1
  238. AND index_value > 0
  239. AND price_date >= '" + price_date + "'
  240. UNION
  241. SELECT factor_id AS index_id, price_date, factor_value AS cumulative_nav
  242. FROM pfdb.cm_factor_value
  243. WHERE factor_id IN (" + index_ids + ")
  244. AND isvalid = 1
  245. AND factor_value > 0
  246. AND price_date >= '" + price_date + "'
  247. ORDER BY price_date"
  248. conn = connect_mysql()
  249. t = odbc::query(conn, s_query)
  250. conn.close()
  251. return t
  252. }
  253. /*
  254. * 取有效基金基本信息
  255. *
  256. * Example: get_fund_info("'HF000004KN','HF00018WXG'");
  257. * get_fund_info(null);
  258. *
  259. */
  260. def get_fund_info(fund_ids) {
  261. s_entity_ids = ids_to_string(fund_ids);
  262. s_entity_sql = iif(s_entity_ids == NULL, '', " AND fi.fund_id IN (" + s_entity_ids + ")");
  263. s_query = "SELECT fi.fund_id, fi.inception_date, fi.primary_benchmark_id AS benchmark_id, IFNULL(fi.initial_unit_value, 1) AS ini_value, fs.strategy, fs.substrategy, fi.raise_type
  264. FROM mfdb.fund_information fi
  265. INNER JOIN mfdb.fund_strategy fs ON fi.fund_id = fs.fund_id
  266. WHERE fs.isvalid = 1
  267. AND fi.isvalid = 1" +
  268. s_entity_sql + "
  269. ORDER BY fi.fund_id"
  270. conn = connect_mysql()
  271. t = odbc::query(conn, s_query)
  272. conn.close()
  273. return t
  274. }
  275. /*
  276. * 取有效指数基本信息
  277. *
  278. * Example: get_index_info("'IN00000008','IN000002GE'");
  279. * get_index_info(null);
  280. *
  281. */
  282. def get_index_info(index_ids) {
  283. s_entity_ids = ids_to_string(index_ids);
  284. s_entity_sql = iif(s_entity_ids == NULL || s_entity_ids == '', '', " AND fi.index_id IN (" + s_entity_ids + ")");
  285. s_query = "SELECT fi.index_id, fi.inception_date, NULL AS benchmark_id, IFNULL(fi.index_initial_value, 1) AS ini_value, fi.index_code, fi.index_type_id
  286. FROM mfdb.indexes_profile fi
  287. WHERE fi.isvalid = 1" +
  288. s_entity_sql + "
  289. ORDER BY fi.index_id";
  290. conn = connect_mysql();
  291. t = odbc::query(conn, s_query);
  292. conn.close();
  293. return t;
  294. }
  295. /*
  296. * 取组合有效信息
  297. *
  298. * Example: get_portfolio_info('166002,166114');
  299. * get_portfolio_info(NULL);
  300. *
  301. */
  302. def get_portfolio_info(portfolio_ids) {
  303. s_entity_ids = ids_to_string(portfolio_ids);
  304. s_entity_sql = iif(s_entity_ids == NULL || s_entity_ids == '', '', " AND cpm.id IN (" + portfolio_ids + ")");
  305. s_query = "SELECT cpm.id AS portfolio_id, cpm.userid, cpm.customer_id, cpm.inception_date, 1 AS ini_value, cpm.portfolio_source, cpm.portfolio_type
  306. FROM pfdb.`pf_customer_portfolio_map` cpm
  307. INNER JOIN pfdb.cm_user u ON cpm.userid = u.userid
  308. WHERE cpm.isvalid = 1
  309. AND u.isvalid = 1" +
  310. s_entity_sql + "
  311. ORDER BY cpm.id"
  312. conn = connect_mysql()
  313. t = odbc::query(conn, s_query)
  314. conn.close()
  315. return t
  316. }
  317. /*
  318. * 取基金组合基础有效信息
  319. *
  320. * Example: get_entity_info('HF', ['HF000004KN','HF000103EU','HF00018WXG']);
  321. * get_entity_info('PF', '166002,166114');
  322. * get_entity_info('MI', NULL);
  323. */
  324. def get_entity_info(entity_type, entity_ids) {
  325. t = null;
  326. s_entity_ids = ids_to_string(entity_ids);
  327. if(entity_type == 'MF' || entity_type == 'HF') {
  328. t = get_fund_info(s_entity_ids);
  329. t.rename!('fund_id', 'entity_id');
  330. } else if(entity_type == 'PF') {
  331. t = get_portfolio_info(s_entity_ids);
  332. t.rename!('portfolio_id', 'entity_id');
  333. } else if(entity_type IN ['MI', 'FI']) {
  334. t = get_index_info(s_entity_ids);
  335. t.rename!('index_id', 'entity_id');
  336. }
  337. return t;
  338. }
  339. /*
  340. * 取某时间后更新的各基金组合最早净值日期
  341. *
  342. * @param entity_type <STRING>: MF, HF, EQ, CF, MI, TI, CI, FA, PF
  343. * @param entity_ids <VECTOR|STRING>: NULL时取全量
  344. * @param update_time <DATETIME>: all updates after this time
  345. * @param isFromMySQL <BOOL>:
  346. *
  347. * Example: get_entity_list_by_nav_updatetime('MF', ['MF00003PW1', 'MF00003PW2'], 2024.09.26, true);
  348. * get_entity_list_by_nav_updatetime('HF', null, 2024.07.19T10:00:00, true);
  349. * get_entity_list_by_nav_updatetime('PF', '166002,166114', 2024.06.20, true);
  350. *
  351. */
  352. def get_entity_list_by_nav_updatetime(entity_type, entity_ids, updatetime, isFromMySQL) {
  353. tmp = get_nav_table_description(entity_type);
  354. s_entity_ids = ids_to_string(entity_ids);
  355. sql_entity_id = '';
  356. if(s_entity_ids != NULL) {
  357. sql_entity_id = " AND " + tmp.sec_id_col[0] + " IN (" + s_entity_ids + ")";
  358. }
  359. if(isFromMySQL == true) {
  360. nav_table_name = tmp.table_name[0];
  361. s_query = "SELECT " + tmp.sec_id_col[0] + " AS entity_id, MIN(price_date) AS price_date
  362. FROM " + tmp.table_name[0] + "
  363. WHERE isvalid = 1 " +
  364. sql_entity_id + "
  365. AND " + tmp.cumulative_nav_col[0] + " > 0
  366. AND updatetime >= '" + updatetime$STRING + "'
  367. GROUP BY " + tmp.sec_id_col[0] + "
  368. ORDER BY " + tmp.sec_id_col[0] + ", price_date";
  369. conn = connect_mysql();
  370. t = odbc::query(conn, s_query);
  371. conn.close();
  372. } else {
  373. //TODO
  374. }
  375. return t
  376. }
  377. /*
  378. * 取私募基金用于月末 fund_performance 表更新的净值
  379. *
  380. * @param fund_ids: 逗号分隔的ID字符串, 每个ID都有''
  381. * @param month_end: 月末日期字符串 YYYY-MM
  382. *
  383. *
  384. */
  385. def get_nav_for_hedge_fund_performance(fund_ids, month_end) {
  386. s_query = "CALL pfdb.sp_get_nav_for_fund_performance(" + fund_ids + ", '" + month_end + "', 1);"
  387. conn = connect_mysql()
  388. t = odbc::query(conn, s_query)
  389. conn.close()
  390. return t
  391. }
  392. /*
  393. * 取某时间段的基金主基准
  394. * NOTE: 目前数据库里只存最新的基准,以后很可能会支持时间序列
  395. *
  396. * Example: get_fund_primary_benchmark("'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  397. */
  398. def get_fund_primary_benchmark(fund_ids, month_start, month_end) {
  399. s_query = "SELECT fund_id, primary_benchmark_id AS benchmark_id, inception_date
  400. FROM mfdb.fund_information
  401. WHERE fund_id IN (" + fund_ids + ")
  402. AND isvalid = 1;";
  403. conn = connect_mysql();
  404. t = odbc::query(conn, s_query);
  405. conn.close();
  406. t.addColumn('end_date', MONTH);
  407. m_start = temporalParse(month_start, 'yyyy-MM');
  408. m_end = temporalParse(month_end, 'yyyy-MM');
  409. tb_end_date = table(m_start..m_end AS end_date);
  410. return (SELECT t.fund_id, d.end_date, t.benchmark_id FROM t JOIN tb_end_date d WHERE d.end_date >= t.inception_date.month());
  411. }
  412. /*
  413. * 取某时间段的组合主基准
  414. * NOTE: 目前所有Java指标计算组合默认主基准是FA00000VNB,以后很可能会改
  415. *
  416. * Example: get_portfolio_primary_benchmark("166002,166114", '1990-01', '2024-08');
  417. */
  418. def get_portfolio_primary_benchmark(portfolio_ids, month_start, month_end) {
  419. s_query = "SELECT id AS portfolio_id, 'FA00000VNB' AS benchmark_id, inception_date
  420. FROM pfdb.pf_customer_portfolio_map
  421. WHERE id IN (" + portfolio_ids + ")
  422. AND isvalid = 1;";
  423. conn = connect_mysql();
  424. t = odbc::query(conn, s_query);
  425. conn.close();
  426. t.addColumn('end_date', MONTH);
  427. m_start = temporalParse(month_start, 'yyyy-MM');
  428. m_end = temporalParse(month_end, 'yyyy-MM');
  429. tb_end_date = table(m_start..m_end AS end_date);
  430. return (SELECT t.portfolio_id, d.end_date, t.benchmark_id FROM t JOIN tb_end_date d WHERE d.end_date >= t.inception_date.month());
  431. }
  432. /*
  433. * 取某时间段的基金组合主基准
  434. *
  435. * NOTE: 指数和因子的”主基准”设置为沪深300
  436. *
  437. * Example: get_entity_primary_benchmark('MF', "'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  438. * get_entity_primary_benchmark('PF', [166002,166114], '1990-01', '2024-08');
  439. * get_entity_primary_benchmark('MI', ['IN00000008', 'IN0000000M'], '2024-07', '2024-08');
  440. */
  441. def get_entity_primary_benchmark(entity_type, entity_ids, month_start, month_end) {
  442. t = table(100:0,
  443. ['entity_id', 'end_date', 'benchmark_id'],
  444. [iif(entity_type == 'PF', INT, SYMBOL), MONTH, SYMBOL]);
  445. s_entity_ids = ids_to_string(entity_ids);
  446. if(s_entity_ids == null || s_entity_ids == '') return null;
  447. if(entity_type == 'MF' || entity_type == 'HF') {
  448. t = get_fund_primary_benchmark(s_entity_ids, month_start, month_end);
  449. t.rename!('fund_id', 'entity_id');
  450. } else if(entity_type == 'PF') {
  451. t = get_portfolio_primary_benchmark(s_entity_ids, month_start, month_end);
  452. t.rename!('portfolio_id', 'entity_id');
  453. } else if(entity_type IN ['MI', 'FI', 'FA', 'CI', 'EQ']) {
  454. // 对于指数、因子来说,没有什么基准。但为了指标计算不得不在这里设个假的
  455. t = SELECT entity_id, end_date, 'IN00000008' AS benchmark_id
  456. FROM cj(get_entity_info(entity_type, s_entity_ids), table(temporalParse(month_start, 'yyyy-MM')..temporalParse(month_end, 'yyyy-MM') AS end_date))
  457. WHERE end_date >= iif(inception_date.isNull(), 1990.01M, inception_date.month())
  458. }
  459. return t;
  460. }
  461. /*
  462. * 取某时间段的基金BFI因子
  463. *
  464. * Example: get_fund_bfi_factors("'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  465. * get_fund_bfi_factors(['MF00003PW2', 'MF00003PW1', 'MF00003PXO'], '1990-01', '2024-06');
  466. */
  467. def get_fund_bfi_factors(fund_ids, month_start, month_end) {
  468. s_entity_ids = ids_to_string(fund_ids);
  469. if(s_entity_ids == null || s_entity_ids == '') return null;
  470. s_query = "SELECT fund_id, end_date, factor_id
  471. FROM pfdb.pf_fund_factor_bfi_by_category_group
  472. WHERE fund_id IN (" + s_entity_ids + ")
  473. AND end_date >= '" + month_start + "'
  474. AND end_date <= '" + month_end + "'
  475. AND isvalid = 1
  476. ORDER BY fund_id, end_date, factor_id;";
  477. conn = connect_mysql();
  478. t = odbc::query(conn, s_query);
  479. conn.close();
  480. return t;
  481. }
  482. /*
  483. * 取某时间段的组合BFI因子
  484. *
  485. * Example: get_portfolio_bfi_factors("166002,166114", '1900-01', '2024-06');
  486. */
  487. def get_portfolio_bfi_factors(portfolio_ids, month_start, month_end) {
  488. s_query = "SELECT portfolio_id, end_date, factor_id
  489. FROM pfdb.pf_portfolio_factor_bfi_by_category_group
  490. WHERE portfolio_id IN (" + portfolio_ids + ")
  491. AND end_date >= '" + month_start + "'
  492. AND end_date <= '" + month_end + "'
  493. AND isvalid = 1
  494. ORDER BY portfolio_id, end_date, factor_id;";
  495. conn = connect_mysql();
  496. t = odbc::query(conn, s_query);
  497. conn.close();
  498. return t;
  499. }
  500. /*
  501. * 取某时间段的基金组合BFI基准
  502. *
  503. *
  504. * Example: get_entity_bfi_factors('MF', "'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  505. * get_entity_bfi_factors('PF', [166002,166114], '1990-01', '2024-08');
  506. */
  507. def get_entity_bfi_factors(entity_type, entity_ids, month_start, month_end) {
  508. t = null;
  509. s_entity_ids = ids_to_string(entity_ids);
  510. if(s_entity_ids == null || s_entity_ids == '') return null;
  511. if(entity_type == 'MF' || entity_type == 'HF') {
  512. t = get_fund_bfi_factors(s_entity_ids, month_start, month_end);
  513. t.rename!('fund_id', 'entity_id');
  514. } else if(entity_type == 'PF') {
  515. t = get_portfolio_bfi_factors(s_entity_ids, month_start, month_end);
  516. t.rename!('portfolio_id', 'entity_id');
  517. }
  518. return t;
  519. }
  520. /*
  521. * 取组合交易表
  522. *
  523. *
  524. * Example: get_portfolio_holding_history("166002,364640")
  525. */
  526. def get_portfolio_holding_history(portfolio_ids) {
  527. s_query = "SELECT portfolio_id, holding_date, fund_id, amount, fund_share, ROUND(amount/fund_share, 6) AS nav
  528. FROM pfdb.pf_portfolio_fund_history
  529. WHERE portfolio_id IN (" + portfolio_ids + ")
  530. AND isvalid = 1
  531. ORDER BY portfolio_id, holding_date";
  532. conn = connect_mysql();
  533. t = odbc::query(conn, s_query);
  534. conn.close();
  535. return t;
  536. }
  537. /*
  538. * 取基金证券从某日期后的所有净值及前值
  539. *
  540. * @param entity_type <STRING>: MF, HF, EQ, CF, MI, TI, CI, FA, PF
  541. * @param freq <STRING>: m, w, d
  542. * @param json_query <JSON>: [{sec_id:xxx, price_date: yyyy-mm-dd}]
  543. *
  544. */
  545. def get_nav_for_return_calculation(entity_type, freq, json_query) {
  546. s_query = "CALL pfdb.sp_get_nav_after_date('" + entity_type + "', '" + freq + "', '" + json_query + "')";
  547. conn = connect_mysql();
  548. t = odbc::query(conn, s_query);
  549. conn.close();
  550. return t;
  551. }
  552. /*
  553. * 取主基准和BFI的历史月收益率
  554. *
  555. * @param benchmarks <TABLE>: entity-benchmark 的对应关系表
  556. * @param end_day <DATE>: 收益的截止日期
  557. *
  558. * @return <TABLE>: benchmark_id, end_date, ret
  559. *
  560. */
  561. def get_benchmark_return(benchmarks, end_day) {
  562. s_index_ids = '';
  563. s_factor_ids = '';
  564. if(benchmarks.isVoid() || benchmarks.size() == 0) { return null; }
  565. // 前缀为 IN 的 benchmark id
  566. t_index_id = SELECT DISTINCT benchmark_id FROM benchmarks WHERE benchmark_id LIKE 'IN%';
  567. s_index_ids = iif(isVoid(t_index_id), "", "'" + t_index_id.benchmark_id.concat("','") + "'");
  568. // 前缀为 FA 的 benchmark id
  569. t_factor_id = SELECT DISTINCT benchmark_id FROM benchmarks WHERE benchmark_id LIKE 'FA%';
  570. s_factor_ids = iif(isVoid(t_factor_id), "", "'" + t_factor_id.benchmark_id.concat("','") + "'");
  571. // 目前指数的月度业绩存在 fund_performance 表
  572. t_bmk = SELECT entity_id AS benchmark_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_monthly_ret('MI', s_index_ids, 1990.01.01, end_day, true);
  573. // 而因子的月度业绩存在 cm_factor_performance 表
  574. INSERT INTO t_bmk SELECT entity_id AS factor_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_monthly_ret('FA', s_factor_ids, 1990.01.01, end_day, true);
  575. return t_bmk;
  576. }
  577. /*
  578. * 取持有基金净值更新的组合列表
  579. *
  580. * TODO: 需要跑3分钟,待优化
  581. *
  582. * Example: get_portfolio_list_by_fund_nav_updatetime([166002,166114], 2024.10.28, true);
  583. */
  584. def get_portfolio_list_by_fund_nav_updatetime(portfolio_ids, updatetime, isFromMySQL) {
  585. t = null;
  586. s_entity_ids = ids_to_string(portfolio_ids);
  587. if(isFromMySQL == true) {
  588. s_query = "CALL pfdb.sp_get_portfolios_to_cal_nav(" + iif(s_entity_ids.isNull(), 'NULL', "'" + s_entity_ids + "'") + ",'" + updatetime + "')";
  589. conn = connect_mysql();
  590. t = odbc::query(conn, s_query);
  591. conn.close();
  592. }
  593. return t
  594. }
  595. /*
  596. * 取Json中指定的组合当日净值
  597. *
  598. * @param s_json <JSON>
  599. *
  600. * Example: get_portfolio_nav_by_date([{"portfolio_id": 166002,"price_date": "2024.10.25"},{"portfolio_id": 166114,"price_date": "2024.03.13"}], true);
  601. */
  602. def get_portfolio_nav_by_date(s_json, isFromMySQL) {
  603. t = null;
  604. if(isFromMySQL == true) {
  605. s_query = "SELECT t.portfolio_id, t.price_date, nav.cumulative_nav
  606. FROM JSON_TABLE ( '" + s_json + "', '$[*]'
  607. COLUMNS ( portfolio_id INT PATH '$.portfolio_id',
  608. price_date DATE PATH '$.price_date' ) ) t
  609. LEFT JOIN pfdb.pf_portfolio_nav nav ON t.portfolio_id = nav.portfolio_id AND t.price_date = nav.price_date;";
  610. conn = connect_mysql();
  611. t = odbc::query(conn, s_query);
  612. conn.close();
  613. }
  614. return t;
  615. }
  616. /*
  617. * 取月度指标表
  618. *
  619. * @param table_name <STRING>: 指标表名
  620. * @param end_date <MONTH>
  621. * @param isFromMySQL <BOOL>
  622. *
  623. * Example: get_monthly_indicator_data('mfdb.fund_performance', 2024.09M, true);
  624. */
  625. def get_monthly_indicator_data(table_name, end_date, isFromMySQL=true) {
  626. t = null;
  627. s_end_date_sql = iif(end_date.isNull(), '', " AND end_date = '" + end_date.temporalFormat('yyyy-MM') + "'" );
  628. if(isFromMySQL == true) {
  629. s_query = "SELECT * FROM " + table_name + " WHERE isvalid = 1 " + s_end_date_sql;
  630. conn = connect_mysql();
  631. t = odbc::query(conn, s_query);
  632. conn.close();
  633. }
  634. return t;
  635. }
  636. /*
  637. * 【Morningstar Integration】取某时间后净值更新的公募基金列表
  638. *
  639. * @param entity_ids <STRING|VECTOR>:
  640. * @param update_time <DATETIME>: all updates after this time
  641. *
  642. * TODO: 将 public_nav2 换成 mfdb.public_nav 后,要把 createtime 改成 updatetime
  643. *
  644. * Example: ms_get_fund_list_by_nav_updatetime(['MF00003PW1','MF00003PWC'], 2024.10.26);
  645. */
  646. def ms_get_fund_list_by_nav_updatetime(entity_ids, updatetime) {
  647. s_entity_ids = ids_to_string(entity_ids);
  648. sql_entity_id = '';
  649. if(s_entity_ids != NULL) {
  650. sql_entity_id = " AND fund_id IN (" + s_entity_ids + ")";
  651. }
  652. s_query = "SELECT fund_id AS entity_id, MIN(price_date) AS price_date
  653. FROM raw_db.public_nav2
  654. WHERE isvalid = 1 " +
  655. sql_entity_id + "
  656. AND cumulative_nav > 0
  657. AND createtime >= '" + updatetime$STRING + "'
  658. GROUP BY fund_id
  659. ORDER BY fund_id, price_date";
  660. conn = connect_mysql();
  661. t = odbc::query(conn, s_query);
  662. conn.close();
  663. return t
  664. }
  665. /*
  666. * 【Morningstar Integration】
  667. *
  668. * Example: ms_get_fund_info("'MF00003PW1','MF00003PWC'");
  669. *
  670. */
  671. def ms_get_fund_info(fund_ids) {
  672. s_entity_ids = ids_to_string(fund_ids);
  673. if(s_entity_ids == NULL || s_entity_ids == '') return null;
  674. s_query = "SELECT fi.fund_id, fi.inception_date, fi.primary_benchmark_id AS benchmark_id, IFNULL(fi.initial_unit_value, 1) AS ini_value, fs.strategy, fs.substrategy
  675. FROM raw_db.fund_information2 fi
  676. INNER JOIN raw_db.fund_strategy2 fs ON fi.fund_id = fs.fund_id AND fs.isvalid = 1
  677. WHERE fi.fund_id IN (" + s_entity_ids + ")
  678. AND fi.isvalid = 1
  679. ORDER BY fi.fund_id"
  680. conn = connect_mysql()
  681. t = odbc::query(conn, s_query)
  682. conn.close()
  683. return t
  684. }
  685. /*
  686. * 【Morningstar Integration】
  687. *
  688. * Example: ms_get_fund_monthly_nav(['MF00003PW1','MF00003PWC']);
  689. *
  690. */
  691. def ms_get_fund_monthly_nav(fund_ids) {
  692. s_entity_ids = ids_to_string(fund_ids);
  693. if(s_entity_ids == NULL || s_entity_ids == '') return null;
  694. s_query = "SELECT n.fund_id AS entity_id, n.price_date, n.cumulative_nav
  695. FROM raw_db.public_nav2 n INNER JOIN (
  696. SELECT fund_id, max(price_date) AS monthend_date
  697. FROM raw_db.public_nav2
  698. WHERE fund_id IN (" + s_entity_ids + ")
  699. AND isvalid = 1
  700. AND cumulative_nav > 0
  701. GROUP BY fund_id, DATE_FORMAT(price_date, '%Y-%m')
  702. ) t ON n.fund_id = t.fund_id AND n.price_date = t.monthend_date
  703. UNION
  704. SELECT fi.fund_id, fi.inception_date, IFNULL(fi.initial_unit_value, 1)
  705. FROM raw_db.fund_information2 fi
  706. WHERE fi.fund_id IN (" + s_entity_ids + ")
  707. ORDER BY entity_id, price_date;"
  708. conn = connect_mysql()
  709. t = odbc::query(conn, s_query)
  710. conn.close()
  711. return t
  712. }
  713. /*
  714. * 【Morningstar Integration】取某时间段的基金主基准
  715. * NOTE: 目前数据库里只存最新的基准,以后很可能会支持时间序列
  716. *
  717. * Example: ms_get_fund_primary_benchmark("'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  718. */
  719. def ms_get_fund_primary_benchmark(fund_ids, month_start, month_end) {
  720. s_query = "SELECT fund_id, primary_benchmark_id AS benchmark_id, inception_date
  721. FROM raw_db.fund_information2
  722. WHERE fund_id IN (" + fund_ids + ")
  723. AND isvalid = 1;";
  724. conn = connect_mysql();
  725. t = odbc::query(conn, s_query);
  726. conn.close();
  727. t.addColumn('end_date', MONTH);
  728. m_start = temporalParse(month_start, 'yyyy-MM');
  729. m_end = temporalParse(month_end, 'yyyy-MM');
  730. tb_end_date = table(m_start..m_end AS end_date);
  731. return (SELECT t.fund_id, d.end_date, t.benchmark_id FROM t JOIN tb_end_date d WHERE d.end_date >= t.inception_date.month());
  732. }
  733. /*
  734. * 【Morningstar Integration】取某时间段的基金组合主基准
  735. *
  736. *
  737. * Example: ms_get_entity_primary_benchmark('MF', "'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  738. * ms_get_entity_primary_benchmark('PF', [166002,166114], '1990-01', '2024-08');
  739. */
  740. def ms_get_entity_primary_benchmark(entity_type, entity_ids, month_start, month_end) {
  741. t = null;
  742. s_entity_ids = ids_to_string(entity_ids);
  743. if(s_entity_ids == null || s_entity_ids == '') return null;
  744. if(entity_type == 'MF' || entity_type == 'HF') {
  745. t = ms_get_fund_primary_benchmark(s_entity_ids, month_start, month_end);
  746. t.rename!('fund_id', 'entity_id');
  747. } else if(entity_type == 'PF') {
  748. t = get_portfolio_primary_benchmark(s_entity_ids, month_start, month_end);
  749. t.rename!('portfolio_id', 'entity_id');
  750. }
  751. return t;
  752. }
  753. /*
  754. * 【Morningstar Integration】取无风险月度利率
  755. *
  756. * ms_get_risk_free_rate(1990.01.01, today())
  757. */
  758. def ms_get_risk_free_rate(start_date, end_date) {
  759. return get_monthly_ret('MI', "'IN000002EI'", start_date, end_date, true);
  760. }
  761. /*
  762. * 【Morningstar Integration】取某时间段的基金同类平均指数
  763. * NOTE: 目前数据库里只存最新的基准,以后很可能会支持时间序列
  764. *
  765. * Example: ms_get_fund_category_average("'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", '1990-01', '2024-06');
  766. */
  767. def ms_get_fund_category_average(fund_ids, month_start, month_end) {
  768. s_query = "SELECT fi.fund_id, ip.index_id AS benchmark_id, fi.inception_date
  769. FROM raw_db.fund_information2 fi
  770. INNER JOIN mfdb.indexes_profile ip ON ip.index_code = concat('MSMWCA.2.', fi.pub_sub_fund_type)
  771. WHERE fi.fund_id IN (" + fund_ids + ")
  772. AND fi.isvalid = 1
  773. AND ip.isvalid = 1;";
  774. conn = connect_mysql();
  775. t = odbc::query(conn, s_query);
  776. conn.close();
  777. t.addColumn('end_date', MONTH);
  778. m_start = temporalParse(month_start, 'yyyy-MM');
  779. m_end = temporalParse(month_end, 'yyyy-MM');
  780. tb_end_date = table(m_start..m_end AS end_date);
  781. return (SELECT t.fund_id, d.end_date, t.benchmark_id FROM t JOIN tb_end_date d WHERE d.end_date >= t.inception_date.month());
  782. }