indicatorCalculator.dos 54 KB

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