indicatorCalculator.dos 59 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010101110121013101410151016101710181019102010211022102310241025102610271028102910301031103210331034103510361037103810391040104110421043104410451046104710481049105010511052105310541055105610571058105910601061106210631064106510661067106810691070107110721073107410751076107710781079108010811082108310841085108610871088108910901091109210931094109510961097109810991100110111021103110411051106110711081109111011111112111311141115111611171118111911201121112211231124112511261127112811291130113111321133113411351136113711381139114011411142114311441145114611471148114911501151115211531154115511561157115811591160116111621163116411651166116711681169117011711172117311741175117611771178117911801181118211831184118511861187118811891190119111921193119411951196119711981199120012011202120312041205120612071208120912101211121212131214121512161217121812191220122112221223122412251226122712281229123012311232123312341235123612371238123912401241124212431244124512461247124812491250125112521253125412551256125712581259126012611262126312641265126612671268126912701271127212731274127512761277127812791280128112821283128412851286128712881289129012911292129312941295129612971298129913001301130213031304130513061307130813091310131113121313131413151316131713181319132013211322132313241325132613271328132913301331133213331334133513361337133813391340134113421343134413451346134713481349135013511352135313541355135613571358135913601361136213631364136513661367136813691370137113721373137413751376137713781379
  1. module fundit::indicatorCalculator
  2. use fundit::sqlUtilities
  3. use fundit::dataPuller
  4. use fundit::returnCalculator
  5. use fundit::navCalculator
  6. /*
  7. * 将VaR包裹一层,使之成为系统认可的聚集函数
  8. * @param returns <DOUBLE VECTOR>: 非空收益率
  9. * @param method <STRING>: 'normal', 'logNormal', 'historical', 'monteCarlo'
  10. * @param confidenceLevel <DOUBLE>: 置信水平,取值区间(0, 1)
  11. *
  12. */
  13. defg aggVaR(returns, method, confidenceLevel) {
  14. if(returns.form() != 1) return null;
  15. return returns.VaR(method, confidenceLevel);
  16. }
  17. /*
  18. * 将CVaR包裹一层,使之成为系统认可的聚集函数
  19. * @param returns <DOUBLE VECTOR>: 非空收益率
  20. * @param method <STRING>: 'normal', 'logNormal', 'historical', 'monteCarlo'
  21. * @param confidenceLevel <DOUBLE>: 置信水平,取值区间(0, 1)
  22. *
  23. */
  24. defg aggCVaR(returns, method, confidenceLevel) {
  25. if(returns.form() != 1) return null;
  26. return returns.CVaR(method, confidenceLevel);
  27. }
  28. /*
  29. * 最大回撤
  30. *
  31. *
  32. */
  33. defg maxDrawdown(navs) {
  34. return max(1 - navs \ cummax(navs));
  35. }
  36. /*
  37. * 几何平均值
  38. *
  39. */
  40. defg geometricMean(x){
  41. return x.log().avg().exp()
  42. }
  43. /*
  44. * Trailing Monthly Return, Standard Deviation, Skewness, Kurtosis, Max Drawdown, VaR, CVaR, Calmar Ratio
  45. *
  46. * @param entity_info <TABLE>: xxx_information表,NEED COLUMNS entity_id, inception_date
  47. * @param ret <TABLE>: 收益表,需要有 entity_id, price_dat, end_date, nav
  48. * @param trailing_month <STRING>: trailing X month or ytd, incep
  49. *
  50. * NOTE: standard deviation of Java version is noncompliant-GIPS annulized number
  51. *
  52. * Create: 20240904 Joey
  53. * TODO: SQL is wrong for max drawdowns
  54. * TODO: var, cvar, calmar are off; std dev, skewness, kurtosis are slightly off
  55. * TODO: SQL is missing for portfolio since inception date return
  56. * TODO: Java calculates max drawdown even there is no nav
  57. * TODO: Java ytd worst month could be wrong (i.e. portfolio 166002, 2024-03)
  58. * TODO: arith_mean & gerom_mean ARE NOT TESTED
  59. *
  60. */
  61. def cal_basic_performance(entity_info, ret, trailing_month) {
  62. // accumulate 版的 skewness, kurtosis, var, cvar 似乎都不对劲,只好找个笨办法来实现
  63. if(trailing_month == 'incep') {
  64. // 需要至少6个数才计算标准差、峰度、偏度
  65. t0 = SELECT price_date.max() AS price_date, nav, ret,
  66. ret.mean() AS arith_mean, (1+ret).prod().pow(1\count(entity_id))-1 AS geom_mean,
  67. iif(count(entity_id) > 5, std(ret), null) AS std_dev,
  68. iif(count(entity_id) > 5, skew(ret, false), null) AS skewness,
  69. iif(count(entity_id) > 5, kurtosis(ret, false), null)-3 AS kurtosis,
  70. min(ret) AS wrst_month
  71. FROM ret
  72. WHERE ret > -1
  73. GROUP BY entity_id
  74. CGROUP BY end_date
  75. ORDER BY entity_id, end_date;
  76. // 年化收益(给后面计算Calmar用)
  77. t0.addColumn(['trailing_ret', 'trailing_ret_a'], [DOUBLE, DOUBLE]);
  78. // MySQL 有bug导致首月ret_1m为空,所以用 prod(1+ret)-1算的有时不对
  79. UPDATE t0
  80. SET trailing_ret = nav\ini_value - 1,
  81. trailing_ret_a = iif(t0.end_date - ei.inception_date.month() > 12, (nav\ini_value).pow(12\(t0.end_date - ei.inception_date.month())) - 1, nav\ini_value - 1)
  82. FROM ej(t0, entity_info ei, 'entity_id');
  83. // 不会用上面的办法算最大回撤, VaR, CVaR
  84. t_var = SELECT entity_id, end_date, ret,
  85. cummax(1 - nav \ cummax(nav)) AS drawdown,
  86. - cumpercentile(ret, 5, 'linear') AS var
  87. FROM ret WHERE ret > -1
  88. CONTEXT BY entity_id;
  89. t_cvar = SELECT entity_id, end_date, drawdown, var,
  90. - cumavg(iif(ret <= -var, ret, null)) AS cvar
  91. FROM t_var
  92. CONTEXT BY entity_id;
  93. t1 = SELECT t0.*, t_cvar.drawdown, t_cvar.var, t_cvar.cvar
  94. FROM t0 LEFT JOIN t_cvar ON t0.entity_id = t_cvar.entity_id AND t0.end_date = t_cvar.end_date
  95. ORDER BY t0.entity_id, t0.end_date;
  96. } else if(trailing_month == 'ytd') {
  97. t1 = SELECT entity_id, end_date, price_date.cummax() AS price_date, nav, ret,
  98. ret.cumavg() AS arith_mean, (1+ret).cumprod().pow(1\cumcount(entity_id))-1 AS geom_mean,
  99. cumprod(1+ret)-1 AS trailing_ret,
  100. cumprod(1+ret)-1 AS trailing_ret_a, // no need annulization for ytd
  101. iif(cumcount(entity_id) > 5, cumstd(ret), null) AS std_dev,
  102. iif(cumcount(entity_id) > 5, tmoving(skew{, false}, end_date, ret, 12), null) AS skewness,
  103. iif(cumcount(entity_id) > 5, tmoving(kurtosis{, false}, end_date, ret, 12)-3, null) AS kurtosis,
  104. cummin(ret) AS wrst_month,
  105. cummax(1 - nav \ cummax(nav)) AS drawdown
  106. FROM ret WHERE ret > -1
  107. CONTEXT BY entity_id, end_date.year()
  108. ORDER BY entity_id, end_date;
  109. // trailing x month
  110. } else {
  111. // 先转成STRING,避免单字符被认为是CHAR而导致转整型出错的结果
  112. win = trailing_month$STRING$INT;
  113. t1 = SELECT entity_id, end_date, price_date.mmax(win) AS price_date, nav, ret,
  114. ret.mavg(win) AS arith_mean, (1+ret).mprod(win).pow(1\mcount(entity_id, win))-1 AS geom_mean,
  115. mprod(1+ret, win)-1 AS trailing_ret,
  116. iif(win > 12,
  117. mprod(1+ret, win).pow(12\win)-1,
  118. mprod(1+ret, win)-1) AS trailing_ret_a,
  119. mstd(ret, win) AS std_dev,
  120. mskew(ret, win, false) AS skewness,
  121. mkurtosis(ret, win, false) - 3 AS kurtosis,
  122. mmin(ret, win) AS wrst_month,
  123. moving(maxDrawdown, nav, win) AS drawdown,
  124. moving(aggVaR{, 'historical', 0.95}, ret, win) AS var,
  125. moving(aggCVaR{, 'historical', 0.95}, ret, win) AS cvar
  126. FROM ret WHERE ret > -1
  127. CONTEXT BY entity_id
  128. ORDER BY entity_id, end_date;
  129. }
  130. t1.addColumn('calmar', DOUBLE);
  131. UPDATE t1 SET calmar = iif(drawdown == 0, null, trailing_ret_a\drawdown);
  132. return t1;
  133. }
  134. /*
  135. * Lower Partial Moment
  136. * NOTE: risk free rate is used as Minimal Accepted Rate (MAR) here
  137. *
  138. */
  139. def cal_LPM(ret, risk_free, trailing_month) {
  140. t = SELECT *, cumcount(entity_id) AS cnt FROM ret WHERE ret > -1 CONTEXT BY entity_id;
  141. if(trailing_month == 'incep') {
  142. lpm = SELECT entity_id, end_date,
  143. iif(cumcount(end_date) > 5, (cumsum (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\1), null) AS lpm1,
  144. iif(cumcount(end_date) > 5, (cumsum2 (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\2), null) AS lpm2,
  145. iif(cumcount(end_date) > 5, (cumsum3 (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\3), null) AS lpm3
  146. FROM t
  147. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  148. CONTEXT BY entity_id
  149. ORDER BY entity_id, end_date;
  150. } else if(trailing_month == 'ytd') {
  151. lpm = SELECT entity_id, end_date,
  152. iif(cumcount(end_date) > 5, (cumsum (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\1), null) AS lpm1,
  153. iif(cumcount(end_date) > 5, (cumsum2 (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\2), null) AS lpm2,
  154. iif(cumcount(end_date) > 5, (cumsum3 (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ cumcount(end_date)).pow(1\3), null) AS lpm3
  155. FROM t
  156. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  157. CONTEXT BY entity_id, end_date.year()
  158. ORDER BY entity_id, end_date;
  159. } else {
  160. win = trailing_month$STRING$INT;
  161. lpm = SELECT t.entity_id, t.end_date,
  162. (msum (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0), win) \ mcount(end_date, win)).pow(1\1) AS lpm1,
  163. (msum2(iif(rfr.ret > t.ret, rfr.ret - t.ret, 0), win) \ mcount(end_date, win)).pow(1\2) AS lpm2,
  164. (moving(sum3, iif(rfr.ret > t.ret, rfr.ret - t.ret, 0), win) \ mcount(end_date, win)).pow(1\3) AS lpm3
  165. FROM t
  166. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  167. CONTEXT BY t.entity_id
  168. ORDER BY entity_id, end_date;
  169. }
  170. return lpm;
  171. }
  172. /*
  173. * Downside Devision, Omega Ratio, Sortino Ratio, Kappa Ratio
  174. *
  175. * TODO: Java version of Downside Deviation (LPM2) uses cnt-1 as denominator to calculate mean excess return, which might be wrong
  176. * Java version of Omega could be wrong because Java uses annualized returns and cnt-1
  177. * Java'version of Kappa could be very wrong
  178. *
  179. */
  180. def cal_omega_sortino_kappa(ret, risk_free, trailing_month) {
  181. lpm = cal_LPM(ret, risk_free, trailing_month);
  182. if(trailing_month == 'incep') {
  183. tb = SELECT t.entity_id, t.end_date,
  184. l.lpm2 AS ds_dev,
  185. iif(l.lpm1.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm1 + 1) AS omega,
  186. iif(l.lpm2.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm2) AS sortino,
  187. iif(l.lpm3.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm3) AS kappa
  188. FROM ret t
  189. INNER JOIN lpm l ON t.entity_id = l.entity_id AND t.end_date = l.end_date
  190. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  191. WHERE t.ret > -1
  192. CONTEXT BY t.entity_id;
  193. } else if(trailing_month == 'ytd') {
  194. tb = SELECT t.entity_id, t.end_date,
  195. l.lpm2 AS ds_dev,
  196. iif(l.lpm1.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm1 + 1) AS omega,
  197. iif(l.lpm2.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm2) AS sortino,
  198. iif(l.lpm3.round(4) == 0, NULL, (t.ret - rfr.ret ).cumavg() \ l.lpm3) AS kappa
  199. FROM ret t
  200. INNER JOIN lpm l ON t.entity_id = l.entity_id AND t.end_date = l.end_date
  201. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  202. WHERE t.ret > -1
  203. CONTEXT BY t.entity_id, t.end_date.year();
  204. } else {
  205. win = trailing_month$STRING$INT;
  206. tb = SELECT t.entity_id, t.end_date,
  207. l.lpm2 AS ds_dev,
  208. iif(l.lpm1.round(4) == 0, NULL, (t.ret - rfr.ret ).mavg(win) \ l.lpm1 + 1) AS omega,
  209. iif(l.lpm2.round(4) == 0, NULL, (t.ret - rfr.ret ).mavg(win) \ l.lpm2) AS sortino,
  210. iif(l.lpm3.round(4) == 0, NULL, (t.ret - rfr.ret ).mavg(win) \ l.lpm3) AS kappa
  211. FROM ret t
  212. INNER JOIN lpm l ON t.entity_id = l.entity_id AND t.end_date = l.end_date
  213. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  214. WHERE t.ret > -1
  215. CONTEXT BY t.entity_id;
  216. }
  217. return tb;
  218. }
  219. /*
  220. * Winning Ratio, Tracking Error, Information Ratio
  221. *
  222. * NOTE: mcount is very unique in mFun, because it doesn't support minPeriods(BUG?), while others default minPeriods = window.
  223. * As a result, we have to delete records having winrate but no tracking error and info ratio for the sake of consisence
  224. *
  225. * TODO: Win Rate incept is off, because Java incorrectly takes all end_date as denominator even when benchmark has no price
  226. * Information Ratio is way off!
  227. * Not sure how to describe a giant number("inf"), for now 999 is used
  228. */
  229. def cal_benchmark_tracking(ret, benchmarks, bmk_ret, trailing_month) {
  230. if(trailing_month == 'incep') {
  231. t0 = SELECT t.entity_id, t.end_date, t.price_date,
  232. t.ret, bmk.ret AS ret_bmk,
  233. t.entity_id.cumcount() AS cnt,
  234. t.ret - bmk.ret AS exc_ret, bm.benchmark_id
  235. FROM ret t
  236. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  237. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  238. WHERE t.ret > -1
  239. AND bmk.ret > -1
  240. CONTEXT BY t.entity_id, bm.benchmark_id;
  241. t = SELECT entity_id, end_date, benchmark_id,
  242. iif(cnt > 5, cumcount(iif(exc_ret >= 0, 1, null)) \ cnt, null) AS winrate,
  243. iif(cnt > 5, exc_ret.cumstd(), null) AS track_error,
  244. iif(cnt > 5, iif(exc_ret.cumstd() == 0, null, exc_ret.cumavg() \ exc_ret.cumstd()), 5) AS info
  245. FROM t0
  246. CONTEXT BY entity_id, benchmark_id
  247. ORDER BY entity_id, end_date, benchmark_id;
  248. } else if(trailing_month == 'ytd') {
  249. t0 = SELECT t.entity_id, t.end_date, t.price_date,
  250. t.ret, bmk.ret AS ret_bmk,
  251. t.entity_id.cumcount() AS cnt, t.ret - bmk.ret AS exc_ret, bm.benchmark_id
  252. FROM ret t
  253. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  254. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  255. WHERE t.ret > -1
  256. AND bmk.ret > -1
  257. CONTEXT BY t.entity_id, bm.benchmark_id, t.end_date.year();
  258. t = SELECT entity_id, end_date, benchmark_id,
  259. iif(cnt > 5, cumcount(iif(exc_ret >= 0, 1, null)) \ cnt, null) AS winrate,
  260. iif(cnt > 5, exc_ret.cumstd(), null) AS track_error,
  261. iif(cnt > 5, iif(exc_ret.cumstd() == 0, null, exc_ret.cumavg() \ exc_ret.cumstd()), null) AS info
  262. FROM t0
  263. CONTEXT BY entity_id, benchmark_id, end_date.year()
  264. ORDER BY entity_id, end_date, benchmark_id;
  265. } else {
  266. win = trailing_month$STRING$INT;
  267. t0 = SELECT t.entity_id, t.end_date, t.price_date,
  268. t.ret, bmk.ret AS ret_bmk,
  269. t.entity_id.mcount(win) AS cnt,
  270. t.ret - bmk.ret AS exc_ret, bm.benchmark_id
  271. FROM ret t
  272. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  273. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  274. WHERE t.ret > -1
  275. AND bmk.ret > -1
  276. CONTEXT BY t.entity_id, bm.benchmark_id;
  277. t = SELECT entity_id, end_date, benchmark_id,
  278. iif(cnt > 5, mcount(iif(exc_ret >= 0, 1, null), win) \ cnt, null) AS winrate,
  279. iif(cnt > 5, mstd(exc_ret, win), null) AS track_error,
  280. iif(cnt > 5, iif(mstd(exc_ret, win) == 0, null, mavg(exc_ret, win) \ mstd(exc_ret, win)), null) AS info
  281. FROM t0
  282. CONTEXT BY entity_id, benchmark_id
  283. ORDER BY entity_id, end_date, benchmark_id;
  284. }
  285. return t; //SELECT * FROM t WHERE track_error IS NOT NULL;
  286. }
  287. /*
  288. * Alpha & Beta
  289. * NOTE: alpha of Java version is wrong because it doesn't use risk free rate
  290. */
  291. def cal_alpha_beta(ret, benchmarks, bmk_ret, risk_free, trailing_month) {
  292. t = SELECT t.entity_id, t.end_date, t.ret, bm.benchmark_id, bmk.ret AS ret_bmk
  293. FROM ret t
  294. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  295. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  296. WHERE t.ret > -1
  297. AND bmk.ret > -1;
  298. if(trailing_month == 'incep') {
  299. beta = SELECT entity_id, end_date, benchmark_id,
  300. iif(cumcount(end_date) > 5, ret.cumbeta(ret_bmk), null) AS beta
  301. FROM t CONTEXT BY entity_id, benchmark_id;
  302. alpha = SELECT t.entity_id, t.end_date, t.benchmark_id, beta.beta AS beta,
  303. (t.ret - rfr.ret).cumavg() - beta.beta * (t.ret_bmk - rfr.ret).cumavg() AS alpha
  304. FROM t
  305. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.benchmark_id = beta.benchmark_id AND t.end_date = beta.end_date
  306. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  307. CONTEXT BY t.entity_id, t.benchmark_id
  308. ORDER BY t.entity_id, t.end_date, t.benchmark_id;
  309. } else if(trailing_month == 'ytd') {
  310. beta = SELECT entity_id, end_date, benchmark_id,
  311. iif(cumcount(end_date) > 5, ret.cumbeta(ret_bmk), null) AS beta
  312. FROM t CONTEXT BY entity_id, benchmark_id, end_date.year();
  313. alpha = SELECT t.entity_id, t.end_date, t.benchmark_id, beta.beta AS beta,
  314. (t.ret - rfr.ret).cumavg() - beta.beta * (t.ret_bmk - rfr.ret).cumavg() AS alpha
  315. FROM t
  316. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.benchmark_id = beta.benchmark_id AND t.end_date = beta.end_date
  317. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  318. CONTEXT BY t.entity_id, t.benchmark_id, t.end_date.year()
  319. ORDER BY t.entity_id, t.end_date, t.benchmark_id;
  320. } else {
  321. win = trailing_month$STRING$INT;
  322. beta = SELECT entity_id, end_date, benchmark_id,
  323. iif(mcount(end_date, win) > 5, ret.mbeta(ret_bmk, win), null) AS beta
  324. FROM t CONTEXT BY entity_id, benchmark_id;
  325. alpha = SELECT t.entity_id, t.end_date, t.benchmark_id, beta.beta AS beta,
  326. (t.ret - rfr.ret).mavg(win) - beta.beta * (t.ret_bmk - rfr.ret).mavg(win) AS alpha
  327. FROM t
  328. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.benchmark_id = beta.benchmark_id AND t.end_date = beta.end_date
  329. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  330. CONTEXT BY t.entity_id, t.benchmark_id
  331. ORDER BY t.entity_id, t.end_date, t.benchmark_id;
  332. }
  333. return alpha;
  334. }
  335. /*
  336. * Upside/Down Capture Return/Ratio
  337. *
  338. * TODO: trailing x month values are way off!
  339. *
  340. */
  341. def cal_capture_ratio(ret, benchmarks, bmk_ret, trailing_month) {
  342. if(trailing_month == 'incep') {
  343. t1 = SELECT t.entity_id, t.end_date,
  344. (1 + iif(bmk.ret >= 0, t.ret, 0)).cumprod() AS upside_ret,
  345. (1 + iif(bmk.ret >= 0, bmk.ret, 0)).cumprod() AS bmk_upside_ret,
  346. cumcount(iif(bmk.ret >= 0, 1, null)) AS bmk_upside_cnt,
  347. (1 + iif(bmk.ret < 0, t.ret, 0)).cumprod() AS downside_ret,
  348. (1 + iif(bmk.ret < 0, bmk.ret, 0)).cumprod() AS bmk_downside_ret,
  349. cumcount(iif(bmk.ret < 0, 1, null)) AS bmk_downside_cnt,
  350. bm.benchmark_id
  351. FROM ret t
  352. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  353. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id AND t.end_date = bmk.end_date
  354. WHERE t.ret > -1
  355. AND bmk.ret > -1
  356. CONTEXT BY t.entity_id, bm.benchmark_id;
  357. } else if(trailing_month == 'ytd') {
  358. t1 = SELECT t.entity_id, t.end_date,
  359. (1 + iif(bmk.ret >= 0, t.ret, 0)).cumprod() AS upside_ret,
  360. (1 + iif(bmk.ret >= 0, bmk.ret, 0)).cumprod() AS bmk_upside_ret,
  361. cumcount(iif(bmk.ret >= 0, 1, null)) AS bmk_upside_cnt,
  362. (1 + iif(bmk.ret < 0, t.ret, 0)).cumprod() AS downside_ret,
  363. (1 + iif(bmk.ret < 0, bmk.ret, 0)).cumprod() AS bmk_downside_ret,
  364. cumcount(iif(bmk.ret < 0, 1, null)) AS bmk_downside_cnt,
  365. bm.benchmark_id
  366. FROM ret t
  367. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  368. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id AND t.end_date = bmk.end_date
  369. WHERE t.ret > -1
  370. AND bmk.ret > -1
  371. CONTEXT BY t.entity_id, bm.benchmark_id, t.end_date.year();
  372. } else {
  373. win = trailing_month$STRING$INT;
  374. t1 = SELECT t.entity_id, t.end_date,
  375. (1 + iif(bmk.ret >= 0, t.ret, 0)).mprod(win) AS upside_ret,
  376. (1 + iif(bmk.ret >= 0, bmk.ret, 0)).mprod(win) AS bmk_upside_ret,
  377. mcount(iif(bmk.ret >= 0, 1, null), win) AS bmk_upside_cnt,
  378. (1 + iif(bmk.ret < 0, t.ret, 0)).mprod(win) AS downside_ret,
  379. (1 + iif(bmk.ret < 0, bmk.ret, 0)).mprod(win) AS bmk_downside_ret,
  380. mcount(iif(bmk.ret < 0, 1, null), win) AS bmk_downside_cnt,
  381. bm.benchmark_id
  382. FROM ret t
  383. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  384. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id AND t.end_date = bmk.end_date
  385. WHERE t.ret > -1
  386. AND bmk.ret > -1
  387. CONTEXT BY t.entity_id, bm.benchmark_id;
  388. }
  389. t = SELECT entity_id, end_date, benchmark_id,
  390. iif(t1.bmk_upside_cnt == 0, NULL, t1.upside_ret.pow(1 \ t1.bmk_upside_cnt)-1) AS upside_capture_ret,
  391. iif(t1.bmk_upside_cnt == 0, NULL, (t1.upside_ret.pow(1 \ t1.bmk_upside_cnt)-1)/(t1.bmk_upside_ret.pow(1 \ t1.bmk_upside_cnt)-1)) AS upside_capture_ratio,
  392. iif(t1.bmk_downside_cnt == 0, NULL, t1.downside_ret.pow(1 \ t1.bmk_downside_cnt)-1) AS downside_capture_ret,
  393. iif(t1.bmk_downside_cnt == 0, NULL, (t1.downside_ret.pow(1 \ t1.bmk_downside_cnt)-1)/(t1.bmk_downside_ret.pow(1 \ t1.bmk_downside_cnt)-1)) AS downside_capture_ratio
  394. FROM t1
  395. ORDER BY entity_id, benchmark_id, end_date;
  396. return t;
  397. }
  398. /*
  399. * Sharpe Ratio
  400. * NOTE: Java version is noncompliant-GIPS annulized number
  401. */
  402. def cal_sharpe(ret, std_dev, risk_free, trailing_month) {
  403. if(trailing_month == 'incep') {
  404. sharpe = SELECT t.entity_id, t.end_date, (t.ret - rfr.ret).cumavg() \ std.std_dev AS sharpe
  405. FROM ret t
  406. INNER JOIN std_dev std ON t.entity_id = std.entity_id AND t.end_date = std.end_date
  407. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  408. WHERE std.std_dev.round(4) <> 0 AND t.ret > -1
  409. CONTEXT BY t.entity_id;
  410. } else if(trailing_month == 'ytd') {
  411. sharpe = SELECT t.entity_id, t.end_date, (t.ret - rfr.ret).cumavg() \ std.std_dev AS sharpe
  412. FROM ret t
  413. INNER JOIN std_dev std ON t.entity_id = std.entity_id AND t.end_date = std.end_date
  414. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  415. WHERE std.std_dev.round(4) <> 0 AND t.ret > -1
  416. CONTEXT BY t.entity_id, t.end_date.year();
  417. } else {
  418. win = trailing_month$STRING$INT;
  419. sharpe = SELECT t.entity_id, t.end_date, (t.ret - rfr.ret).mavg(win) \ std.std_dev AS sharpe
  420. FROM ret t
  421. INNER JOIN std_dev std ON t.entity_id = std.entity_id AND t.end_date = std.end_date
  422. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  423. WHERE std.std_dev.round(4) <> 0 AND t.ret > -1
  424. CONTEXT BY t.entity_id;
  425. }
  426. return sharpe;
  427. }
  428. /*
  429. * Treynor Ratio = annulized excess return / beta
  430. *
  431. * TODO: ytd is off because Java uses non-GIPS rule to annulize return
  432. */
  433. def cal_treynor(ret, risk_free, beta, trailing_month) {
  434. if(trailing_month == 'incep') {
  435. t = SELECT *, cumcount(entity_id) AS cnt
  436. FROM ret t
  437. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  438. WHERE t.ret > -1
  439. AND rfr.ret > -1
  440. CONTEXT BY t.entity_id;
  441. treynor = SELECT t.entity_id, t.end_date, beta.benchmark_id,
  442. iif(beta.beta.round(4) == 0, NULL,
  443. ((1 + t.ret).cumprod().pow(12\iif(t.cnt<12, 12, t.cnt)) - (1 + t.rfr_ret).cumprod().pow(12\iif(t.cnt<12, 12, t.cnt))) \ beta.beta) AS treynor
  444. FROM t
  445. INNER JOIN beta AS beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  446. CONTEXT BY t.entity_id, beta.benchmark_id;
  447. } else if(trailing_month == 'ytd') {
  448. t = SELECT *, cumcount(entity_id) AS cnt
  449. FROM ret t
  450. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  451. WHERE t.ret > -1
  452. AND rfr.ret > -1
  453. CONTEXT BY t.entity_id, t.end_date.year();
  454. treynor = SELECT t.entity_id, t.end_date, beta.benchmark_id,
  455. iif(beta.beta.round(4) == 0, NULL,
  456. ((1 + t.ret).cumprod().pow(12\iif(t.cnt<12, 12, t.cnt)) - (1 + t.rfr_ret).cumprod().pow(12\iif(t.cnt<12, 12, t.cnt))) \ beta.beta) AS treynor
  457. FROM t
  458. INNER JOIN beta AS beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  459. CONTEXT BY t.entity_id, beta.benchmark_id, t.end_date.year();
  460. } else {
  461. win = trailing_month$STRING$INT;
  462. t = SELECT *, mcount(entity_id, win) AS cnt
  463. FROM ret t
  464. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  465. WHERE t.ret > -1
  466. AND rfr.ret > -1
  467. CONTEXT BY t.entity_id;
  468. treynor = SELECT t.entity_id, t.end_date, beta.benchmark_id,
  469. iif(beta.beta.round(4) == 0, NULL,
  470. ((1 + t.ret).mprod(win).pow(12\iif(t.cnt<12, 12, t.cnt)) - (1 + t.rfr_ret).mprod(win).pow(12\iif(t.cnt<12, 12, t.cnt))) \ beta.beta) AS treynor
  471. FROM t
  472. INNER JOIN beta AS beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  473. CONTEXT BY t.entity_id, beta.benchmark_id;
  474. }
  475. return treynor;
  476. }
  477. /*
  478. * Jensen's Alpha
  479. * TODO: the result is slightly off
  480. */
  481. def cal_jensen(ret, bmk_ret, risk_free, beta, trailing_month) {
  482. if(trailing_month == 'incep') {
  483. jensen = SELECT t.entity_id, t.end_date, t.ret.cumavg() - rfr.ret.cumavg() - beta.beta * (bmk.ret.cumavg() - rfr.ret.cumavg()) AS jensen, beta.benchmark_id
  484. FROM ret t
  485. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  486. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND beta.benchmark_id = bmk.benchmark_id
  487. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  488. WHERE t.ret > -1
  489. CONTEXT BY t.entity_id, beta.benchmark_id;
  490. } else if(trailing_month == 'ytd') {
  491. jensen = SELECT t.entity_id, t.end_date, t.ret.cumavg() - rfr.ret.cumavg() - beta.beta * (bmk.ret.cumavg() - rfr.ret.cumavg()) AS jensen, beta.benchmark_id
  492. FROM ret t
  493. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  494. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND beta.benchmark_id = bmk.benchmark_id
  495. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  496. WHERE t.ret > -1
  497. CONTEXT BY t.entity_id, beta.benchmark_id, t.end_date.year();
  498. } else {
  499. win = trailing_month$STRING$INT;
  500. jensen = SELECT t.entity_id, t.end_date, t.ret.mavg(win) - rfr.ret.mavg(win) - beta.beta * (bmk.ret.mavg(win) - rfr.ret.mavg(win)) AS jensen, beta.benchmark_id
  501. FROM ret t
  502. INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
  503. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND beta.benchmark_id = bmk.benchmark_id
  504. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  505. WHERE t.ret > -1
  506. CONTEXT BY t.entity_id, beta.benchmark_id;
  507. }
  508. return jensen;
  509. }
  510. /*
  511. * Modigliani Modigliani Measure (M2)
  512. * NOTE: M2 = sharpe * std(benchmark) + risk_free_rate
  513. * NOTE: Java version is noncompliant-GIPS annulized number
  514. */
  515. def cal_m2(ret, benchmarks, bmk_ret, risk_free, trailing_month) {
  516. if(trailing_month == 'incep') {
  517. m2 = SELECT t.entity_id, t.end_date,
  518. iif(t.entity_id.cumcount() > 5,
  519. iif(t.ret.cumstd().round(4) == 0, NULL, (t.ret - rfr.ret).cumavg() \ t.ret.cumstd() * bmk.ret.cumstd() + rfr.ret.cumavg()),
  520. NULL) AS m2, bm.benchmark_id
  521. FROM ret t
  522. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  523. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  524. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  525. WHERE t.ret > -1
  526. CONTEXT BY t.entity_id, bm.benchmark_id;
  527. } else if(trailing_month == 'ytd') {
  528. m2 = SELECT t.entity_id, t.end_date,
  529. iif(t.entity_id.cumcount() > 5,
  530. iif(t.ret.cumstd().round(4) == 0, NULL, (t.ret - rfr.ret).cumavg() \ t.ret.cumstd() * bmk.ret.cumstd() + rfr.ret.cumavg()),
  531. NULL) AS m2, bm.benchmark_id
  532. FROM ret t
  533. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  534. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  535. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  536. WHERE t.ret > -1
  537. CONTEXT BY t.entity_id, bm.benchmark_id, t.end_date.year();
  538. } else {
  539. win = trailing_month$STRING$INT;
  540. m2 = SELECT t.entity_id, t.end_date,
  541. iif(t.entity_id.mcount(win) > 5,
  542. iif(t.ret.mstd(win) == 0, NULL, (t.ret - rfr.ret).mavg(win) \ t.ret.mstd(win) * bmk.ret.mstd(win) + rfr.ret.mavg(win)),
  543. NULL) AS m2, bm.benchmark_id
  544. FROM ret t
  545. INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
  546. INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
  547. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  548. WHERE t.ret > -1
  549. CONTEXT BY t.entity_id, bm.benchmark_id;
  550. }
  551. return m2;
  552. }
  553. /*
  554. * Morningstar Return, Morningstar Risk-Adjusted Return
  555. *
  556. * TODO: Tax and loads are NOT taken care of
  557. * TODO: Assume Chinese methodology using 3, 5, 10 as number of traling years
  558. * TODO: need verify with reliable results
  559. *
  560. * NOTE: Morningstar methodology requires monthly return for calculation, so that "12" is hard-coded here
  561. *
  562. *
  563. */
  564. def cal_ms_return(ret, risk_free, trailing_month) {
  565. win = trailing_month$STRING$INT;
  566. r = SELECT t.entity_id, t.end_date,
  567. iif(t.end_date.mmax(win) == t.end_date.mmin(win), NULL,
  568. ((1 + t.ret)\(1 + rfr.ret)).mprod(win).pow(12\(t.end_date.mmax(win) - t.end_date.mmin(win)))-1) AS ms_ret_a,
  569. (1 + t.ret).pow(-2).mavg(win).pow(-12/2)-1 AS ms_rar_a
  570. FROM ret t
  571. INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
  572. WHERE t.ret > -1
  573. CONTEXT BY t.entity_id;
  574. return r;
  575. }
  576. /*
  577. * 有效主体-基准对应表
  578. *
  579. * @param benchmarks <TABLE>: entity-benchmark 的对应关系表 NEED COLUMNS: entity_id, end_date, benchmark_id
  580. * @param end_day <DATE>:
  581. * @param trailing_month <STRING>:
  582. * @param isEffectiveOnly <BOOL>: false时与Java相同; true:多了个限制条件:如果区间内有效基准数少于1/2,不做计算
  583. * 比如过去12个月中某BFI只出现2次,小于需要的6次,此BFI不参与 trailing 1 year 计算
  584. *
  585. */
  586. def get_effective_benchmarks(benchmarks, end_day, trailing_month, isEffectiveOnly) {
  587. min_pct = 0.5;
  588. if(isEffectiveOnly) {
  589. t_dates = SELECT DISTINCT entity_id, end_date FROM benchmarks WHERE end_date <= end_day.month();
  590. if(trailing_month == 'incep') {
  591. t = SELECT entity_id, end_date, end_date.cumcount() AS cnt FROM t_dates CONTEXT BY entity_id;
  592. bmk = SELECT bmk.* FROM benchmarks bmk
  593. INNER JOIN t ON bmk.entity_id = t.entity_id AND bmk.end_date = t.end_date
  594. CONTEXT BY bmk.entity_id, bmk.benchmark_id
  595. HAVING bmk.end_date.cumcount() >= t.cnt * min_pct;
  596. } else if(trailing_month == 'ytd') {
  597. t = SELECT entity_id, end_date, end_date.cumcount() AS cnt FROM t_dates CONTEXT BY entity_id, end_date.year();
  598. bmk = SELECT bmk.* FROM benchmarks bmk
  599. INNER JOIN t ON bmk.entity_id = t.entity_id AND bmk.end_date = t.end_date
  600. CONTEXT BY entity_id, benchmark_id, end_date.year()
  601. HAVING bmk.end_date.cumcount() >= t.cnt * min_pct;
  602. } else {
  603. win = trailing_month$STRING$INT;
  604. t = SELECT entity_id, end_date, end_date.mcount(win) AS cnt FROM t_dates CONTEXT BY entity_id;
  605. bmk = SELECT bmk.* FROM benchmarks bmk
  606. INNER JOIN t ON bmk.entity_id = t.entity_id AND bmk.end_date = t.end_date
  607. CONTEXT BY entity_id, benchmark_id
  608. HAVING bmk.end_date.mcount(win) >= t.cnt * min_pct;
  609. }
  610. } else {
  611. bmk = SELECT * FROM benchmarks WHERE end_date <= end_day.month();
  612. }
  613. return bmk;
  614. }
  615. /*
  616. * Calculation for monthly indicators which need benchmark
  617. *
  618. * @param entity_info <TABLE>: xxx_information表,NEED COLUMNS entity_id, inception_date
  619. * @param benchmark_mapping <TABLE>: entity-benchmark mapping table, NEED COLUMNS entity_id, end_date, benchmark_id
  620. * @param end_day <DATE>;
  621. * @param tb_ret <TABLE>: 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
  622. * @param index_ret <TABLE>: historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
  623. * @param risk_free <TABLE>: historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
  624. * @param month <INT>: trailing x month
  625. *
  626. * @return: indicators table
  627. *
  628. *
  629. * Create 20240904 模仿Java & python代码在Dolphin中实现,具体计算逻辑可能会有不同 Joey
  630. * TODO: some datapoints require more data, we need a way to disable calculation for them
  631. *
  632. */
  633. def cal_indicators_with_benchmark(entity_info, benchmark_mapping, end_day, tb_ret, index_ret, risk_free, month) {
  634. if(entity_info.isVoid() || entity_info.size() == 0 || benchmark_mapping.isVoid() || benchmark_mapping.size() == 0 ) return null;
  635. if(tb_ret.isVoid() || tb_ret.size() == 0 || index_ret.isVoid() || index_ret.size() == 0 || risk_free.isVoid() || risk_free.size() == 0 ) return null;
  636. // sorting for correct first() and last() value
  637. ret = SELECT * FROM tb_ret WHERE ret > -1 AND end_date <= end_day.month() ORDER BY entity_id, price_date;
  638. // get the effective benchmarks
  639. benchmarks = get_effective_benchmarks(benchmark_mapping, end_day, month, true);
  640. if(ret.isVoid() || ret.size() == 0 || benchmarks.isVoid() || benchmarks.size() == 0) return null;
  641. // alpha, beta
  642. alpha_beta = cal_alpha_beta(ret, benchmarks, index_ret, risk_free, month);
  643. // 胜率、跟踪误差、信息比率
  644. bmk_tracking = cal_benchmark_tracking(ret, benchmarks, index_ret, month);
  645. // 特雷诺
  646. treynor = cal_treynor(ret, risk_free, alpha_beta, month);
  647. // 詹森指数
  648. jensen = cal_jensen(ret, index_ret, risk_free, alpha_beta, month);
  649. // M2
  650. m2 = cal_m2(ret, benchmarks, index_ret, risk_free, month);
  651. // 上下行捕获率、收益
  652. capture_r = cal_capture_ratio(ret, benchmarks, index_ret, month);
  653. r = SELECT * FROM bmk_tracking a1
  654. LEFT JOIN alpha_beta ON a1.entity_id = alpha_beta.entity_id AND a1.benchmark_id = alpha_beta.benchmark_id AND a1.end_date = alpha_beta.end_date
  655. LEFT JOIN treynor ON a1.entity_id = treynor.entity_id AND a1.benchmark_id = treynor.benchmark_id AND a1.end_date = treynor.end_date
  656. LEFT JOIN jensen ON a1.entity_id = jensen.entity_id AND a1.benchmark_id = jensen.benchmark_id AND a1.end_date = jensen.end_date
  657. LEFT JOIN m2 ON a1.entity_id = m2.entity_id AND a1.benchmark_id = m2.benchmark_id AND a1.end_date = m2.end_date
  658. LEFT JOIN capture_r ON a1.entity_id = capture_r.entity_id AND a1.benchmark_id = capture_r.benchmark_id AND a1.end_date = capture_r.end_date;
  659. // 年化各数据点
  660. // GIPS RULE: NO annulization for data less than 1 year
  661. plainAnnu = get_annulization_multiple('m');
  662. sqrtAnnu = sqrt(get_annulization_multiple('m'));
  663. r.addColumn(['alpha_a', 'jensen_a', 'track_error_a', 'info_a', 'm2_a'],
  664. [DOUBLE, DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
  665. UPDATE r
  666. SET alpha_a = alpha * iif(end_date - inception_date.month() > 12, plainAnnu, 1),
  667. jensen_a = jensen * iif(end_date - inception_date.month() > 12, plainAnnu, 1),
  668. track_error_a = track_error * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1),
  669. info_a = info * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1),
  670. m2_a = m2 * iif(end_date - inception_date.month() > 12, plainAnnu, 1)
  671. FROM ej(r, entity_info, 'entity_id');
  672. return r;
  673. }
  674. /*
  675. * Monthly standard indicator calculation
  676. *
  677. * @param entity_info <TABLE>:
  678. * @param benchmarks <TABLE>: entity-benchmark mapping table
  679. * @param end_day <DATE>:
  680. * @param tb_ret <TABLE>: 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
  681. * @param benchmark_ret <TABLE>: historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
  682. * @param risk_free <TABLE>: historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
  683. * @param month <STRING>:
  684. *
  685. * @return: indicators table
  686. *
  687. *
  688. * Create 20240904 模仿Java & python代码在Dolphin中实现,具体计算逻辑可能会有不同 Joey
  689. *
  690. */
  691. def cal_indicators(entity_info, benchmarks, end_day, tb_ret, benchmark_ret, risk_free, month) {
  692. if(entity_info.isVoid() || entity_info.size() == 0 || benchmarks.isVoid() || benchmarks.size() == 0 ) return null;
  693. if(tb_ret.isVoid() || tb_ret.size() == 0 || benchmark_ret.isVoid() || benchmark_ret.size() == 0 || risk_free.isVoid() || risk_free.size() == 0 ) return null;
  694. // sorting for correct first() and last() value
  695. ret = SELECT * FROM tb_ret WHERE end_date <= end_day.month() ORDER BY entity_id, price_date;
  696. // 收益、标准差、偏度、峰度、最大回撤、VaR, CVaR、卡玛比率
  697. rtn = cal_basic_performance(entity_info, ret, month);
  698. // 夏普
  699. sharpe = cal_sharpe(ret, rtn, risk_free, month);
  700. // 整合后的下行标准差、欧米伽、索提诺、卡帕
  701. lpms = cal_omega_sortino_kappa(ret, risk_free, month);
  702. // 需要基准的指标们
  703. indicator_with_benchmark = cal_indicators_with_benchmark(entity_info, benchmarks, end_day, ret, benchmark_ret, risk_free, month);
  704. r = SELECT * FROM rtn a1
  705. LEFT JOIN sharpe ON a1.entity_id = sharpe.entity_id AND a1.end_date = sharpe.end_date
  706. LEFT JOIN lpms ON a1.entity_id = lpms.entity_id AND a1.end_date = lpms.end_date
  707. LEFT JOIN indicator_with_benchmark bmk ON a1.entity_id = bmk.entity_id AND a1.end_date = bmk.end_date;
  708. // 晨星收益和风险
  709. if(month$STRING in ['36', '60', '120']) {
  710. ms = cal_ms_return(ret, risk_free, month);
  711. r = SELECT * FROM r LEFT JOIN ms ON r.entity_id = ms.entity_id AND r.end_date = ms.end_date;
  712. }
  713. // 年化各数据点
  714. // GIPS RULE: NO annulization for data less than 1 year
  715. plainAnnu = get_annulization_multiple('m');
  716. sqrtAnnu = sqrt(get_annulization_multiple('m'));
  717. r.addColumn(['std_dev_a', 'ds_dev_a', 'sharpe_a', 'sortino_a'],
  718. [DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
  719. UPDATE r
  720. SET std_dev_a = std_dev * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1),
  721. ds_dev_a = ds_dev * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1),
  722. sharpe_a = sharpe * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1),
  723. sortino_a = sortino * iif(end_date - inception_date.month() > 12, sqrtAnnu, 1)
  724. FROM ej(r, entity_info, 'entity_id');
  725. return r;
  726. }
  727. /*
  728. * Calculate trailing 3m, 6m, ytd, 1y, 2y, 3y, 4y, 5y, 10y and since inception datapoints
  729. *
  730. * @param: func <FUNCTION>: the calculation function
  731. * @param: entity_info <TABLE>: basic information of entity, NEED COLUMNS entity_id, inception_date
  732. * @param benchmarks <TABLE>: entity-benchmark mapping table
  733. * @param: end_day <DATE>: 计算截止日期
  734. * @param: ret <TABLE>: 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
  735. * @param bmk_ret <TABLE>: historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
  736. * @param risk_free <TABLE>: historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
  737. *
  738. *
  739. */
  740. def cal_trailing(func, entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate ) {
  741. r_incep = null;
  742. r_ytd = null;
  743. r_3m = null;
  744. r_6m = null;
  745. r_1y = null;
  746. r_2y = null;
  747. r_3y = null;
  748. r_4y = null;
  749. r_5y = null;
  750. r_10y = null;
  751. // incep
  752. r_incep = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, 'incep');
  753. // ytd
  754. r_ytd = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, 'ytd');
  755. // 3m 只需要支持收益计算
  756. r_3m = cal_basic_performance(entity_info, tb_ret, '3');
  757. // 6m
  758. r_6m = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '6');
  759. // 1y
  760. r_1y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '12');
  761. // 2y
  762. r_2y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '24');
  763. // 3y
  764. r_3y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '36');
  765. // 4y
  766. r_4y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '48');
  767. // 5y
  768. r_5y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '60');
  769. // 10y
  770. r_10y = func(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate, '120');
  771. return r_incep, r_ytd, r_3m, r_6m, r_1y, r_2y, r_3y, r_4y, r_5y, r_10y;
  772. }
  773. /*
  774. * Calculate trailing ytd, 3m, 6m, 1y, 2y, 3y, 4y, 5y, 10y and since inception standard indicators
  775. *
  776. * @param: entity_info <TABLE>: basic information of entity, NEED COLUMNS entity_id, inception_date
  777. * @param benchmarks <TABLE>: entity-benchmark mapping table
  778. * @param: ret <TABLE>: 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
  779. * @param: end_day <DATE>: 计算截止日期
  780. * @param bmk_ret <TABLE>: historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
  781. * @param risk_free <TABLE>: historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
  782. *
  783. */
  784. def cal_trailing_indicators(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate) {
  785. return cal_trailing(cal_indicators, entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate);
  786. }
  787. /*
  788. * Calculate trailing ytd, 3m, 6m, 1y, 2y, 3y, 4y, 5y, 10y and since inception bfi indicators
  789. *
  790. * @param: entity_info <TABLE>: basic information of entity, NEED COLUMNS entity_id, inception_date
  791. * @param benchmarks <TABLE>: entity-benchmark mapping table
  792. * @param: ret <TABLE>: 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
  793. * @param: end_day <DATE>: 计算截止日期
  794. * @param bmk_ret <TABLE>: historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
  795. * @param risk_free <TABLE>: historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
  796. *
  797. * NOTE: 3m 的所有指标没有意义
  798. *
  799. *
  800. */
  801. def cal_trailing_bfi_indicators(entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate) {
  802. return cal_trailing(cal_indicators_with_benchmark, entity_info, benchmarks, end_day, tb_ret, bmk_ret, risk_free_rate);
  803. }
  804. /*
  805. * 通用月度指标计算
  806. *
  807. * @param entity_type <STRING>:
  808. * @param indicator_type <STRING>: PBI, BFI
  809. * @param monthly_returns <TABLE>: NEED COLUMN: entity_id, end_date, price_date, nav, ret
  810. *
  811. * @return <DICT TABLE>: ['PBI-INCEP', 'PBI-YTD', 'PBI-3M', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y']
  812. *
  813. */
  814. def cal_monthly_indicators(entity_type, indicator_type, monthly_returns) {
  815. if(find(['MF', 'HF', 'PF', 'MI', 'FI'], entity_type) < 0) return null;
  816. if(monthly_returns.isVoid() || monthly_returns.size() < 1) return null;
  817. oldest_date = EXEC price_date.min() FROM monthly_returns;
  818. v_entity_ids = EXEC DISTINCT entity_id FROM monthly_returns;
  819. entity_info = get_entity_info(entity_type, v_entity_ids);
  820. if(entity_info.isVoid() || entity_info.size() == 0) { return null };
  821. end_day = today();
  822. // 取基金和基准的对照表
  823. if(indicator_type == 'BFI') {
  824. benchmark = SELECT fund_id AS entity_id, end_date.temporalParse('yyyy-MM') AS end_date, factor_id AS benchmark_id
  825. FROM get_fund_bfi_factors(v_entity_ids, oldest_date.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
  826. } else {
  827. // 主基准, 对应 xxx_info 中的 primary_benchmark_id
  828. benchmark = SELECT entity_id, end_date, iif(benchmark_id.isNull(), 'IN00000008', benchmark_id) AS benchmark_id
  829. FROM get_entity_primary_benchmark(entity_type, v_entity_ids, oldest_date.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM')) ;
  830. }
  831. // 取所有出现的基准月收益
  832. bmk_ret = get_benchmark_return(benchmark, end_day);
  833. if(bmk_ret.isVoid() || bmk_ret.size() == 0) { return null; }
  834. // TODO: risk free指数月收益存在fund_performance表,所以先将就用 fund_id 表示。之后统一改为更准确的名字
  835. risk_free_rate = SELECT entity_id AS fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(oldest_date, end_day);
  836. if(risk_free_rate.isVoid() || risk_free_rate.size() == 0) { return null; }
  837. // 指标计算
  838. if(indicator_type == 'BFI') {
  839. t0 = cal_trailing_bfi_indicators(entity_info, benchmark, end_day, monthly_returns, bmk_ret, risk_free_rate);
  840. v_table_name = ['BFI-INCEP', 'BFI-YTD', 'BFI-3M', 'BFI-6M', 'BFI-1Y', 'BFI-2Y', 'BFI-3Y', 'BFI-4Y', 'BFI-5Y', 'BFI-10Y'];
  841. } else {
  842. t0 = cal_trailing_indicators(entity_info, benchmark, end_day, monthly_returns, bmk_ret, risk_free_rate);
  843. v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-3M', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
  844. }
  845. return dict(v_table_name, t0);
  846. }
  847. /*
  848. * Calculate historcial fund trailing indicators
  849. *
  850. * @param entity_type <STRING>: MF, HF
  851. * @param fund_ids <STRING>: 逗号和单引号分隔的fund_id
  852. * @param end_day <DATE>: 要计算的日期
  853. * @param isFromNav <BOOL>: 用净值实时计算还是从表中取月收益
  854. * @param isFromSQL <BOOL>: TODO: 从MySQL还是本地DolphinDB取净值/收益数据
  855. *
  856. * @return <DICT TABLE>: ['PBI-INCEP', 'PBI-YTD', 'PBI-3M', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y', 'MS-3Y', 'MS-5Y', 'MS-10Y']
  857. *
  858. *
  859. * Example: cal_fund_indicators('HF', "'HF000004KN','HF000103EU','HF00018WXG'", 2024.06.28, true);
  860. *
  861. */
  862. def cal_fund_indicators(entity_type, fund_ids, end_day, isFromNav) {
  863. very_old_date = 1990.01.01;
  864. if(isFromNav == true) {
  865. // 从净值开始计算收益
  866. tb_ret = SELECT * FROM cal_fund_monthly_returns(entity_type, fund_ids, true) WHERE price_date <= end_day;
  867. tb_ret.rename!(['fund_id', 'cumulative_nav'], ['entity_id', 'nav']);
  868. } else {
  869. // 从fund_performance表里读月收益
  870. tb_ret = get_monthly_ret(entity_type, fund_ids, very_old_date, end_day, true);
  871. v_end_date = tb_ret.end_date.temporalParse('yyyy-MM');
  872. tb_ret.replaceColumn!('end_date', v_end_date);
  873. }
  874. if(tb_ret.isVoid() || tb_ret.size() == 0) { return null; }
  875. // 标准的指标
  876. d = cal_monthly_indicators(entity_type, 'PBI', tb_ret);
  877. return d;
  878. }
  879. /*
  880. * Calculate historcial fund trailing BFI indicators
  881. *
  882. * @param entity_type <STRING>: MF, HF
  883. * @param fund_ids <STRING>: 逗号和单引号分隔的fund_id
  884. * @param end_day <DATE>: 要计算的日期
  885. * @param isFromNav <BOOL>: 用净值实时计算还是从表中取月收益
  886. * @param isFromSQL <BOOL>: TODO: 从MySQL还是本地DolphinDB取净值/收益数据
  887. *
  888. * @return <DICT TABLE>: ['BFI-INCEP', 'BFI-YTD', 'BFI-3M', 'BFI-6M', 'BFI-1Y', 'BFI-2Y', 'BFI-3Y', 'BFI-4Y', 'BFI-5Y', 'BFI-10Y']
  889. *
  890. *
  891. * Example: cal_fund_bfi_indicators('MF', "'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", 2024.08.31, true);
  892. *
  893. */
  894. def cal_fund_bfi_indicators(entity_type, fund_ids, end_day, isFromNav) {
  895. very_old_date = 1990.01.01;
  896. if(isFromNav == true) {
  897. // 从净值开始计算收益
  898. tb_ret = SELECT * FROM cal_fund_monthly_returns(entity_type, fund_ids, true) WHERE price_date <= end_day;
  899. tb_ret.rename!(['fund_id', 'cumulative_nav'], ['entity_id', 'nav']);
  900. } else {
  901. // 从fund_performance表里读月收益
  902. tb_ret = get_monthly_ret(entity_type, fund_ids, very_old_date, end_day, true);
  903. tb_ret.rename!(['fund_id'], ['entity_id']);
  904. v_end_date = tb_ret.end_date.temporalParse('yyyy-MM');
  905. tb_ret.replaceColumn!('end_date', v_end_date);
  906. }
  907. if(tb_ret.isVoid() || tb_ret.size() == 0) { return null; }
  908. // BFI指标
  909. d = cal_monthly_indicators(entity_type, 'BFI', tb_ret);
  910. return d;
  911. }
  912. /*
  913. * Calculate historcial portfolio trailing indicators
  914. *
  915. * @param portfolio_ids <STRING>: comma-delimited portfolio ids
  916. * @param end_day <DATE>: the date
  917. * @param cal_method <INT>: calculate based on cumulative nav (1) or nav (2)
  918. * @param isFromNav <BOOL>: calculate returns from NAV on-the-fly (true) or get from monthly return table (false)
  919. *
  920. * Example: cal_portfolio_indicators('166002,166114', 2024.08.31, 1, true);
  921. *
  922. def cal_portfolio_indicators(portfolio_ids, end_day, cal_method, isFromNav) {
  923. very_old_date = 1990.01.01;
  924. start_month = very_old_date.month();
  925. portfolio_info = get_portfolio_info(portfolio_ids);
  926. if(portfolio_info.isVoid() || portfolio_info.size() == 0) { return null };
  927. portfolio_info.rename!('portfolio_id', 'entity_id');
  928. if(isFromNav == true) {
  929. // 从净值开始计算收益
  930. tb_raw_ret = SELECT * FROM cal_portfolio_nav(portfolio_ids, very_old_date, cal_method) WHERE price_date <= end_day;
  931. if(tb_raw_ret.isVoid() || tb_raw_ret.size() == 0) return null;
  932. // funky thing is you can't use "AS" for the grouping columns?
  933. tb_ret = SELECT portfolio_id, price_date.month(), price_date.last() AS price_date, (1+ret).prod()-1 AS ret, nav.last() AS nav
  934. FROM tb_raw_ret
  935. WHERE price_date <= end_day
  936. GROUP BY portfolio_id, price_date.month();
  937. tb_ret.rename!(['portfolio_id', 'month_price_date'], ['entity_id', 'end_date']);
  938. } else {
  939. // 从pf_portfolio_performance表里读月收益
  940. tb_ret = get_monthly_ret('PF', portfolio_ids, very_old_date, end_day, true);
  941. tb_ret.rename!(['portfolio_id'], ['entity_id']);
  942. v_end_date = tb_ret.end_date.temporalParse('yyyy-MM');
  943. tb_ret.replaceColumn!('end_date', v_end_date);
  944. }
  945. if(tb_ret.isVoid() || tb_ret.size() == 0) return null;
  946. // 混合因子做基准,同SQL保持一致
  947. t_dates = table(start_month..end_day.month() AS end_date);
  948. primary_benchmark = SELECT ei.entity_id, dt.end_date, 'FA00000VNB' AS benchmark_id
  949. FROM portfolio_info ei JOIN t_dates dt
  950. WHERE dt.end_date >= ei.inception_date.month();
  951. if(primary_benchmark.isVoid() || primary_benchmark.size() == 0) { return null; }
  952. // 取所有出现的基准月收益
  953. bmk_ret = get_benchmark_return(primary_benchmark, end_day);
  954. if(bmk_ret.isVoid() || bmk_ret.size() == 0) { return null; }
  955. // TODO: risk free指数月收益存在fund_performance表,所以先将就用 fund_id 表示。之后统一改为更准确的名字
  956. risk_free_rate = SELECT entity_id AS fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
  957. if(risk_free_rate.isVoid() || risk_free_rate.size() == 0) { return null; }
  958. t0 = cal_trailing_indicators(portfolio_info, primary_benchmark, end_day, tb_ret, bmk_ret, risk_free_rate);
  959. v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
  960. return dict(v_table_name, t0);
  961. }
  962. * Calculate historcial portfolio trailing BFI indicators
  963. *
  964. * @param portfolio_ids <STRING>: comma-delimited portfolio ids
  965. * @param end_day <DATE>: the date
  966. * @param cal_method <INT>: calculate based on cumulative nav (1) or nav (2)
  967. * @param isFromNav <BOOL>: calculate returns from NAV on-the-fly (true) or get from monthly return table (false)
  968. *
  969. * TODO: intergrate with cal_portfolio_indicators
  970. *
  971. * Example: cal_portfolio_bfi_indicators('166002,166114', 2024.08.31, 1, true);
  972. *
  973. def cal_portfolio_bfi_indicators(portfolio_ids, end_day, cal_method, isFromNav) {
  974. very_old_date = 1990.01.01;
  975. start_month = 1990.01M;
  976. portfolio_info = get_portfolio_info(portfolio_ids);
  977. if(portfolio_info.isVoid() || portfolio_info.size() == 0) { return null };
  978. portfolio_info.rename!('portfolio_id', 'entity_id');
  979. if(isFromNav == true) {
  980. // 从净值开始计算收益
  981. tb_raw_ret = SELECT * FROM cal_portfolio_nav(portfolio_ids, very_old_date, cal_method) WHERE price_date <= end_day;
  982. if(tb_raw_ret.isVoid() || tb_raw_ret.size() == 0) return null;
  983. // funky thing is you can't use "AS" for the grouping columns?
  984. tb_ret = SELECT portfolio_id, price_date.month(), price_date.last() AS price_date, (1+ret).prod()-1 AS ret, nav.last() AS nav
  985. FROM tb_raw_ret
  986. WHERE price_date <= end_day
  987. GROUP BY portfolio_id, price_date.month();
  988. tb_ret.rename!(['portfolio_id', 'month_price_date'], ['entity_id', 'end_date']);
  989. } else {
  990. // 从pf_portfolio_performance表里读月收益
  991. tb_ret = get_monthly_ret('PF', portfolio_ids, very_old_date, end_day, true);
  992. tb_ret.rename!(['portfolio_id'], ['entity_id']);
  993. v_end_date = tb_ret.end_date.temporalParse('yyyy-MM');
  994. tb_ret.replaceColumn!('end_date', v_end_date);
  995. }
  996. if(tb_ret.isVoid() || tb_ret.size() == 0) return null;
  997. // 取组合和基准的对照表
  998. bfi_benchmark = SELECT portfolio_id AS entity_id, end_date.temporalParse('yyyy-MM') AS end_date, factor_id AS benchmark_id
  999. FROM get_portfolio_bfi_factors(portfolio_ids, start_month.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
  1000. if(bfi_benchmark.isVoid() || bfi_benchmark.size() == 0) { return null; }
  1001. bmk_ret = get_benchmark_return(bfi_benchmark, end_day);
  1002. if(bmk_ret.isVoid() || bmk_ret.size() == 0) { return null; }
  1003. // TODO: risk free指数月收益存在fund_performance表,所以先将就用 fund_id 表示。之后统一改为更准确的名字
  1004. risk_free_rate = SELECT entity_id AS fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
  1005. if(risk_free_rate.isVoid() || risk_free_rate.size() == 0) { return null; }
  1006. t0 = cal_trailing_bfi_indicators(portfolio_info, bfi_benchmark, end_day, tb_ret, bmk_ret, risk_free_rate);
  1007. v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
  1008. return dict(v_table_name, t0);
  1009. }
  1010. */
  1011. /*
  1012. * 【Morningstar Integration】通用月度指标计算
  1013. *
  1014. * @param entity_type <STRING>:
  1015. * @param indicator_type <STRING>: PBI, BFI
  1016. * @param monthly_returns <TABLE>: NEED COLUMN: entity_id, end_date, price_date, nav, ret
  1017. *
  1018. * @return <DICT TABLE>: ['PBI-INCEP', 'PBI-YTD', 'PBI-3M', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y']
  1019. *
  1020. */
  1021. def ms_cal_monthly_indicators(entity_type, indicator_type, monthly_returns) {
  1022. if(find(['MF', 'HF', 'PF'], entity_type) < 0) return null;
  1023. if(monthly_returns.isVoid() || monthly_returns.size() < 1) return null;
  1024. oldest_date = EXEC price_date.min() FROM monthly_returns;
  1025. v_entity_ids = (SELECT DISTINCT entity_id FROM monthly_returns).entity_id;
  1026. entity_info = get_entity_info(entity_type, v_entity_ids);
  1027. if(entity_info.isVoid() || entity_info.size() == 0) { return null };
  1028. end_day = today();
  1029. // 取基金和基准的对照表
  1030. if(indicator_type == 'BFI') {
  1031. benchmark = SELECT fund_id AS entity_id, end_date.temporalParse('yyyy-MM') AS end_date, factor_id AS benchmark_id
  1032. FROM get_fund_bfi_factors(v_entity_ids, oldest_date.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
  1033. } else if(indicator_type == 'CAI') {
  1034. benchmark = SELECT fund_id AS entity_id, end_date.temporalParse('yyyy-MM') AS end_date, factor_id AS benchmark_id
  1035. FROM ms_get_fund_category_average(v_entity_ids, oldest_date.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
  1036. } else {
  1037. // 主基准, 对应 xxx_info 中的 primary_benchmark_id
  1038. benchmark = SELECT entity_id, end_date, iif(benchmark_id.isNull(), 'IN00000008', benchmark_id) AS benchmark_id
  1039. FROM ms_get_entity_primary_benchmark(entity_type, v_entity_ids, oldest_date.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM')) ;
  1040. }
  1041. // 取所有出现的基准月收益
  1042. bmk_ret = get_benchmark_return(benchmark, end_day);
  1043. if(bmk_ret.isVoid() || bmk_ret.size() == 0) { return null; }
  1044. // TODO: risk free指数月收益存在fund_performance表,所以先将就用 fund_id 表示。之后统一改为更准确的名字
  1045. risk_free_rate = SELECT entity_id AS fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM ms_get_risk_free_rate(oldest_date, end_day);
  1046. if(risk_free_rate.isVoid() || risk_free_rate.size() == 0) { return null; }
  1047. // 指标计算
  1048. if(indicator_type == 'BFI') {
  1049. t0 = cal_trailing_bfi_indicators(entity_info, benchmark, end_day, monthly_returns, bmk_ret, risk_free_rate);
  1050. v_table_name = ['BFI-INCEP', 'BFI-YTD', 'BFI-3M', 'BFI-6M', 'BFI-1Y', 'BFI-2Y', 'BFI-3Y', 'BFI-4Y', 'BFI-5Y', 'BFI-10Y'];
  1051. } else if(indicator_type == 'CAI') {
  1052. t0 = cal_trailing_bfi_indicators(entity_info, benchmark, end_day, monthly_returns, bmk_ret, risk_free_rate);
  1053. v_table_name = ['CAI-INCEP', 'CAI-YTD', 'CAI-3M', 'CAI-6M', 'CAI-1Y', 'CAI-2Y', 'CAI-3Y', 'CAI-4Y', 'CAI-5Y', 'CAI-10Y'];
  1054. } else {
  1055. t0 = cal_trailing_indicators(entity_info, benchmark, end_day, monthly_returns, bmk_ret, risk_free_rate);
  1056. v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-3M', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
  1057. }
  1058. return dict(v_table_name, t0);
  1059. }