浏览代码

上传文件至 'modules'

first commit
Joey 1 月之前
父节点
当前提交
fe29374710
共有 3 个文件被更改,包括 824 次插入0 次删除
  1. 436 0
      modules/dataPuller.dos
  2. 133 0
      modules/fundCalculator.dos
  3. 255 0
      modules/returnCalculator.dos

+ 436 - 0
modules/dataPuller.dos

@@ -0,0 +1,436 @@
+module fundit::dataPuller
+ 
+/*
+ *  MySQL 连接,使用前应确保 loadPlugin("ODBC")已经被运行过
+ *
+ *  Create  20240711  使用ODBC连接MySQL数据库                                     Joey
+ *  
+ */
+def connect_mysql() {
+
+    // 阿里云的mysql被魔改过,当前DolphinDB无法支持MySQL插件,只能用ODBC
+    // loadPlugin("ODBC")
+
+    // conn = odbc::connect("Driver={MySQL ODBC 9.0 UNICODE Driver};Server=funditdb-dev.mysql.rds.aliyuncs.com;Database=mfdb;User=pf_user;Password=MzBlMDA0OG", "MySQL")
+
+    // 使用Windows的ODBC数据源事先设置号的连接
+    // conn = odbc::connect("Dsn=FunditDB-mfdb")
+    conn = odbc::connect("Dsn=FunditDB-dev-mfdb")
+
+//    t = odbc::query(conn, "SELECT * FROM pfdb.pf_portfolio_nav LIMIT 100")
+
+    return conn
+}
+
+/*
+ *  取本地数据库
+ *
+ *  get_local_database("fundit", "mfdb")
+ */
+def get_local_database(server_name, db_name) {
+
+    db = database(directory="D:/Program Files/DolphinDB/server/database/" + server_name + "/" + db_name + "/")
+    
+    return db
+}
+
+/*
+ * 读本地dolphindb数据表
+ *
+ * load_table_from_local("fundit", mfdb.fund_performance")
+ */
+def load_table_from_local(server_name, table_name) {
+
+    db = get_local_database(server_name, table_name.split(".")[0])
+    
+    return loadTable(db, table_name.split(".")[1])
+
+}
+
+/*
+ * 存数据表到mySQL或本地dolphindb,原数据会被替代!
+ *
+ * save_table(tb_fund_performance, "mfdb.fund_performance", false)
+ */
+
+def save_table(tb, table_name, isToMySQL) {
+
+
+    if(isToMySQL == true) {
+    
+        tb.addColumn("creatorid" "createtime" "updaterid" "updatetime" "isvalid", [INT, DATETIME, INT, DATETIME, INT])
+        
+        UPDATE tb SET creatorid = 888888, createtime = now(), updaterid = null, updatetime = null, isvalid = 1
+    
+        conn = connect_mysql()
+        
+        odbc::execute(conn, "TRUNCATE TABLE " + table_name + "_dolphin")
+        
+        odbc::append(conn, tb, table_name + "_dolphin", false)
+        
+        conn.close()
+    
+    } else {
+    
+        db = get_local_database("fundit", table_name.split(".")[0])
+    
+        saveTable(db, tb, table_name.split(".")[1])
+    }
+    
+}
+
+/*
+ *  取指数周收益
+ *
+ *  get_index_weekly_rets("'FA00000WKG','FA00000WKH','IN0000007G'", 1990.01.01, today())
+ */
+def get_index_weekly_rets(index_ids, start_date, end_date) {
+
+    s_start_date = iif(start_date.isNull(), "", " AND price_date >= '" + start_date$STRING + "'")
+    s_end_date = iif(end_date.isNull(), "", " AND price_date <= '" + end_date$STRING + "'")
+
+    s_query = "SELECT factor_id AS index_id, year_week, price_date, factor_value AS cumulative_nav, ret_1w
+               FROM pfdb.cm_factor_performance_weekly
+               WHERE isvalid = 1
+                 AND factor_id IN (" + index_ids + ")" +
+                 s_start_date +
+                 s_end_date + "
+                 AND ret_1w IS NOT NULL
+               UNION
+               SELECT fund_id AS index_id, year_week, price_date, cumulative_nav, ret_1w
+               FROM mfdb.fund_performance_weekly
+               WHERE isvalid = 1
+                 AND fund_id IN (" + index_ids + ")" +
+                 s_start_date +
+                 s_end_date + "
+                 AND ret_1w IS NOT NULL
+               ORDER BY year_week"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+}
+
+
+/*
+ *  取基金周收益
+ *
+ *
+ *  get_fund_weekly_rets("'MF00003TMH','MF00003UQM'", 1990.01.01, null, true)
+ */
+def get_fund_weekly_rets(fund_ids, start_date, end_date, isFromMySQL) {
+
+    s_fund_id = iif(fund_ids.isNull(), "", " AND fund_id IN (" + fund_ids + ")")
+    s_start_date = iif(start_date.isNull(), "", " AND price_date >= '" + start_date$STRING + "'")
+    s_end_date = iif(end_date.isNull(), "", " AND price_date <= '" + end_date$STRING + "'")
+    
+    s_query = "SELECT fund_id, year_week, price_date, cumulative_nav, ret_1w
+               FROM mfdb.fund_performance_weekly
+               WHERE isvalid = 1 " + 
+                 s_fund_id + 
+                 s_start_date +
+                 s_end_date + "
+                 AND ret_1w IS NOT NULL
+               ORDER BY fund_id, year_week"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+}
+
+/*
+ *  取组合周收益
+ *  TODO: 增加从本地取数据的功能
+ *
+ *
+ *  get_portfolio_weekly_rets("166002,364640", 1990.01.01, today(), true)
+ */
+def get_portfolio_weekly_rets(portfolio_ids, start_date, end_date, isFromMySQL) {
+
+    s_portfolio_id = iif(portfolio_ids.isNull(), "", " AND portfolio_id IN (" + portfolio_ids + ")")
+
+    s_query = "SELECT portfolio_id, year_week, price_date, cumulative_nav, ret_1w
+               FROM pfdb.pf_portfolio_performance_weekly
+               WHERE isvalid = 1 " +
+                 s_portfolio_id + "
+                 AND ret_1w IS NOT NULL
+                 AND price_date BETWEEN '" + start_date$STRING + "' AND '" + end_date$STRING + "'
+               ORDER BY portfolio_id, year_week"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+}
+
+/*
+ *  取公私募基金月收益
+ *
+ *  get_fund_monthly_ret("'MF00003PW1','MF00003PW1'", 1990.01.01, today(), true)
+ */
+
+def get_fund_monthly_ret(fund_ids, start_date, end_date, isFromMySQL) {
+
+    yyyymm_start = start_date.temporalFormat("yyyy-MM")
+    yyyymm_end = end_date.temporalFormat("yyyy-MM")
+
+    if(isFromMySQL == true) {
+
+        ret_table_name = "mfdb.fund_performance"
+        
+        s_query = "SELECT fund_id, end_date, ret_1m AS ret, cumulative_nav AS nav, ret_ytd_a, ret_incep_a
+                   FROM " + ret_table_name + "
+                   WHERE fund_id IN (" + fund_ids + ")
+                      AND isvalid = 1
+                      AND ret_1m IS NOT NULL
+                      AND end_date BETWEEN '" + yyyymm_start + "' AND '" + yyyymm_end + "'
+                   ORDER BY fund_id, end_date"
+     
+        conn = connect_mysql()
+     
+        t = odbc::query(conn, s_query)
+     
+        conn.close()
+
+    } else {
+        
+        tb_local = load_table_from_local("fundit", "mfdb.fund_performance")
+
+        s_col = (sqlCol("fund_id"), sqlCol("end_date"), sqlColAlias(<ret_1m>, "ret"), sqlColAlias(<cumulative_nav>, "nav"), sqlCol("ret_ytd_a"), sqlCol("ret_incep_a"))
+
+        s_where = expr(<fund_id>, in, fund_ids.strReplace("'", "").split(","))
+        
+        t = sql(s_col, tb_local, s_where).eval()
+    
+    }
+
+    return t
+}
+
+/*
+ * 取无风险月度利率
+ *
+ * get_risk_free_rate("IN0000000M", 1990.01.01, today())
+ */
+def get_risk_free_rate(index_id, start_date, end_date) {
+    
+    return get_fund_monthly_ret(index_id, start_date, end_date, true)
+}
+
+
+/*
+ * 取基金最新收益及净值
+ *
+ * get_fund_latest_nav_performance("'HF000004KN','HF00018WXG'")
+ */
+def get_fund_latest_nav_performance(fund_ids, isFromMySQL) {
+
+    if(isFromMySQL == true) {
+    
+        s_query = "SELECT *
+                   FROM mfdb.fund_latest_nav_performance
+                   WHERE fund_id IN (" + fund_ids + ")
+                     AND isvalid = 1
+                     ORDER BY fund_id"
+
+        conn = connect_mysql()
+    
+        t = odbc::query(conn, s_query)
+    
+        conn.close()
+
+    } else {
+
+        tb_local = load_table_from_local("fundit", "mfdb.fund_latest_nav_performance")
+
+        s_col = sqlCol("*")
+
+        s_where = expr(<fund_id>, in, fund_ids.strReplace("'", "").split(","))
+        
+        t = sql(s_col, tb_local, s_where).eval()
+
+    }
+
+    return t
+
+}
+
+/*
+ * 取私募基金净值
+ *
+ * get_hedge_fund_nav_by_price_date("'HF000004KN','HF00018WXG'", 2024.05.01, true)
+ */
+def get_hedge_fund_nav_by_price_date(fund_ids, price_date, isFromMySQL) {
+
+    if(isFromMySQL == true) {
+
+        nav_table_name = "mfdb.nav"
+    
+        s_query = "SELECT fund_id, price_date, cumulative_nav
+                   FROM " + nav_table_name + "
+                   WHERE fund_id IN (" + fund_ids + ")
+                     AND isvalid = 1
+                     AND cumulative_nav > 0
+                     AND price_date >= '" + price_date$STRING + "'
+                   ORDER BY fund_id, price_date"
+    
+        conn = connect_mysql()
+    
+        t = odbc::query(conn, s_query)
+    
+        conn.close()
+    } else {
+    
+        tb_local = load_table_from_local("fundit", "mfdb.nav")
+
+        s_col = sqlCol("*")
+
+        s_where = [expr(<fund_id>, in, fund_ids.strReplace("'", "").split(",")), <price_date >= price_date>]
+        
+        t = sql(s_col, tb_local, s_where).eval()
+    
+    }
+
+    return t
+
+}
+
+
+/*
+ * 取指数因子点位
+ *
+ * get_index_nav_by_price_date("'IN00000008','FA00000WKG'", 2024.06.01)
+ */
+def get_index_nav_by_price_date(index_ids, price_date) {
+
+    s_query = "SELECT index_id, price_date, close AS cumulative_nav
+               FROM mfdb.market_indexes
+               WHERE index_id IN (" + index_ids + ")
+                 AND isvalid = 1
+                 AND close > 0
+                 AND price_date >= '" + price_date + "'
+               UNION
+               SELECT index_id AS index_id, price_date, index_value AS cumulative_nav
+               FROM mfdb.indexes_ty_index
+               WHERE index_id IN (" + index_ids + ")
+                 AND isvalid = 1
+                 AND index_value > 0
+                 AND price_date >= '" + price_date + "'
+               UNION
+               SELECT factor_id AS index_id, price_date, factor_value AS cumulative_nav
+               FROM pfdb.cm_factor_value
+               WHERE factor_id IN (" + index_ids + ")
+                 AND isvalid = 1
+                 AND factor_value > 0
+                 AND price_date >= '" + price_date + "'
+               ORDER BY price_date"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+
+}
+
+
+/*
+ * 取有效基金基本信息
+ *
+ * get_fund_info("'HF000004KN','HF00018WXG'")
+ */
+def get_fund_info(fund_ids) {
+
+    s_query = "SELECT fi.fund_id, fi.inception_date, fi.primary_benchmark_id AS benchmark_id, IFNULL(fi.initial_unit_value, 1) AS ini_value, fs.strategy, fs.substrategy
+               FROM mfdb.fund_information fi
+               INNER JOIN mfdb.fund_strategy fs ON fi.fund_id = fs.fund_id AND fs.isvalid = 1
+               WHERE fi.fund_id IN (" + fund_ids + ")
+               AND fi.isvalid = 1
+               ORDER BY fi.fund_id"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+
+}
+
+
+/*
+ * 取私募基金净值更新信息, 返回基金及其净值更新的最早净值日期
+ *
+ * get_fund_list_by_nav_updatetime(2024.07.19T10:00:00)
+ */
+def get_fund_list_by_nav_updatetime(updatetime) {
+
+    s_query = "SELECT fi.fund_id, MIN(nav.price_date) AS price_date
+               -- fi.inception_date, fi.primary_benchmark_id AS benchmark_id, IFNULL(fi.initial_unit_value, 1) AS ini_value, 
+               FROM mfdb.fund_information fi
+               INNER JOIN mfdb.nav ON fi.fund_id = nav.fund_id
+               WHERE fi.isvalid = 1
+                 AND nav.cumulative_nav > 0
+                 AND nav.updatetime >= '" + updatetime + "'
+               GROUP BY fi.fund_id
+               ORDER BY fi.fund_id"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+
+}
+
+
+/*
+ * 存私募基金净值到本地dolphindb
+ *
+ * save_hedge_fund_nav_to_local(tb_nav)
+ */
+def save_hedge_fund_nav_to_local(tb_nav) {
+
+    save_table(tb_nav, "mfdb.nav", false)
+
+}
+
+
+/*
+ * 存私募基金净值到本地dolphindb
+ *
+ * get_portfolio_holding_history("166002,364640")
+ */
+def get_portfolio_holding_history(portfolio_ids) {
+
+    s_query = "SELECT portfolio_id, holding_date, fund_id, amount, fund_share, ROUND(amount/fund_share, 6) as nav
+               FROM pfdb.pf_portfolio_fund_history
+               WHERE portfolio_id IN (" + portfolio_ids + ")
+                 AND isvalid = 1
+               ORDER BY portfolio_id, holding_date"
+
+    conn = connect_mysql()
+
+    t = odbc::query(conn, s_query)
+
+    conn.close()
+
+    return t
+
+}

+ 133 - 0
modules/fundCalculator.dos

@@ -0,0 +1,133 @@
+module fundit::fundCalculator
+/*
+ *   RBSA 计算
+ *   @param: ret: historical return (double) vector which contains the same number of return as index
+ *           index_ret: historical index returen matrix which each row is an index
+ *           isLongShort: bool
+ *   @return: table
+ * 
+ *   Create  20240703  模仿python代码在Dolphin中实现,具体计算逻辑完全不懂                          Joey
+ *                     原代码见: http://gogs.fundit.cn/FundIt/FinanceCalcPython/src/dev36/pf_scical/v1/calc_rbsa_use_osqp.py
+ *                     Python官方示例见:https://osqp.org/docs/examples/least-squares.html
+ *                     Dolphin官方示例见:https://docs.dolphindb.cn/zh/funcs/o/osqp.html
+ *                     取数据脚本:SELECT fund_id, GROUP_CONCAT(ret_1w SEPARATOR ' ')
+ *                                 FROM mfdb.`fund_performance_weekly` 
+ *                                 WHERE fund_id IN ( 'MF00003PW1', 'IN00000008', 'IN00000077', 'IN0000009M', 'IN0000007G')
+ *                                 AND year_week BETWEEN 202411 AND 202422
+ *                                 GROUP BY fund_id
+ *
+ */
+def cal_rbsa(ret, index_ret, isLongShort) {
+
+    // 窗口长度
+    m = ret.size()
+    // 指数个数
+    n = index_ret.cols()
+    
+    P0 = matrix(float, n, m+n)
+    P1 = concatMatrix([matrix(float, m, n), eye(m)])
+    P = concatMatrix([P0, P1], false)
+    q = array(float, m+n, (m+n)*10, 0)
+    
+    A0 = concatMatrix( [matrix(index_ret), -eye(m)])
+    A1 = concatMatrix( [matrix(take(1, n)).transpose(), matrix(float, 1, m)])
+    A2 = concatMatrix( [eye(n), matrix(float, n, m)])
+    A = concatMatrix( [A0, A1, A2], false)
+    
+    // join 1 是为了限制所有权重加总为100%
+    // 下限
+    lb =(ret join 1) join array(float, n, n*10, iif(isLongShort == false, 0, -2))
+    // 上限
+    ub=(ret join 1) join array(float, n, n*10, iif(isLongShort == false, 1, 2))
+    
+    res = osqp( q, P, A, lb, ub)
+    
+    return res
+ }
+
+/*
+ * 滚动 rbsa
+ * @param: ret: return table, at least with "date" and "ret" as columns
+ *         index_ret: index return pivot table, with "date" and all index ids as columns
+ *         isLongShort: boolean. true means weightings could be negative values
+ *         window: number of return in a window
+ *         step: rolling step
+ * @return: table, with "date", "status" and "weights" columns. "weights" contains space-delimited numbers
+ */
+def cal_rolling_rbsa(ret, index_ret, isLongShort, window, step) {
+
+
+    t = SELECT *
+        FROM ret INNER JOIN index_ret ON ret.date = index_ret.date
+        ORDER BY ret.date
+    t.nullFill!(0)
+
+    // 指数个数
+    n = index_ret.cols() - 1
+        
+    // 计算起始位置
+    i = t.size() % step
+
+    // 运行rbsa计算次数
+    cnt = (t.size() - i) / step
+    
+    tb = table(max(cnt,1):0, ["date", "status", "weights"], [STRING, STRING, STRING])
+
+    if(t.size() >= window && cnt > 0) {
+        do {
+    
+            v_ret = t.ret[i:(i+window)]
+            
+            t_index_ret = t.slice( i:(i+window), ret.cols(): )
+        
+            // 传入window个收益
+            res = cal_rbsa(v_ret, t_index_ret, isLongShort)
+    
+            // 取窗口内最后(新)的日期
+            tb.tableInsert(t.date[i+window-1], res[0], res[1][0:n].round(6).concat(" ")$STRING)
+    
+            // 往前推进step个收益
+            i = i + step
+            
+            cnt -= 1
+    
+        } while( cnt > 0)
+        
+    } else {
+    
+        tb.tableInsert(null, "error", "The number of joined returns must not be less than window size.")
+    }
+
+    return tb
+
+}
+
+
+
+
+/*
+ * 年化收益率计算(只支持月收益)
+ *
+ * date_rets 是个日期排正序的收益率表
+ */
+def cal_ret_annualized(date_rets, isGIPS) {
+
+    date_format = "y-M"
+    
+    t = SELECT fund_id, (1 + ret).prod() - 1 AS ret_a, end_date.max().datetimeParse(date_format) - end_date.min().datetimeParse(date_format) AS date_diff
+        FROM date_rets
+        GROUP BY fund_id
+   
+    // GIPS 规则是不够一年不年化
+    if(isGIPS == true) {
+    
+        UPDATE t SET ret_a = (1 + ret_a).pow(12 \ date_diff) - 1
+        WHERE date_diff > 12
+    } else {
+    
+        UPDATE t SET ret_a = (1 + ret_a).pow(12 \ date_diff) - 1
+    }
+
+    return t
+    
+}

+ 255 - 0
modules/returnCalculator.dos

@@ -0,0 +1,255 @@
+module fundit::returnCalculator
+use fundit::fundCalculator
+use fundit::dataPuller
+
+/*
+ *  批量计算私募基金收益
+ *
+ *
+ *  cal_hedge_fund_returns("'HF000004KN','HF00018WXG','HF000103EU'", true)
+ *
+ */
+def cal_hedge_fund_returns(fund_ids, isFromMySQL) {
+
+    // 用于保证老基金也能取到所有历史净值
+    very_old_price_date = 1990.01.01
+
+    // 基金基本信息,包括初始净值
+    tb_fund_info = get_fund_info(fund_ids)
+    
+    // 基金净值
+    tb_nav = get_hedge_fund_nav_by_price_date(fund_ids, very_old_price_date, isFromMySQL)
+    
+    // NOTE: mySQL currently uses calendar day, while the codes below takes business day. it might cause a few different numbers calcuated
+    tb_monthly_nav = SELECT fund_id, businessMonthEnd(price_date).month().last() AS end_date, price_date.last() AS price_date, cumulative_nav.last() AS cumulative_nav
+                     FROM tb_nav
+                     GROUP BY fund_id, businessMonthEnd(price_date)
+    
+    // 为了把不数据库里不存在的nav记录填空,不得不先做个pivot;然后才能正确计算ratios (ret_1m)
+    tb_rets_1m = (SELECT cumulative_nav FROM tb_monthly_nav PIVOT BY end_date, fund_id).ffill!().ratios()-1
+    
+    // 取被pivot掉的fund_Ids
+    v_col_name = tb_rets_1m.columnNames()[1:]
+    tb_tmp = tb_rets_1m.unpivot("end_date", v_col_name).rename!("valueType" "value", "fund_id" "ret_1m")
+                         
+    tb_rets = SELECT fund_id, end_date, ret_1m,
+                     (1 + ret_1m).mprod(3) - 1 AS ret_3m, (1 + ret_1m).mprod(6) - 1 AS ret_6m, (1 + ret_1m).mprod(12) - 1 AS ret_1y,
+                     (1 + ret_1m).mprod(24) - 1 AS ret_2y, (1 + ret_1m).mprod(36) - 1 AS ret_3y, (1 + ret_1m).mprod(48) - 1 AS ret_4y,
+                     (1 + ret_1m).mprod(60) - 1 AS ret_5y, (1 + ret_1m).mprod(120) - 1 AS ret_10y
+              FROM tb_tmp
+              // WHERE ret_1m IS NOT NULL
+              CONTEXT BY fund_id
+    
+    UPDATE tb_rets SET ret_1m_a = (1 + ret_1m).pow(12) - 1, ret_3m_a = (1 + ret_3m).pow(4) - 1, ret_6m_a = (1 + ret_6m).pow(2) - 1, ret_1y_a= ret_1y,
+                       ret_2y_a = (1 + ret_2y).pow(1\2) - 1, ret_3y_a = (1 + ret_3y).pow(1\3) - 1, ret_4y_a = (1 + ret_4y).pow(1\4) - 1, 
+                       ret_5y_a = (1 + ret_5y).pow(1\5) - 1, ret_10y_a = (1 + ret_10y).pow(1\10) - 1
+    
+    // ytd 不会用上面的CONTEXT BY语句实现
+    tb_ret_ytd = SELECT a.fund_id, a.end_date, a.price_date, a.cumulative_nav, -1 + a.cumulative_nav \ b.cumulative_nav AS ret_ytd, (a.cumulative_nav \ b.cumulative_nav).pow(12\(a.end_date - b.end_date)) - 1 AS ret_ytd_a
+                 FROM tb_monthly_nav a
+                 INNER JOIN tb_monthly_nav b ON a.fund_Id = b.fund_id 
+                   AND b.end_date = a.price_date.yearEnd().datetimeAdd(-1y).month()
+    
+    // since inception 不会用上面的CONTEXT BY语句实现
+    tb_ret_incep = SELECT a.fund_id, a.end_date, a.price_date,  cumulative_nav, -1 + cumulative_nav \ ini_value AS ret_incep
+                   FROM tb_monthly_nav a
+                   INNER JOIN tb_fund_info fi ON a.fund_id = fi.fund_id
+    
+    UPDATE tb_ret_incep SET ret_incep_a = (1 + ret_incep).pow(12\(end_date - end_date.first())) - 1 CONTEXT BY fund_Id
+    UPDATE tb_ret_incep SET ret_incep_a_gips = iif( end_date - end_date.first() < 12, ret_incep, ret_incep_a ), ret_incep_a_all = ret_incep_a CONTEXT BY fund_id
+    
+    // 只选需要更新的记录
+    tb_fund_performance = SELECT a.fund_id, a.end_date.datetimeFormat("yyyy-MM") AS end_date, c.price_date, c.cumulative_nav,
+                                 a.ret_1m, a.ret_1m_a, a.ret_3m, a.ret_3m_a, a.ret_6m, a.ret_6m_a,
+                                 a.ret_1y, a.ret_1y_a, a.ret_2y, a.ret_2y_a, a.ret_3y, a.ret_3y_a,
+                                 a.ret_4y, a.ret_4y_a, a.ret_5y, a.ret_5y_a, a.ret_10y, a.ret_10y_a,
+                                 b.ret_ytd, b.ret_ytd_a, c.ret_incep, c.ret_incep_a, c.ret_incep_a_all, c.ret_incep_a_gips
+                                 // , 123 AS creatorid, now() AS createtime, 123 AS updaterid, now() AS updatetime, 1 AS isvalid
+                          FROM tb_rets a 
+                          LEFT JOIN tb_ret_ytd b ON a.fund_id = b.fund_id AND a.end_date = b.end_date
+                          LEFT JOIN tb_ret_incep c ON a.fund_id = c.fund_id AND a.end_date = c.end_date
+                          WHERE c.price_date IS NOT NULL
+                          ORDER BY a.fund_id, c.price_date
+
+/*    
+    // 把这些数据写回mySQL数据表
+    save_table(tb_fund_performance, "mfdb.fund_performance", true)
+
+    // 把这些数据写到本地数据表
+    save_table(tb_fund_performance, "mfdb.fund_performance", false)
+*/
+
+    return tb_fund_performance
+}
+
+
+/*
+ *  批量计算私募基金周收益
+
+ *  TODO: 需要用每周最后一个交易日?
+ *
+ *  cal_hedge_fund_weekly_returns("'HF000004KN','HF00018WXG','HF000103EU'", true)
+ *
+ */
+def cal_hedge_fund_weekly_returns(fund_ids, isFromMySQL) {
+
+    // 用于保证老基金也能取到所有历史净值
+    very_old_price_date = 1990.01.01
+
+    tb_nav = get_hedge_fund_nav_by_price_date(fund_ids, very_old_price_date, isFromMySQL)
+
+    UPDATE tb_nav SET year_week = price_date.year()$STRING + (price_date.weekOfYear()$STRING).lpad(2, "0")
+    
+    tb_weekly_nav = SELECT fund_id, year_week, price_date.last() AS price_date, cumulative_nav.last() AS cumulative_nav
+                    FROM tb_nav
+                    GROUP BY fund_id, year_week
+                    ORDER BY fund_id, year_week
+    
+    // 这里选最简单的计算方式:不补任何净值空洞,净值前值日期不做任何限制
+    // TODO: 可以考虑将月收益也改为这种方式
+    tb_rets_1w = SELECT fund_id, year_week, price_date, cumulative_nav, cumulative_nav.ratios()-1 AS ret_1w 
+                 FROM tb_weekly_nav
+                 ORDER BY fund_id, year_week
+    
+    return tb_rets_1w
+
+}
+
+/*
+ *  批量计算私募基金区间收益
+ *  TODO: mySQL version 向前取4天,向后不做限制。这里的逻辑是向前取4个交易日
+ *
+ *  get_trailing_return(tb_last_nav, tb_nav, -7d, "ret_1w")
+ *
+ */
+def get_trailing_return(table_last_nav, table_nav, duration, return_column_name) {
+
+    tb =  SELECT a.fund_id, a.price_date.last() AS price_date, a.cumulative_nav.last() \ b.cumulative_nav.last() - 1 AS ret
+          FROM table_last_nav a
+          INNER JOIN table_nav b ON a.fund_id = b.fund_id 
+          WHERE b.price_date <= a.price_date.datetimeAdd(duration)
+            AND b.price_date >= a.price_date.datetimeAdd(duration).datetimeAdd(-4d).businessDay()
+          GROUP by a.fund_id
+          ORDER BY fund_id
+    tb.rename!("ret", return_column_name)
+
+    return tb    
+}
+
+/*
+ *  批量计算私募基金最新收益
+ *
+ *
+ *  cal_hedge_fund_weekly_returns("'HF000004KN','HF00018WXG','HF000103EU'", true)
+ *
+ */
+def cal_hedge_fund_latest_returns(fund_ids, isFromMySQL) {
+
+    // 用于保证老基金也能取到所有历史净值
+    very_old_price_date = 1990.01.01
+
+    tb_nav = get_hedge_fund_nav_by_price_date(fund_ids, very_old_price_date, isFromMySQL)
+    
+    tb_last_nav = SELECT fund_id, price_date.last() AS price_date, cumulative_nav.last() AS cumulative_nav
+                  FROM tb_nav
+                  GROUP BY fund_id
+                  ORDER BY fund_id
+    
+    // 近1期收益,对应mySQL fund_latest_nav_performance 中的 net_value_change
+    // 因为是倒序,所以算出来的 ratios() = n0 / n1, 要把它改换成 n1 / n0 - 1 的收益
+    tb_last_return = SELECT TOP 2 fund_id, price_date.first() AS price_date, price_date AS pre_preice_date,
+                                  cumulative_nav.first() AS cumulative_nav, 1\cumulative_nav.ratios() - 1 AS net_value_change
+                     FROM ( SELECT * FROM tb_nav ORDER BY price_date DESC )
+                     CONTEXT BY fund_id
+                     ORDER BY fund_id
+    tb_last_return = SELECT * FROM tb_last_return WHERE net_value_change IS NOT NULL
+
+
+    // 近1交易日收益
+    tb_1d = SELECT a.fund_id, a.price_date, a.cumulative_nav \ b.cumulative_nav - 1 AS ret_1d
+            FROM tb_last_nav a
+            INNER JOIN tb_nav b ON a.fund_id = b.fund_id AND b.price_date = a.price_date.datetimeAdd(-1d).businessDay()
+            ORDER BY fund_id
+
+    // 近1周、1/3/6月、1/2/3/4/5/10年收益
+    tb_1w = get_trailing_return(tb_last_nav, tb_nav, -7d, "ret_1w")
+    tb_1m = get_trailing_return(tb_last_nav, tb_nav, -1M, "ret_1m")
+    tb_3m = get_trailing_return(tb_last_nav, tb_nav, -3M, "ret_3m")
+    tb_6m = get_trailing_return(tb_last_nav, tb_nav, -6M, "ret_6m")
+    tb_1y = get_trailing_return(tb_last_nav, tb_nav, -1y, "ret_1y")
+    tb_2y = get_trailing_return(tb_last_nav, tb_nav, -2y, "ret_2y")
+    tb_3y = get_trailing_return(tb_last_nav, tb_nav, -3y, "ret_3y")
+    tb_4y = get_trailing_return(tb_last_nav, tb_nav, -4y, "ret_4y")
+    tb_5y = get_trailing_return(tb_last_nav, tb_nav, -5y, "ret_5y")
+    tb_10y = get_trailing_return(tb_last_nav, tb_nav, -10y, "ret_10y")
+
+    // ytd return
+    tb_ytd =  SELECT a.fund_id, a.price_date.last() AS price_date, a.cumulative_nav.last() \ b.cumulative_nav.last() - 1 AS ret_ytd
+              FROM tb_last_nav a
+              INNER JOIN tb_nav b ON a.fund_id = b.fund_id 
+              WHERE b.price_date < a.price_date.yearBegin()
+                AND b.price_date >= a.price_date.yearBegin().datetimeAdd(-4d)
+              GROUP by a.fund_id
+
+    // since inception return
+    tb_fund_info = get_fund_info(fund_ids)
+    tb_incep = SELECT a.fund_id, a.price_date, -1 + cumulative_nav \ ini_value AS ret_incep, fi.inception_date
+               FROM tb_last_nav a
+               INNER JOIN tb_fund_info fi ON a.fund_id = fi.fund_id
+    
+    // annulized since reception return
+    UPDATE tb_incep SET ret_incep_a = (1 + ret_incep).pow(365.25\(price_date-inception_date)) - 1
+    UPDATE tb_incep SET ret_incep_a_all = ret_incep_a,
+                        ret_incep_a_gips = iif((price_date-inception_date)<365, ret_incep, ret_incep_a)
+
+    // 最大回撤
+    tb_drawdown_1m = SELECT a.fund_id, max( 1 - b.cumulative_nav \ b.cumulative_nav.cummax() ) AS drawdown_1m
+                     FROM tb_last_return a
+                     INNER JOIN tb_nav b ON a.fund_id = b.fund_id
+                     WHERE b.price_date >= a.price_date.datetimeAdd(-1M)
+                     GROUP BY a.fund_id
+
+    tb_drawdown_3m = SELECT a.fund_id, max( 1 - b.cumulative_nav \ b.cumulative_nav.cummax() ) AS drawdown_3m
+                     FROM tb_last_return a
+                     INNER JOIN tb_nav b ON a.fund_id = b.fund_id
+                     WHERE b.price_date >= a.price_date.datetimeAdd(-3M)
+                     GROUP BY a.fund_id
+
+    tb_drawdown_incep = SELECT fund_id, max( 1 - cumulative_nav \ cumulative_nav.cummax() ) AS drawdown_incep
+                        FROM tb_nav GROUP BY fund_id
+
+    tb_rets = SELECT a.fund_id, a.price_date.datetimeFormat("yyyy-MM") AS end_date, a.price_date, a.pre_preice_date, a.cumulative_nav,
+                     a.net_value_change, d1.ret_1d, w1.ret_1w, m1.ret_1m, m3.ret_3m, m6.ret_6m,
+                     y1.ret_1y, y2.ret_2y, y3.ret_3y, y4.ret_4y, y5.ret_5y, y10.ret_10y,
+                     ytd.ret_ytd, incep.ret_incep, incep.ret_incep_a, incep.ret_incep_a_all, incep.ret_incep_a_gips,
+                     dd_m1.drawdown_1m AS maxdrawdown_1m, dd_m3.drawdown_3m AS maxdrawdown_3m,
+                     dd_incep.drawdown_incep AS maxdrawdown_incep,
+                     iif(dd_incep.drawdown_incep == 0, null,incep.ret_incep_a \ dd_incep.drawdown_incep) AS calmarratio_incep
+              FROM tb_last_return a
+              LEFT JOIN tb_1d d1 ON a.fund_id = d1.fund_id
+              LEFT JOIN tb_1w w1 ON a.fund_id = w1.fund_id
+              LEFT JOIN tb_1m m1 ON a.fund_id = m1.fund_id
+              LEFT JOIN tb_3m m3 ON a.fund_id = m3.fund_id
+              LEFT JOIN tb_6m m6 ON a.fund_id = m6.fund_id
+              LEFT JOIN tb_1y y1 ON a.fund_id = y1.fund_id
+              LEFT JOIN tb_2y y2 ON a.fund_id = y2.fund_id
+              LEFT JOIN tb_3y y3 ON a.fund_id = y3.fund_id
+              LEFT JOIN tb_4y y4 ON a.fund_id = y4.fund_id
+              LEFT JOIN tb_5y y5 ON a.fund_id = y5.fund_id
+              LEFT JOIN tb_10y y10 ON a.fund_id = y10.fund_id
+              LEFT JOIN tb_ytd ytd ON a.fund_id = ytd.fund_id
+              LEFT JOIN tb_incep incep ON a.fund_id = incep.fund_id
+              LEFT JOIN tb_drawdown_1m dd_m1 ON a.fund_id = dd_m1.fund_id
+              LEFT JOIN tb_drawdown_3m dd_m3 ON a.fund_id = dd_m3.fund_id
+              LEFT JOIN tb_drawdown_incep dd_incep ON a.fund_id = dd_incep.fund_id
+              ORDER BY a.fund_id
+
+    // 忽略掉非GIPS标准的所有年化收益字段(包括ytd_a)
+    UPDATE tb_rets SET ret_1y_a = ret_1y, ret_2y_a = (1 + ret_2y).pow(1\2) - 1, ret_3y_a = (1 + ret_3y).pow(1\3) - 1,
+                       ret_4y_a = (1 + ret_4y).pow(1\4) - 1, ret_5y_a = (1 + ret_5y).pow(1\5) - 1, ret_10y_a = (1 + ret_10y).pow(1\10) - 1
+
+
+    return tb_rets
+
+}
+