indicatorCalculator.dos 55 KB

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