Forráskód Böngészése

局部优化,<TAB>换成空格

Joey 1 hete
szülő
commit
18c23350a0
1 módosított fájl, 70 hozzáadás és 84 törlés
  1. 70 84
      modules/navCalculator.dos

+ 70 - 84
modules/navCalculator.dos

@@ -8,37 +8,37 @@ use fundit::dataPuller
  * 
  * 
  */
-def convert_transaction_to_snapshot(portfolio_ids) {
+def convert_transaction_to_snapshot(portfolio_ids, end_date) {
 
     // 取数据库中的持仓交易表
-	tb_transaction = get_portfolio_holding_history(portfolio_ids);
-	
+    tb_transaction = get_portfolio_holding_history(portfolio_ids);
+    
     // 所有交易日期
-	tb_date = SELECT DISTINCT portfolio_id, holding_date FROM tb_transaction;
+    tb_date = SELECT DISTINCT portfolio_id, holding_date FROM tb_transaction;
 
-	// 所有基金证券id
-	tb_id = SELECT DISTINCT portfolio_id, fund_id FROM tb_transaction;
+    // 所有基金证券id
+    tb_id = SELECT DISTINCT portfolio_id, fund_id FROM tb_transaction;
 
-	tmp = SELECT tb_date.portfolio_id, tb_date.holding_date, tb_id.fund_id FROM fj(tb_date, tb_id, 'portfolio_id');
+    tmp = SELECT tb_date.portfolio_id, tb_date.holding_date, tb_id.fund_id FROM ej(tb_date, tb_id, 'portfolio_id');
 
     // 取各交易日期时的持仓截面, Window Join 的上限设成-1d 是因为买入基金当日无收益,所以计算份额时要排除掉
-	tb = wj(tmp, tb_transaction.sortBy!('holding_date'), duration('-50y'):duration('-1d'), <[t.fund_share.sum() AS shares]>, ['portfolio_id', 'fund_id', 'holding_date']);
+    tb = wj(tmp, tb_transaction.sortBy!('holding_date'), duration('-50y'):duration('-1d'), <[t.fund_share.sum() AS shares]>, ['portfolio_id', 'fund_id', 'holding_date']);
 
-	tb.addColumn('nav', DOUBLE);
+    tb.addColumn('nav', DOUBLE);
     // 买入的基金份额记为0, 保留原始买入净值
-	UPDATE tb
-	SET shares = 0, nav = tb_transaction.nav
-	FROM ej(tb, tb_transaction, ['portfolio_id', 'holding_date', 'fund_id'],, isNull(tb.shares));
+    UPDATE tb
+    SET shares = 0, nav = tb_transaction.nav
+    FROM ej(tb, tb_transaction, ['portfolio_id', 'holding_date', 'fund_id'],, isNull(tb.shares));
 
-	// 删除没用的数据;防一手脏数据
-	DELETE FROM tb WHERE shares IS NULL OR shares.round(0) < 0;
+    // 删除没用的数据;防一手脏数据
+    DELETE FROM tb WHERE shares IS NULL OR shares.round(0) < 0;
 
-	// 补上个虚拟的未来截面,以免buy-n-hold的证券信息损失;用0当NAV也是没办法,DolphinDB不能SELECT出个全NULL的列
-	INSERT INTO tb
-	SELECT portfolio_id, today()+1, fund_id, fund_share.sum(), 0
-	FROM tb_transaction
-	GROUP BY portfolio_id, fund_id
-	HAVING fund_share.sum().round(0) > 0;
+    // 补上个虚拟的未来截面,以免buy-n-hold的证券信息损失;用0当NAV也是没办法,DolphinDB不能SELECT出个全NULL的列
+    INSERT INTO tb
+    SELECT portfolio_id, end_date, fund_id, fund_share.sum(), 0
+    FROM tb_transaction
+    GROUP BY portfolio_id, fund_id
+    HAVING fund_share.sum().round(0) > 0;
 
     return tb;
 
@@ -46,10 +46,11 @@ def convert_transaction_to_snapshot(portfolio_ids) {
 
 /*
  *  计算FOF类组合收益
- * 
+ *  NOTE: 与MySQL逻辑一致,用户界面输入的交易净值会被暂时忽略,因为我们无法确保同一基金同一时间被输入的净值是相同的;
+ *        忽略手工净值会导致收益不精确或无法计算的问题,但可能错误的净值将导致错误的结果,两害取其轻。
+ *  
  *  
  *  Create:  20240908 用于代替 sp_cal_portfolio_nav            Joey
- *                    TODO: 当用户手工输入同一基金同一时间的净值不同时,暂时用平均值代替(这会导致那个时间点附近的收益计算错误!)
  * 
  *  @param portfolio_ids <STRING>: 逗号分隔的组合ID
  *  @param start_date <DATE>: 持仓证券净值更新的起始日期
@@ -60,75 +61,59 @@ def convert_transaction_to_snapshot(portfolio_ids) {
  def cal_portfolio_return(portfolio_ids, start_date, cal_method) {
 
     // 取持仓截面
-    tb_snapshot = convert_transaction_to_snapshot(portfolio_ids).rename!('fund_id', 'sec_id');;
-
+    tb_snapshot = convert_transaction_to_snapshot(portfolio_ids, today()).rename!('fund_id', 'sec_id');
 
     // 取涉及到的所有基金证券最早持仓日期
     s_json = (SELECT sec_id, holding_date.min() AS price_date FROM tb_snapshot GROUP BY sec_id).toStdJson();
 
- 	// 取涉及到的所有基金证券有用净值
- 	// TODO: need consider inception date nav
- 	tb_nav = get_holding_nav(s_json);
-
- 	// Buggy DolphinDB, INSERT INTO Table1 (Columns) SELECT Columns FROM Table2 会报列数不匹配的奇葩错误
-    tb_dup = SELECT sec_id, holding_date, nav.mean().round(6) AS nav
-  	         FROM tb_snapshot
-             WHERE NOT EXISTS ( SELECT 1 FROM tb_nav WHERE sec_id = tb_snapshot.sec_id AND price_date = tb_snapshot.holding_date )
-             GROUP BY sec_id, holding_date;
-
-    // 为了把不数据库里不存在的nav记录填空,不得不先做个pivot;然后才能正确计算ratios (ret_1m)
-    if ( cal_method == 1) {
-
-        // 补一下用户手工输入的交净值
-        // this is the way to get around the problem mentioned above
-	    INSERT INTO tb_nav (sec_id, price_date, cumulative_nav) VALUES (tb_dup.sec_id, tb_dup.holding_date, tb_dup.nav);
+    // 取涉及到的所有基金证券有用净值
+    // TODO: need consider inception date nav
+    tb_nav = get_holding_nav(s_json);
 
-        // 统一叫NAV,省得麻烦
-		tmp_nav = (SELECT cumulative_nav AS nav FROM tb_nav PIVOT BY price_date, sec_id).ffill!(); 
+    // 补一下最新界面
+    tb_latest_snapshot = SELECT sec_id, holding_date, nav.mean().round(6) AS nav
+                         FROM tb_snapshot
+                         WHERE NOT EXISTS ( SELECT 1 FROM tb_nav WHERE sec_id = tb_snapshot.sec_id AND price_date = tb_snapshot.holding_date )
+                         GROUP BY sec_id, holding_date;
 
-    } else {
-
- 	    // 补一下用户手工输入的交净值
-     	INSERT INTO tb_nav (sec_id, price_date, nav) VALUES (tb_dup.sec_id, tb_dup.holding_date, tb_dup.nav);
-
-    	tmp_nav = (SELECT nav FROM tb_nav PIVOT BY price_date, sec_id).ffill!();
-    }
-    // 计算每期收益
-	tmp_rets = tmp_nav.ratios()-1;
-
-    // 取被pivot掉的fund_Ids
-    v_col_name = tmp_rets.columnNames()[1:]
-
-    // 横表变回竖表
-    tb_navs = tmp_nav.unpivot("price_date", v_col_name).rename!("valueType" "value", "sec_id" "nav");
-    tb_rets = tmp_rets.unpivot("price_date", v_col_name).rename!("valueType" "value", "sec_id" "ret");
-
-    // 清一下内存
-    tmp_rets = null;
-    tmp_nav = null;
-    tb_nav = null;
-    
-    // 清掉没用的空数据
-    DELETE FROM tb_navs WHERE nav IS NULL;
-    DELETE FROM tb_rets WHERE ret IS NULL;
+    // Buggy DolphinDB, INSERT INTO Table1 (Columns) SELECT Columns FROM Table2 会报列数不匹配的奇葩错误
+    // this is the way to get around it
+    INSERT INTO tb_nav (sec_id, price_date, cumulative_nav) VALUES (tb_latest_snapshot.sec_id, tb_latest_snapshot.holding_date, tb_latest_snapshot.nav);
 
     // 在各证券持仓时段中,填充所有无净值的但其它证券有净值的合理日期
     // 比如 2024-01-10 ~ 2024-01-20区间,组合持有基金A和基金B,基金A有每日净值
     // 而基金B只有01-12和01-19两期周五净值,那么基金B需要填充除这两天以外的所有日期
-    tb_id_oldest_date = SELECT portfolio_id, sec_id, holding_date.min() AS oldest_date FROM tb_snapshot GROUP BY portfolio_id, sec_id;
-    
-    tb_holdings = SELECT id.portfolio_id, r.price_date, id.sec_id, r.ret
-                       FROM tb_id_oldest_date id
-                       INNER JOIN tb_rets r ON id.sec_id = r.sec_id
-                       WHERE r.price_date >= id.oldest_date
-                       ORDER BY id.portfolio_id, r.price_date, id.sec_id;
+    tb_holding_date_range = SELECT portfolio_id, sec_id, holding_date.min() AS oldest_date, holding_date.max() AS latest_date
+                            FROM tb_snapshot GROUP BY portfolio_id, sec_id;
+    // 所有净值日期
+    tb_date = SELECT DISTINCT dr.portfolio_id, n.price_date
+              FROM tb_holding_date_range dr
+              INNER JOIN tb_nav n ON dr.sec_id = n.sec_id
+              WHERE n.price_date >= dr.oldest_date 
+                AND n.price_date <= dr.latest_date;
+
+    // 所有基金证券id
+    tb_id = SELECT DISTINCT portfolio_id, sec_id FROM tb_snapshot;
+
+    tb_holdings = SELECT id.portfolio_id, dt.price_date, id.sec_id, n.cumulative_nav, n.nav
+                  FROM tb_id id
+                  INNER JOIN tb_date dt ON id.portfolio_id = dt.portfolio_id
+                  INNER JOIN tb_holding_date_range dr ON dr.portfolio_id = id.portfolio_id AND dr.sec_id = id.sec_id 
+                  LEFT JOIN tb_nav n ON n.sec_id = id.sec_id AND n.price_date = dt.price_date
+                  WHERE dt.price_date >= dr.oldest_date AND dt.price_date <= dr.latest_date
+                  ORDER BY id.portfolio_id, dt.price_date, id.sec_id;
+    // 清一下内存
+    tb_nav = null;
 
-    tb_holdings.addColumn(['nav', 'shares', 'market_value', 'total_mkt_value', 'weight'], [DOUBLE, DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
+    // 为收益计算填充净值
+    UPDATE tb_holdings SET cumulative_nav = cumulative_nav.ffill(), nav = nav.ffill()
+    CONTEXT BY portfolio_id, sec_id;
 
-    // 更新各持仓日期的基金净值
-    UPDATE tb_holdings pr
-      SET nav = tb_navs.nav
-    FROM ej(tb_holdings, tb_navs, ['sec_id', 'price_date']);
+    tb_holdings.addColumn(['ret', 'shares', 'market_value', 'total_mkt_value', 'weight'], [DOUBLE, DOUBLE, DOUBLE, DOUBLE, DOUBLE]);
+
+    // 计算各持仓证券收益
+    UPDATE tb_holdings SET ret = (cumulative_nav.ratios()-1).round(6)
+    CONTEXT BY portfolio_id, sec_id;
 
     // 把交易日截面的份额数用于组合收益表
     UPDATE tb_holdings
@@ -141,8 +126,11 @@ def convert_transaction_to_snapshot(portfolio_ids) {
     CONTEXT BY portfolio_id, sec_id;
 
     // 计算各日期的持仓资产及总资产
-    UPDATE tb_holdings
-      SET market_value = (nav * shares).round(6);
+    if(cal_method == 1) {
+        UPDATE tb_holdings SET market_value = (cumulative_nav * shares).round(6);
+    } else {
+        UPDATE tb_holdings SET market_value = (nav * shares).round(6);
+    }
 
     UPDATE tb_holdings
       SET total_mkt_value = market_value.sum()
@@ -166,9 +154,7 @@ def convert_transaction_to_snapshot(portfolio_ids) {
     UPDATE tb_portfolio_ret SET nav = (1+ret).cumprod() WHERE nav IS NULL CONTEXT BY portfolio_id;
 
     // 删掉没有用的数据
-    DELETE FROM tb_portfolio_ret WHERE price_date > today();
-
-    // 尤其是私募基金,有很多冗余
+    DELETE FROM tb_portfolio_ret WHERE price_date >= today();
 
     return tb_portfolio_ret;
  }