module fundit::indicatorCalculator
use fundit::dataPuller
use fundit::returnCalculator
use fundit::navCalculator
/*
* Annulized multiple
*/
def get_annulization_multiple(freq) {
ret = 1;
if (freq == 'd') {
ret = 252; // We have differences here between Java and DolphinDB, Java uses 365.25 days
} else if (freq == 'w') {
ret = 52;
} else if (freq == 'm') {
ret = 12;
} else if (freq == 'q') {
ret = 4;
} else if (freq == 's') {
ret = 2;
} else if (freq == 'a') {
ret = 1;
}
return ret;
}
/*
* 取主基准和BFI的历史月收益率
*
* @param benchmarks
: entity-benchmark 的对应关系表
* @param end_day : 收益的截止日期
*
* @return : benchmark_id, end_date, ret
*
*/
def get_benchmark_return(benchmarks, end_day) {
s_index_ids = '';
s_factor_ids = '';
if(benchmarks.isVoid() || benchmarks.size() == 0) { return null; }
// 前缀为 IN 的 benchmark id
t_index_id = SELECT DISTINCT benchmark_id FROM benchmarks WHERE benchmark_id LIKE 'IN%';
s_index_ids = iif(isVoid(t_index_id), "", "'" + t_index_id.benchmark_id.concat("','") + "'");
// 前缀为 FA 的 benchmark id
t_factor_id = SELECT DISTINCT benchmark_id FROM benchmarks WHERE benchmark_id LIKE 'FA%';
s_factor_ids = iif(isVoid(t_factor_id), "", "'" + t_factor_id.benchmark_id.concat("','") + "'");
// 目前指数的月度业绩存在 fund_performance 表
t_bmk = SELECT fund_id AS benchmark_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_monthly_ret('IX', s_index_ids, 1990.01.01, end_day, true);
// 而因子的月度业绩存在 cm_factor_performance 表
INSERT INTO t_bmk SELECT factor_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_monthly_ret('FA', s_factor_ids, 1990.01.01, end_day, true);
return t_bmk;
}
/*
* Trailing Return, Standard Deviation, Skewness, Kurtosis, Max Drawdown, VaR, CVaR, Calmar Ratio
* @param ret: 收益表,需要有 entity_id, price_dat, end_date, nav
* @param freq: 数据频率,d, w, m, q, s, a
*
* TODO: max drowdown is off!
* NOTE: standard deviation of Java version is noncompliant-GIPS annulized number
*
* Create: 20240904 Joey
* TODO: var and cvar are silightly off compared with Java version
* calmar is offCalmar
*
*/
def cal_basic_performance(ret, freq) {
/* OLD version that can only calculate the latest numbers (group-by version)
t = SELECT entity_id, end_date.max() AS end_date, max(price_date) AS price_date, min(price_date) AS min_date,
((1+ret).prod()-1).round(6) AS trailing_ret,
iif(price_date.max().month()-price_date.min().month()>12,
((1+ret).prod()).pow(get_annulization_multiple('m')\(end_date.max()-end_date.min()))-1,
((1+ret).prod()-1)).round(6) AS trailing_ret_a,
ret.std() AS std_dev,
ret.skew(false) AS skewness,
ret.kurtosis(false) - 3 AS kurtosis,
ret.min() AS wrst_month
max( 1 - nav \ nav.cummax() ) AS drawdown
FROM ret
GROUP BY entity_id;
// var & cvar require return NOT NULL
// NOTE: DolphinDB supports 4 different ways: normal, logNormal, historical, monteCarlo. we use historical
t1 = SELECT entity_id, max(end_date) AS end_date, max(price_date) AS price_date,
ret.VaR('historical', 0.95) AS var,
ret.CVaR('historical', 0.95) AS cvar
FROM ret
WHERE ret.ret > - 1
GROUP BY entity_id;
return (SELECT * FROM t LEFT JOIN t1 ON t.entity_id = t1.entity_id AND t.end_date = t1.end_date AND t.price_date = t1.price_date);
*/
t = SELECT max(price_date) AS price_date, min(price_date) AS min_date,
((1+ret).prod()-1).round(6) AS trailing_ret,
iif(price_date.max().month()-price_date.min().month()>12,
((1+ret).prod()).pow(get_annulization_multiple('m')\(end_date.max()-end_date.min()))-1,
((1+ret).prod()-1)).round(6) AS trailing_ret_a,
ret.std() AS std_dev,
ret.skew(false) AS skewness,
ret.kurtosis(false) - 3 AS kurtosis,
ret.min() AS wrst_month
FROM ret
GROUP BY entity_id
CGROUP BY end_date
ORDER BY end_date;
// because neither VaR and CVaR in context-by (cumXXX version) are NOT supported by DolphinDB , nor they are supported in cgroup-by
// we have to implement them using more basic ways:
t1 = SELECT entity_id, end_date, ret,
cummax( 1 - nav \ nav.cummax() ) AS drawdown, // same story: cummax is not supported by cgroup-by, so it is moved here
-ret.cumpercentile(5, 'linear') AS var
FROM ret
CONTEXT BY entity_id;
// CVaR = mean of all returns below VaR
t_cvar = SELECT DISTINCT entity_id, end_date, drawdown, var, cvar
FROM (
SELECT t1.entity_id, t1.end_date, t1.drawdown, t1.var, -avg(t2.ret) AS cvar
FROM t1
INNER JOIN t1 AS t2 ON t1.entity_id = t2.entity_id
WHERE t2.end_date <= t1.end_date
AND t2.ret < -t1.var
CONTEXT BY t1.entity_id, t1.end_date );
return (SELECT *, iif(t_cvar.drawdown == 0, null, t.trailing_ret_a\t_cvar.drawdown) AS calmar
FROM t LEFT JOIN t_cvar ON t.entity_id = t_cvar.entity_id AND t.end_date = t_cvar.end_date ORDER BY entity_id, end_date);
}
/*
* Lower Partial Moment
* NOTE: risk free rate is used as Minimal Accepted Rate (MAR) here
*
*/
def cal_LPM(ret, risk_free) {
t = SELECT *, count(entity_id) AS cnt FROM ret WHERE ret > -1 CONTEXT BY entity_id;
lpm = SELECT t.entity_id, t.end_date,
(cumsum (iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ (t.cnt[0])).pow(1\1) AS lpm1,
(cumsum2(iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ (t.cnt[0])).pow(1\2) AS lpm2,
(cumsum3(iif(rfr.ret > t.ret, rfr.ret - t.ret, 0)) \ (t.cnt[0])).pow(1\3) AS lpm3
FROM t
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id;
return lpm;
}
/*
* Downside Devision, Omega Ratio, Sortino Ratio, Kappa Ratio
*
* TODO: Java version of Downside Deviation (LPM2) uses cnt-1 as denominator to calculate mean excess return, which might be wrong
* Java version of Omega could be wrong because Java uses annualized returns and cnt-1
* Java'version of Kappa could be very wrong
*
*/
def cal_omega_sortino_kappa(ret, risk_free) {
lpm = cal_LPM(ret, risk_free);
tb = SELECT t.entity_id, t.end_date,
l.lpm2 AS ds_dev,
(t.ret - rfr.ret ).cumavg() \ l.lpm1 + 1 AS omega,
(t.ret - rfr.ret ).cumavg() \ l.lpm2 AS sortino,
(t.ret - rfr.ret ).cumavg() \ l.lpm3 AS kappa
FROM ret t
INNER JOIN lpm l ON t.entity_id = l.entity_id AND t.end_date = l.end_date
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id;
return tb;
}
/*
* Alpha & Beta
* NOTE: alpha of Java version is noncompliant-GIPS annulized number
*/
def cal_alpha_beta(ret, benchmarks, bmk_ret, risk_free) {
t = SELECT t.entity_id, t.end_date, t.ret, bm.benchmark_id, bmk.ret AS ret_bmk
FROM ret t
INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
WHERE t.ret > -1
AND bmk.ret > -1;
beta = SELECT entity_id, end_date, benchmark_id, ret.cumbeta(ret_bmk) AS beta FROM t CONTEXT BY entity_id, benchmark_id;
alpha = SELECT t.entity_id, t.end_date, t.benchmark_id, beta.beta AS beta,
(t.ret - rfr.ret).cumavg() - beta.beta * (t.ret_bmk - rfr.ret).cumavg() AS alpha
FROM t
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
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id, t.benchmark_id
ORDER BY t.entity_id, t.end_date, t.benchmark_id;
return alpha;
}
/*
* Winning Ratio, Tracking Error, Information Ratio
*
* DO WE FOUND A BIG BUG OF JAVA IMPLEMENTATION, WHICH ASSUMES FACTORS OF CURRENT MONTH ARE SAME AS HISTORICAL ONES!
*
* TODO: Information Ratio is way off!
* Not sure how to describe a giant number("inf"), for now 999 is used
*/
def cal_benchmark_tracking(ret, benchmarks, bmk_ret) {
t0 = SELECT t.entity_id, t.end_date, t.price_date,
t.ret, bmk.ret AS ret_bmk, cumcount(t.entity_id) AS cnt, (t.ret - bmk.ret) AS exc_ret, bm.benchmark_id
FROM ret t
INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
WHERE t.ret > -1
AND bmk.ret > -1
CONTEXT BY t.entity_id, bm.benchmark_id;
t = SELECT entity_id, end_date.cummax() AS end_date, price_date.cummax() AS price_date, price_date.cummin() AS min_date, benchmark_id,
cumcount(iif(exc_ret >= 0, 1, null)) \ cnt AS winrate,
exc_ret.cumstd() AS track_error,
iif(exc_ret.cumstd() == 0, null, exc_ret.cumavg() / exc_ret.cumstd()) AS info
FROM t0 CONTEXT BY entity_id, benchmark_id
ORDER BY entity_id, end_date, benchmark_id;
return t;
}
/*
* Upside/Down Capture Return/Ratio
*
*/
def cal_capture_ratio(ret, benchmarks, bmk_ret) {
t1 = SELECT t.entity_id, t.end_date, (1+t.ret).cumprod() AS upside_ret, (1+bmk.ret).cumprod() AS bmk_upside_ret, bmk.end_date.cumcount() AS bmk_upside_cnt, bm.benchmark_id
FROM ret t
INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
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
WHERE t.ret > -1
AND bmk.ret >= 0
CONTEXT BY t.entity_id, bm.benchmark_id;
t2 = SELECT t.entity_id, t.end_date, (1+t.ret).cumprod() AS downside_ret, (1+bmk.ret).cumprod() AS bmk_downside_ret, bmk.end_date.cumcount() AS bmk_downside_cnt, bm.benchmark_id
FROM ret t
INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
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
WHERE t.ret > -1
AND bmk.ret < 0
CONTEXT BY t.entity_id, bm.benchmark_id;
t = (SELECT * FROM (
SELECT iif(isNull(t1.entity_id), t2.entity_id, t1.entity_id) AS entity_id,
iif(isNull(t1.end_date), t2.end_date, t1.end_date) AS end_date,
iif(isNull(t1.benchmark_id), t2.benchmark_id, t1.benchmark_id) AS benchmark_id,
t1.upside_ret.pow(1 \ t1.bmk_upside_cnt)-1 AS upside_capture_ret,
(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,
t2.downside_ret.pow(1 \ t2.bmk_downside_cnt)-1 AS downside_capture_ret,
(t2.downside_ret.pow(1 \ t2.bmk_downside_cnt)-1)/(t2.bmk_downside_ret.pow(1 \ t2.bmk_downside_cnt)-1) AS downside_capture_ratio
FROM t1 FULL JOIN t2 ON t1.entity_id = t2.entity_id AND t1.benchmark_id = t2.benchmark_id AND t1.end_date = t2.end_date)
ORDER BY entity_id, benchmark_id, end_date).ffill();
return t;
}
/*
* Sharpe Ratio
* NOTE: Java version is noncompliant-GIPS annulized number
*/
def cal_sharpe(ret, std_dev, risk_free) {
sharpe = SELECT t.entity_id, t.end_date, (t.ret - rfr.ret).cumavg() / std.std_dev AS sharpe
FROM ret t
INNER JOIN std_dev std ON t.entity_id = std.entity_id AND t.end_date = std.end_date
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
WHERE std.std_dev <> 0
CONTEXT BY t.entity_id;
return sharpe;
}
/*
* Treynor Ratio
*/
def cal_treynor(ret, risk_free, beta) {
t = SELECT *, cumcount(entity_id) AS cnt
FROM ret t
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
WHERE t.ret > -1
AND rfr.ret > -1
CONTEXT BY t.entity_id;
treynor = SELECT t.entity_id, t.end_date, beta.benchmark_id,
((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
FROM t
INNER JOIN beta AS beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
CONTEXT BY t.entity_id, beta.benchmark_id;
return treynor;
}
/*
* Jensen's Alpha
* TODO: the result is slightly off
*/
def cal_jensen(ret, bmk_ret, risk_free, beta) {
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
FROM ret t
INNER JOIN beta beta ON t.entity_id = beta.entity_id AND t.end_date = beta.end_date
INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND beta.benchmark_id = bmk.benchmark_id
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id, beta.benchmark_id;
return jensen;
}
/*
* Modigliani Modigliani Measure (M2)
* NOTE: M2 = sharpe * std(benchmark) + risk_free_rate
* NOTE: Java version is noncompliant-GIPS annulized number
*/
def cal_m2(ret, benchmarks, bmk_ret, risk_free) {
m2 = SELECT t.entity_id, t.end_date, (t.ret - rfr.ret).cumavg() / t.ret.cumstd() * bmk.ret.cumstd() + rfr.ret.cumavg() AS m2, bm.benchmark_id
FROM ret t
INNER JOIN benchmarks bm ON t.entity_id = bm.entity_id AND t.end_date = bm.end_date
INNER JOIN bmk_ret bmk ON t.end_date = bmk.end_date AND bm.benchmark_id = bmk.benchmark_id
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id, bm.benchmark_id;
return m2;
}
/*
* Morningstar Return, Morningstar Risk-Adjusted Return
*
* TODO: Tax and loads are NOT taken care of
* TODO: Assume Chinese methodology using 3, 5, 10 as number of traling years
* TODO: need verify with reliable results
*
* NOTE: Morningstar methodology requires monthly return for calculation, so that "12" is hard-coded here
*
*
*/
def cal_ms_return(ret, risk_free) {
r = SELECT t.entity_id, t.end_date, t.price_date.cummax() AS price_date, t.price_date.cummin() AS min_date,
((1 + t.ret)\(1 + rfr.ret)).cumprod().pow(12\(t.end_date.cummax() - t.end_date.cummin()))-1 AS ms_ret_a,
(1 + t.ret).pow(-2).cumavg().pow(-12/2)-1 AS ms_rar_a
FROM ret t
INNER JOIN risk_free rfr ON t.end_date = rfr.end_date
CONTEXT BY t.entity_id;
return r;
}
/*
* Calculation for monthly indicators which need benchmark
* @param ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param benchmarks : entity-benchmark mapping table
* @param index_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
* @return: indicators table
*
*
* Create 20240904 模仿Java & python代码在Dolphin中实现,具体计算逻辑可能会有不同 Joey
* TODO: some datapoints require more data, we need a way to disable calculation for them
*
*/
def cal_indicators_with_benchmark(mutable ret, benchmarks, index_ret, risk_free) {
// sorting for correct first() and last() value
ret.sortBy!(['entity_id', 'price_date'], [1, 1]);
// alpha, beta
alpha_beta = cal_alpha_beta(ret, benchmarks, index_ret, risk_free);
// 胜率、跟踪误差、信息比率
bmk_tracking = cal_benchmark_tracking(ret, benchmarks, index_ret);
// 特雷诺
treynor = cal_treynor(ret, risk_free, alpha_beta);
// 詹森指数
jensen = cal_jensen(ret, index_ret, risk_free, alpha_beta);
// M2
m2 = cal_m2(ret, benchmarks, index_ret, risk_free);
// 上下行捕获率、收益
capture_r = cal_capture_ratio(ret, benchmarks, index_ret);
r = SELECT * FROM bmk_tracking a1
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
LEFT JOIN treynor ON a1.entity_id = treynor.entity_id AND a1.benchmark_id = treynor.benchmark_id AND a1.end_date = treynor.end_date
LEFT JOIN jensen ON a1.entity_id = jensen.entity_id AND a1.benchmark_id = jensen.benchmark_id AND a1.end_date = jensen.end_date
LEFT JOIN m2 ON a1.entity_id = m2.entity_id AND a1.benchmark_id = m2.benchmark_id AND a1.end_date = m2.end_date
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;
// 年化各数据点
// GIPS RULE: NO annulization for data less than 1 year
plainAnnu = get_annulization_multiple('m');
sqrtAnnu = sqrt(get_annulization_multiple('m'));
r.addColumn(['alpha_a', 'jensen_a', 'track_error_a', 'info_a', 'm2_a'],
[DOUBLE, DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
UPDATE r
SET alpha_a = alpha * iif(price_date.month() - min_date.month() >= 11, plainAnnu, 1),
jensen_a = jensen * iif(price_date.month() - min_date.month() >= 11, plainAnnu, 1),
track_error_a = track_error * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1),
info_a = info * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1),
m2_a = m2 * iif(price_date.month() - min_date.month() >= 11, plainAnnu, 1);
return r.dropColumns!(['price_date', 'min_date']);
}
/*
* Monthly standard indicator calculation
* @param ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param benchmarks : entity-benchmark mapping table
* @param benchmark_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
* @return: indicators table
*
*
* Create 20240904 模仿Java & python代码在Dolphin中实现,具体计算逻辑可能会有不同 Joey
* TODO: some datapoints require more data, we need a way to disable calculation for them
*
*/
def cal_indicators(mutable ret, benchmarks, benchmark_ret, risk_free) {
// sorting for correct first() and last() value
ret.sortBy!(['entity_id', 'price_date'], [1, 1]);
// 收益、标准差、偏度、峰度、最大回撤、VaR, CVaR、卡玛比率
rtn = cal_basic_performance(ret, 'm');
// 夏普
sharpe = cal_sharpe(ret, rtn, risk_free);
// 整合后的下行标准差、欧米伽、索提诺、卡帕
lpms = cal_omega_sortino_kappa(ret, risk_free);
// 需要基准的指标们
indicator_with_benchmark = cal_indicators_with_benchmark(ret, benchmarks, benchmark_ret, risk_free);
r = SELECT * FROM rtn a1
LEFT JOIN sharpe ON a1.entity_id = sharpe.entity_id AND a1.end_date = sharpe.end_date
LEFT JOIN lpms ON a1.entity_id = lpms.entity_id AND a1.end_date = lpms.end_date
LEFT JOIN indicator_with_benchmark bmk ON a1.entity_id = bmk.entity_id AND a1.end_date = bmk.end_date;
// 年化各数据点
// GIPS RULE: NO annulization for data less than 1 year
plainAnnu = get_annulization_multiple('m');
sqrtAnnu = sqrt(get_annulization_multiple('m'));
r.addColumn(['std_dev_a', 'ds_dev_a', 'sharpe_a', 'sortino_a'],
[DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
UPDATE r
SET std_dev_a = std_dev * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1),
ds_dev_a = ds_dev * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1),
sharpe_a = sharpe * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1),
sortino_a = sortino * iif(price_date.month() - min_date.month() >= 11, sqrtAnnu, 1);
return r;
}
/*
* Monthly BFI indicator calculation
* @param ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param benchmarks : entity-benchmark mapping table
* @param benchmark_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
* @return: BFI indicators table
*
*
* Create 20240914 Joey
*
*/
def cal_bfi_indicators(mutable ret, benchmarks, benchmark_ret, risk_free) {
// 需要基准的指标们
r = cal_indicators_with_benchmark(ret, benchmarks, benchmark_ret, risk_free);
return r;
}
/*
* Monthly Morningstar indicator calculation
*
* @param ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param benchmarks :
* @param benchmark_ret :
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
*/
def cal_ms_indicators(mutable ret, benchmarks, benchmark_ret, risk_free) {
r = cal_ms_return(ret, risk_free);
return r;
}
/*
* Calculate trailing 6m, ytd, 1y, 2y, 3y, 4y, 5y, 10y and since inception datapoints
*
* @param: func : the calculation function
* @param: entity_info : basic information of entity, NEED COLUMNS entity_id, inception_date
* @param benchmarks : entity-benchmark mapping table
* @param: ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param: end_day : 计算截止日期
* @param bmk_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
* @param periods : 是否计算的区间向量,分别对应 incep, ytd, 6m, 1y, 2y, 3y, 4y, 5y, 10y
*
* Example: cal_trailing(
*
*/
def cal_trailing(func, entity_info, benchmarks, mutable tb_ret, end_day, bmk_ret, risk_free_rate, periods) {
r_incep = null;
r_ytd = null;
r_6m = null;
r_1y = null;
r_2y = null;
r_3y = null;
r_4y = null;
r_5y = null;
r_10y = null;
// since inception
if(tb_ret.size() > 0 && periods[0] == 1) {
r_incep = func(tb_ret, benchmarks, bmk_ret, risk_free_rate);
}
// ytd
tb_ret_ytd = SELECT * FROM tb_ret WHERE end_date >= end_day.yearBegin().month();
if(tb_ret_ytd.size() > 0 && periods[1] == 1) {
r_ytd = func(tb_ret_ytd, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 6m
tb_ret_6m = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-6 AND (end_day.month() - ei.inception_date.month()) >= 6;
if(tb_ret_6m.size() > 0 && periods[2] == 1) {
r_6m = func(tb_ret_6m, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 1y
tb_ret_1y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-12 AND (end_day.month() - ei.inception_date.month()) >= 12;
if(tb_ret_1y.size() > 0 && periods[3] == 1) {
r_1y = func(tb_ret_1y, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 2y
tb_ret_2y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-24 AND (end_day.month() - ei.inception_date.month()) >= 24;
if(tb_ret_2y.size() > 0 && periods[4] == 1) {
r_2y = func(tb_ret_2y, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 3y
tb_ret_3y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-36 AND (end_day.month() - ei.inception_date.month()) >= 36;
if(tb_ret_3y.size() > 0 && periods[5] == 1) {
r_3y = func(tb_ret_3y, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 4y
tb_ret_4y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-48 AND (end_day.month() - ei.inception_date.month()) >= 48;
if(tb_ret_4y.size() > 0 && periods[6] == 1) {
r_4y = func(tb_ret_4y, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 5y
tb_ret_5y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-60 AND (end_day.month() - ei.inception_date.month()) >= 60;
if(tb_ret_5y.size() > 0 && periods[7] == 1) {
r_5y = func(tb_ret_5y, benchmarks, bmk_ret, risk_free_rate);
}
// trailing 10y
tb_ret_10y = SELECT * FROM tb_ret r INNER JOIN entity_info ei ON r.entity_id = ei.entity_id
WHERE r.end_date > end_day.month()-120 AND (end_day.month() - ei.inception_date.month()) >= 120;
if(tb_ret_10y.size() > 0 && periods[8] == 1) {
r_10y = func(tb_ret_10y, benchmarks, bmk_ret, risk_free_rate);
}
return r_incep, r_ytd, r_6m, r_1y, r_2y, r_3y, r_4y, r_5y, r_10y;
}
/*
* Calculate trailing 6m, ytd, 1y, 2y, 3y, 4y, 5y, 10y and since inception standard indicators
*
* @param: entity_info : basic information of entity, NEED COLUMNS entity_id, inception_date
* @param benchmarks : entity-benchmark mapping table
* @param: ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param: end_day : 计算截止日期
* @param bmk_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
*/
def cal_trailing_indicators(entity_info, benchmarks, mutable tb_ret, end_day, bmk_ret, risk_free_rate) {
return cal_trailing(cal_indicators, entity_info, benchmarks, tb_ret, end_day, bmk_ret, risk_free_rate, [1,1,1,1,1,1,1,1,1]);
}
/*
* Calculate trailing 6m, ytd, 1y, 2y, 3y, 4y, 5y, 10y and since inception bfi indicators
*
* @param: entity_info : basic information of entity, NEED COLUMNS entity_id, inception_date
* @param benchmarks : entity-benchmark mapping table
* @param: ret : 收益表,NEED COLUMNS entity_id, price_dat, end_date, nav
* @param: end_day : 计算截止日期
* @param bmk_ret : historical benchmark return table, NEED COLUMNS fund_id, end_date, ret
* @param risk_free : historical risk free rate table, NEED COLUMNS fund_id, end_date, ret
*
*
*/
def cal_trailing_bfi_indicators(entity_info, benchmarks, mutable tb_ret, end_day, bmk_ret, risk_free_rate) {
return cal_trailing(cal_bfi_indicators, entity_info, benchmarks, tb_ret, end_day, bmk_ret, risk_free_rate, [1,1,1,1,1,1,1,1,1]);
}
/*
* Calculate trailing 3y, 5y, 10y Morningstar Return, Risk-Adjested Return and Risk
*
*/
def cal_trailing_ms_indicators(entity_info, mutable tb_ret, end_day, risk_free_rate) {
return cal_trailing(cal_ms_indicators, entity_info, , tb_ret, end_day, , risk_free_rate, periods=[0,0,0,0,0,1,0,1,1]);
}
/*
* Calculate fund indicators for one date
*
* @param entity_type : MF, HF
* @param fund_ids : 逗号和单引号分隔的fund_id
* @param end_day : 要计算的日期
* @param isFromNav : 用净值实时计算还是从表中取月收益
* @param isFromSQL : TODO: 从MySQL还是本地DolphinDB取净值/收益数据
*
* @return : ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y', 'MS-3Y', 'MS-5Y', 'MS-10Y']
*
* TODO: primary_benchmark_id seems not be used as benchmark, when it is FA00000VNB
*
* Example: cal_fund_indicators('HF', "'HF000004KN','HF000103EU','HF00018WXG'", 2024.06.28, true);
*
*/
def cal_fund_indicators(entity_type, fund_ids, end_day, isFromNav) {
very_old_date = 1990.01.01;
start_month = 1990.01M;
fund_info = get_fund_info(fund_ids);
if(fund_info.isVoid() || fund_info.size() == 0) { return null };
fund_info.rename!('fund_id', 'entity_id');
if(isFromNav == true) {
// 从净值开始计算收益
tb_ret = SELECT * FROM cal_fund_monthly_returns(entity_type, fund_ids, true) WHERE price_date <= end_day;
tb_ret.rename!(['fund_id', 'cumulative_nav'], ['entity_id', 'nav']);
} else {
// 从fund_performance表里读月收益
tb_ret = get_monthly_ret('FD', fund_ids, very_old_date, end_day, true);
tb_ret.rename!(['fund_id'], ['entity_id']);
}
// 取基金和基准的对照表
primary_benchmark = SELECT fund_id AS entity_id, end_date, iif(benchmark_id.isNull(), 'IN00000008', benchmark_id) AS benchmark_id
FROM get_fund_primary_benchmark(fund_ids, start_month.temporalFormat('yyyy-MM'), end_day.month().temporalFormat('yyyy-MM')) ;
// 取所有出现的基准月收益
bmk_ret = get_benchmark_return(primary_benchmark, end_day);
risk_free_rate = SELECT fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
// 标准的指标
t0 = cal_trailing_indicators(fund_info, primary_benchmark, tb_ret, end_day, bmk_ret, risk_free_rate);
// Morningstar 指标
t1 = cal_trailing_ms_indicators(fund_info, tb_ret, end_day, risk_free_rate);
// PBI stands for "Primary Benchmark Index", MS stands for "MorningStar"
v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y', 'MS-3Y', 'MS-5Y', 'MS-10Y'];
return dict(v_table_name, t0 <- t1[5] <- t1[7] <- t1[8]);
}
/*
* Calculate fund BFI indicators for one date
*
* @param entity_type : MF, HF
* @param fund_ids : 逗号和单引号分隔的fund_id
* @param end_day : 要计算的日期
* @param isFromNav : 用净值实时计算还是从表中取月收益
* @param isFromSQL : TODO: 从MySQL还是本地DolphinDB取净值/收益数据
*
* @return : ['BFI-INCEP', 'BFI-YTD', 'BFI-6M', 'BFI-1Y', 'BFI-2Y', 'BFI-3Y', 'BFI-4Y', 'BFI-5Y', 'BFI-10Y']
*
* TODO: primary_benchmark_id seems not be used as benchmark, when it is FA00000VNB
* TODO: intergrate with cal_fund_indicators
*
* Example: cal_fund_bfi_indicators('MF', "'MF00003PW2', 'MF00003PW1', 'MF00003PXO'", 2024.08.31, true);
*
*/
def cal_fund_bfi_indicators(entity_type, fund_ids, end_day, isFromNav) {
very_old_date = 1990.01.01;
start_month = 1990.01M;
fund_info = get_fund_info(fund_ids);
if(fund_info.isVoid() || fund_info.size() == 0) { return null };
fund_info.rename!('fund_id', 'entity_id');
if(isFromNav == true) {
// 从净值开始计算收益
tb_ret = SELECT * FROM cal_fund_monthly_returns(entity_type, fund_ids, true) WHERE price_date <= end_day;
tb_ret.rename!(['fund_id', 'cumulative_nav'], ['entity_id', 'nav']);
} else {
// 从fund_performance表里读月收益
tb_ret = get_monthly_ret('FD', fund_ids, very_old_date, end_day, true);
tb_ret.rename!(['fund_id'], ['entity_id']);
}
// 取基金和基准的对照表
bfi_benchmark = SELECT fund_id AS entity_id, end_date.temporalParse('yyyy-MM') AS end_date, factor_id AS benchmark_id
FROM get_fund_bfi_factors(fund_ids, start_month.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
if(bfi_benchmark.isVoid() || bfi_benchmark.size() == 0) { return null; }
bmk_ret = get_benchmark_return(bfi_benchmark, end_day);
risk_free_rate = SELECT fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
t0 = cal_trailing_bfi_indicators(fund_info, bfi_benchmark, tb_ret, end_day, bmk_ret, risk_free_rate);
// BFI stands for "Best Fit Index"
v_table_name = ['BFI-INCEP', 'BFI-YTD', 'BFI-6M', 'BFI-1Y', 'BFI-2Y', 'BFI-3Y', 'BFI-4Y', 'BFI-5Y', 'BFI-10Y'];
return dict(v_table_name, t0);
}
/*
* Calculate portfolio indicators for one date
*
* @param portfolio_ids : comma-delimited portfolio ids
* @param end_day : the date
* @param cal_method : calculate based on cumulative nav (1) or nav (2)
* @param isFromNav : calculate returns from NAV on-the-fly (true) or get from monthly return table (false)
*
* Example: cal_portfolio_indicators('166002,166114', 2024.08.31, 1, true);
*
*/
def cal_portfolio_indicators(portfolio_ids, end_day, cal_method, isFromNav) {
very_old_date = 1990.01.01;
portfolio_info = get_portfolio_info(portfolio_ids);
if(portfolio_info.isVoid() || portfolio_info.size() == 0) { return null };
portfolio_info.rename!('portfolio_id', 'entity_id');
if(isFromNav == true) {
// 从净值开始计算收益
tb_raw_ret = SELECT * FROM cal_portfolio_nav(portfolio_ids, very_old_date, cal_method) WHERE price_date <= end_day;
// funky thing is you can't use "AS" for the grouping columns?
tb_ret = SELECT portfolio_id, price_date.month(), price_date.last() AS price_date, (1+ret).prod()-1 AS ret, nav.last() AS nav
FROM tb_raw_ret
WHERE price_date <= end_day
GROUP BY portfolio_id, price_date.month();
tb_ret.rename!(['portfolio_id', 'month_price_date'], ['entity_id', 'end_date']);
} else {
// 从pf_portfolio_performance表里读月收益
tb_ret = get_monthly_ret('PF', portfolio_ids, very_old_date, end_day, true);
tb_ret.rename!(['portfolio_id'], ['entity_id']);
}
// 沪深300做基准,同SQL保持一致
primary_benchmark = SELECT entity_id, 'IN00000008' AS benchmark_id FROM portfolio_info;
// 取所有出现的基准月收益
bmk_ret = get_benchmark_return(primary_benchmark, end_day);
risk_free_rate = SELECT fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
t0 = cal_trailing_indicators(portfolio_info, primary_benchmark, tb_ret, end_day, bmk_ret, risk_free_rate);
v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
return dict(v_table_name, t0);
}
/*
* Calculate portfolio bfi indicators for one date
*
* @param portfolio_ids : comma-delimited portfolio ids
* @param end_day : the date
* @param cal_method : calculate based on cumulative nav (1) or nav (2)
* @param isFromNav : calculate returns from NAV on-the-fly (true) or get from monthly return table (false)
*
* TODO: intergrate with cal_portfolio_indicators
*
* Example: cal_portfolio_bfi_indicators('166002,166114', 2024.08.31, 1, true);
*
*/
def cal_portfolio_bfi_indicators(portfolio_ids, end_day, cal_method, isFromNav) {
very_old_date = 1990.01.01;
start_month = 1990.01M;
portfolio_info = get_portfolio_info(portfolio_ids);
if(portfolio_info.isVoid() || portfolio_info.size() == 0) { return null };
portfolio_info.rename!('portfolio_id', 'entity_id');
if(isFromNav == true) {
// 从净值开始计算收益
tb_raw_ret = SELECT * FROM cal_portfolio_nav(portfolio_ids, very_old_date, cal_method) WHERE price_date <= end_day;
// funky thing is you can't use "AS" for the grouping columns?
tb_ret = SELECT portfolio_id, price_date.month(), price_date.last() AS price_date, (1+ret).prod()-1 AS ret, nav.last() AS nav
FROM tb_raw_ret
WHERE price_date <= end_day
GROUP BY portfolio_id, price_date.month();
tb_ret.rename!(['portfolio_id', 'month_price_date'], ['entity_id', 'end_date']);
} else {
// 从pf_portfolio_performance表里读月收益
tb_ret = get_monthly_ret('PF', portfolio_ids, very_old_date, end_day, true);
tb_ret.rename!(['portfolio_id'], ['entity_id']);
}
// 取组合和基准的对照表
bfi_benchmark = SELECT portfolio_id AS entity_id, end_date, factor_id AS benchmark_id
FROM get_portfolio_bfi_factors(portfolio_ids, start_month.temporalFormat('yyyy-MM'), end_day.temporalFormat('yyyy-MM'));
if(bfi_benchmark.isVoid() || bfi_benchmark.size() == 0) { return null; }
bmk_ret = get_benchmark_return(bfi_benchmark, end_day);
risk_free_rate = SELECT fund_id, temporalParse(end_date, 'yyyy-MM') AS end_date, ret FROM get_risk_free_rate(very_old_date, end_day);
t0 = cal_trailing_bfi_indicators(portfolio_info, bfi_benchmark, tb_ret, end_day, bmk_ret, risk_free_rate);
v_table_name = ['PBI-INCEP', 'PBI-YTD', 'PBI-6M', 'PBI-1Y', 'PBI-2Y', 'PBI-3Y', 'PBI-4Y', 'PBI-5Y', 'PBI-10Y'];
return dict(v_table_name, t0);
}