indicatorCalculator.dos 54 KB

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