indicatorCalculator.dos 54 KB

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