2025-12-11T09:05:40.png
SQL Server版本


CREATE FUNCTION [dbo].[IPS_SplitToTable]
(
    @InputString NVARCHAR(MAX),
    @RowSplit CHAR(1)=';',  --拆分行的标识符
    @ColSplit CHAR(1)=','   --拆分列的标识符
)
RETURNS @ResultTable TABLE 
(
    LineNum INT,
    Value1 NVARCHAR(MAX),
    Value2 NVARCHAR(MAX)
)
AS
BEGIN
    -- 临时表存储按分号拆分的行
    DECLARE @Rows TABLE (RowNumber INT IDENTITY(1,1), RowData NVARCHAR(MAX));
    
    -- 按分号拆分字符串得到行
    INSERT INTO @Rows (RowData)
    SELECT value 
    FROM STRING_SPLIT(@InputString, @RowSplit)
    WHERE value <> ''; -- 排除空行
    
    -- 声明变量
    DECLARE @TotalRows INT = (SELECT COUNT(*) FROM @Rows);
    DECLARE @CurrentRow INT = 1;
    DECLARE @RowData NVARCHAR(MAX);
    DECLARE @Pos INT;
    
    -- 使用循环处理每一行
    WHILE @CurrentRow <= @TotalRows
    BEGIN
        -- 获取当前行数据
        SELECT @RowData = RowData 
        FROM @Rows 
        WHERE RowNumber = @CurrentRow;
        
        -- 查找逗号位置
        SET @Pos = CHARINDEX(@ColSplit, @RowData);
        
        -- 插入结果表
        INSERT INTO @ResultTable (LineNum, Value1, Value2)
        VALUES (
            @CurrentRow,
            -- 第一列:从开头到第一个逗号
            CASE WHEN @Pos > 0 THEN SUBSTRING(@RowData, 1, @Pos - 1) ELSE @RowData END,
            -- 第二列:从第一个逗号后到结尾
            CASE WHEN @Pos > 0 THEN SUBSTRING(@RowData, @Pos + 1, LEN(@RowData) - @Pos) ELSE NULL END
        );
        
        -- 移动到下一行
        SET @CurrentRow = @CurrentRow + 1;
    END
    
    RETURN;
END

HANA版本


CREATE FUNCTION "IPS_SplitToTable"
(
  InputStr NVARCHAR(100000),
  Split CHAR(1) DEFAULT ',',      --拆分行,默认以逗号分开 
  ColSplit CHAR(1) DEFAULT NULL    --拆分列,默认以横线分开
)
RETURNS TABLE("Val1" NVARCHAR(500),"Val2" NVARCHAR(500))
AS
BEGIN

  DECLARE InputStr2 NVARCHAR(100000);  
  
  InputStr2=:InputStr||',';

  --构建临时表结构
  TMP_DATA=SELECT :InputStr2 AS "Value" FROM DUMMY WHERE 1=2;
  
  WHILE LOCATE(:InputStr2,:Split) <> 0 DO
    IF SUBSTRING(:InputStr2,1,LOCATE(:InputStr2,:Split)-1) <> '' THEN
      TMP_DATA=
        SELECT "Value" FROM :TMP_DATA
        UNION ALL
        SELECT SUBSTRING(:InputStr2,0,LOCATE(InputStr2,:Split)-1) AS "Value" FROM DUMMY;
    END IF;
    InputStr2 := SUBSTRING(:InputStr2,LOCATE(:InputStr2,:Split)+1,LENGTH(:InputStr2)-LOCATE(:InputStr2,:Split));
  END WHILE;  
  
  IF ColSplit IS NULL THEN
    RETURN SELECT CAST("Value" AS NVARCHAR(500)) AS "Val1",CAST(NULL AS NVARCHAR(500)) AS "Val2" FROM :TMP_DATA;
  ELSE
    RETURN SELECT CAST(CASE WHEN LOCATE("Value",:ColSplit)=0 THEN "Value" ELSE SUBSTR_BEFORE("Value",:ColSplit) END AS NVARCHAR(500)) AS "Val1",
                  CAST(SUBSTR_AFTER("Value",:ColSplit) AS NVARCHAR(500)) AS "Val2" 
           FROM :TMP_DATA; 
  END IF;
END;

评论已关闭