indicatorCalculator.dos 53 KB

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