實現樹樁類型結構及其相應的操作【增刪查改和移動】

一、創建樹樁結構對應的表

1、創建樹樁層次結構表

樹狀結構表採用鏈結構的設計方式,每個節點包含一個當前節點指針ID、下一節點指針ID,以及當前節點的相關信息:節點名稱、順序、有效性、是否為葉子、層次,以下為創建表結構的SQL語句

    CREATE TABLE [dbo].[dispatch_type_config](
     [type_id] [nvarchar](50) NOT NULL,
     [b_type_id] [nvarchar](50) NOT NULL,
     [type_name_cn] [nvarchar](200) NOT NULL,
     [type_name_tw] [nvarchar](200) NOT NULL,
     [type_name_en] [nvarchar](300) NOT NULL,
     [sort] [int] NOT NULL,
     [is_enable] [bit] NOT NULL,
     [belong_client] [bit] NULL,
     [is_leaf] [bit] NULL,
     [layer] [int] NOT NULL,
     CONSTRAINT [PK_dispatch_type_config] PRIMARY KEY CLUSTERED 
    (
     [type_id] ASC,
     [b_type_id] ASC
    )WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
    ) ON [PRIMARY]
    GO
    ALTER TABLE [dbo].[dispatch_type_config] ADD  CONSTRAINT [DF_dispatch_type_config_is_enable]  DEFAULT ((1)) FOR [is_enable]
    GO
    ALTER TABLE [dbo].[dispatch_type_config] ADD  CONSTRAINT [DF_dispatch_type_config_belong_client]  DEFAULT ((0)) FOR [belong_client]
    GO
    ALTER TABLE [dbo].[dispatch_type_config] ADD  CONSTRAINT [DF_dispatch_type_config_is_leaf]  DEFAULT ((1)) FOR [is_leaf]
    GO

2、創建樹樁葉子節點對應的信息配置表

樹狀葉子節點的信息配置表,是葉子節點才有的信息表,結合具體需求設計自己需要的欄位,以下為創建表結構的SQL語句

    CREATE TABLE [dbo].[dispatch_type_leaf](
     [dispatch_rowid] [nvarchar](50) NOT NULL,
     [ctrl_type] [nvarchar](50) NULL,
     [subject] [nvarchar](500) NULL,
     [context] [nvarchar](3000) NULL,
     [has_case] [bit] NULL,
     [is_show] [bit] NULL,
     CONSTRAINT [PK_dispatch_type_leaf] PRIMARY KEY CLUSTERED 
    (
     [dispatch_rowid] ASC
    )WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [PRIMARY]
    ) ON [PRIMARY]
    GO
    ALTER TABLE [dbo].[dispatch_type_leaf] ADD  CONSTRAINT [DF_dispatch_type_leaf_has_case]  DEFAULT ((0)) FOR [has_case]
    GO
    ALTER TABLE [dbo].[dispatch_type_leaf] ADD  CONSTRAINT [DF_dispatch_type_leaf_is_show]  DEFAULT ((1)) FOR [is_show]
    GO

二、獲取樹樁結構的數據

由於樹狀層次結構表採用了鏈結構的設計方式,因此要想獲得所有樹狀結構節點的數據需要採用循環inner join的方式,又因設限具體的層次數量,故而將循環inner join的SQL以字符串的形式先組合起來,然後再通過exec來獲取數據。

    -- [dbo].[dispatch_GetType] 'cn','0'
    ALTER  proc [dbo].[dispatch_GetType]
    (
      @language nvarchar(10),
      @bSetting nvarchar(10)
    )
    AS
    Begin
 
     declare @sql nvarchar(max)
     declare @select nvarchar(max)
     declare @from nvarchar(max)
     declare @where nvarchar(max)
     declare @orderby nvarchar(max)
     declare @pid nvarchar(20)
     declare @id nvarchar(20)
     declare @index int
     declare @num int
     declare @maxNum int
     set @sql=''
     select @maxNum=max(layer) from dispatch_type_config where is_leaf='1'
     declare _cursor cursor local for
     select distinct layer from dispatch_type_config where is_leaf='1'
     open _cursor
     fetch next from _cursor into @num
     while @@FETCH_STATUS=0
     begin
       set @index=1
       set @id=CONVERT(nvarchar,@index)
       set @select=' select A'+@id+'.[type_id] as type_id'+@id+' ,A'+@id+'.type_name_'+@language+' as type_name'+@id+' ,A'+@id+'.is_enable as is_enable'+@id+' ,A'+@id+'.sort as sort'+@id
       set @from=' from dispatch_type_config A'+@id
       if(@sql='') set @orderby=' order by sort'+@id
       set @index=@index+1
       while @index<=@num
       begin
       set @pid=@id
       set @id=CONVERT(nvarchar,@index)
       set @select=@select+' ,A'+@id+'.[type_id] as type_id'+@id+' ,A'+@id+'.type_name_'+@language+' as type_name'+@id+' ,A'+@id+'.is_enable as is_enable'+@id+' ,A'+@id+'.sort as sort'+@id
       set @from=@from+' inner join dispatch_type_config A'+@id+' on A'+@pid+'.[b_type_id]=A'+@id+'.[type_id] and A'+@pid+'.layer='+@pid+' and A'+@id+'.layer='+@id
       if(@sql='') set @orderby=@orderby+' ,sort'+@id
       set @index=@index+1
       end
       set @pid=@id
       while @index<=@maxNum
       begin
       set @id=CONVERT(nvarchar,@index)
       set @select=@select+' ,'''' as type_id'+@id+' ,'''' as type_name'+@id+' ,'''' as is_enable'+@id+' ,'''' as sort'+@id
       if(@sql='') set @orderby=@orderby+' ,sort'+@id
       set @index=@index+1
       end
   
       set @select=@select+' ,A'+@pid+'.[type_id] as dispatch_rowid ,B.has_case ,B.ctrl_type ,A'+@pid+'.b_type_id, A'+@pid+'.belong_client as dispatch_belong '
       set @from=@from+' left join dispatch_type_leaf B on A'+@pid+'.[type_id]=B.dispatch_rowid and B.is_show=''1'' '
       set @where=' where A'+@pid+'.is_leaf=''1'' '
       if(@bSetting='0') set @where=@where+' and  A'+@pid+'.is_enable=''1'' '
   
       if(@sql='') set @sql=@select+@from+@where
       else set @sql=@sql+' union '+@select+@from+@where
       fetch next from _cursor into @num
     end
 
     close _cursor
     deallocate _cursor
 
     set @sql=@sql+@orderby
     exec(@sql)
    End

三、將第二步獲取的樹狀結構數據轉換為zTree需要的JSON字符串

1、定義一個樹樁節點對應的json模板

private static string nodeModel = ""id":"{0}","pId":"{1}","bId":"{2}","name":"{3}","is_enable":"{4}","isParent":"{5}"{6}";

2、將DataTable轉換為JSON字符串

對於獲取的樹狀層次結構數據是以Row的形式,要想轉換為zTree需要的層次結構(父節點一條記錄,其子節點為N條記錄,每條子節點又有N條記錄……)的形式,故而需要逐層構造zTree需要的數據,首先需要確定根節點,然後依次是各個層次中的第一個節點(第一層中的第一個節點……,第N層中的第一個節點,……最後一層中的所有葉子節點),然後是各層中的第二個節點,……。因此採用遞歸的方式來處理,具體實現代碼如下:

        //對DataRow進行操作
        private void getDispatchItem(int n, List nums, List types, DataRow dr, StringBuilder sb)
        {
            if (n == 0) { return; }
            if (types[n - 1] != dr["type_id" + n.ToString()].ToString() || dr["type_id" + n.ToString()].ToString() == "")
            {
                getDispatchItem(n - 1, nums, types, dr, sb);
                types[n - 1] = dr["type_id" + n.ToString()].ToString().Trim();
                if (types[n - 1] == "") { return; }
                string pId = "", str = ","open":"true"";
                if (n >= 2) { pId = types[n - 2]; if (n >= 3) { str = ","open":"false""; } }
                //葉子節點或者沒有節點的父節點
                if (n == types.Count || dr["type_id" + (n + 1).ToString()].ToString() == "")
                {
                    sb.AppendFormat(nodeModel, dr["dispatch_rowid"].ToString(), pId, dr["b_type_id"].ToString(), dr["type_name" + n.ToString()].ToString(), dr["is_enable" + n.ToString()].ToString(), false, ","open":"false","type":"" + dr["ctrl_type"].ToString() + "","has_case":"" + dr["has_case"].ToString() + """);
                    //sb.AppendFormat(nodeModel, dr["dispatch_rowid"].ToString(), n == 1 ? "0" : types[n - 2], dr["b_type_id"].ToString(), dr["type_name" + n.ToString()].ToString(), false, ","open":"false","type":"" + dr["ctrl_type"].ToString() + "","has_case":"" + dr["has_case"].ToString() + """);
                }
                else
                {
                    //if (n == 1) { sb.AppendFormat(nodeModel, types[n - 1], "0", dr["type_id" + (n + 1).ToString()].ToString(), dr["type_name" + n.ToString()].ToString(), true, ","open":"true""); }
                    //else if (n == 2) { sb.AppendFormat(nodeModel, types[n - 1], types[n - 2], dr["type_id" + (n + 1).ToString()].ToString(), dr["type_name" + n.ToString()].ToString(), true, ","open":"true""); }
                    //else { sb.AppendFormat(nodeModel, types[n - 1], types[n - 2], dr["type_id" + (n + 1).ToString()].ToString(), dr["type_name" + n.ToString()].ToString(), true, ","open":"false""); }
                    sb.AppendFormat(nodeModel, types[n - 1], pId, dr["type_id" + (n + 1).ToString()].ToString(), dr["type_name" + n.ToString()].ToString(), dr["is_enable" + n.ToString()].ToString(), true, str);
                }
                sb.Append("},{");
            }
        }
        //對DataTable進行操作
        private string getDispatchTypeTree1(DataTable dt, string search)
        {
            string result = "";
            DataRow[] drc = dt.Select(search);
            if (drc.Length > 0)
            {
                int layer = (dt.Columns.Count - 5) / 4;
                List types = new List();
                List nums = new List();
                for (int n = 0; n < layer; n++) { types.Add(""); nums.Add(0); }
                StringBuilder sb = new StringBuilder("{");
                foreach (DataRow dr in drc)
                {
                    getDispatchItem(layer, nums, types, dr, sb);
                }
                result = sb.ToString().TrimEnd('{');
            }
            return result;
        }

四、對樹樁結構進行【增刪查改和移動操作】

實現對葉子節點的相關操作

1、增加葉子節點的操作

    --[dbo].[dispatch_GetType_Add] 'cn','525d9a53-bc37-5b9e-371a-8d76054cc2ef','0f39b6ba-0ad0-3fb8-df2d-9d187c69a4cb','049b50ab-bb57-9113-be36-34484409c2fb','新增节点'
    ALTER  proc [dbo].[dispatch_GetType_Add]
    (
      @language nvarchar(10),
      @pId nvarchar(50),
      @type_id nvarchar(50),
      @b_type_id nvarchar(50),
      @type_name nvarchar(200)
    )
    AS
    Begin Tran
 
     declare @sort int--子節點序號
     declare @layer int--子節點樹層
 
 
     --該節點如果為葉子節點,就改為非葉子(葉子節點滿足:dispatch_type_leaf有數據,並且is_show為true)
     if exists (select * from dispatch_type_config where [type_id]=@pId and is_leaf='1')
     begin
      select @sort=1,@layer=layer+1 from dispatch_type_config where [type_id]=@pId group by layer
      update dispatch_type_config set is_leaf='0' where [type_id]=@pId and is_leaf='1'--改為非葉子
      if exists (select * from dispatch_type_leaf where dispatch_rowid=@pId )--改為非葉子,將其節點數據先隱藏,當其子節點都刪除后,再還原
      begin
       update dispatch_type_leaf set is_show='0' where dispatch_rowid=@pId--改為非葉子
      end
     end
     else--非葉子節點才插入樹狀關係
     begin
      select @sort=count(*)+1,@layer=layer+1 from dispatch_type_config where [type_id]=@pId group by layer
      /****插入樹狀關係**********/
      insert into dispatch_type_config([type_id],b_type_id,type_name_cn,type_name_tw,type_name_en,sort,layer,is_leaf)
      select distinct [type_id],@type_id,type_name_cn,type_name_tw,type_name_en,sort,layer,is_leaf
      from dispatch_type_config where [type_id]=@pId
     end
 
     /****插入樹狀子節點**********/
     declare @type_name_cn nvarchar(200),@type_name_tw nvarchar(200),@type_name_en nvarchar(300)
     set @type_name_cn=@type_name+N'**修改**' set @type_name_tw=@type_name+N'**修改**' set @type_name_en=@type_name+N'**Modify**'
     if(@language='cn') set @type_name_cn=@type_name
     else if(@language='tw')set @type_name_tw=@type_name
     else if(@language='en') set @type_name_en=@type_name
     --插入樹狀子節點
     insert into dispatch_type_config(type_id,b_type_id,type_name_cn,type_name_tw,type_name_en,sort,layer,is_leaf)
     values(@type_id,@b_type_id,@type_name_cn,@type_name_tw,@type_name_en,@sort,@layer,'1')
     /******插入子節點對應的信息*****/
     --insert into dispatch_type_leaf(dispatch_rowid,ctrl_type,[subject],context,has_case,is_show)
     --values(@type_id,'common','','','0','1')
    If @@Error <> 0           
    Begin
     Rollback
     Return @@Error
    End    
    Commit Tran

2、刪除樹樁節點的操作

    -- [dbo].[dispatch_GetType_Delete] '0fed864e-1227-f9ac-1df8-c64e84627d0c'
    ALTER  proc [dbo].[dispatch_GetType_Delete]
    (
      @type_id nvarchar(50)
    )
    AS
    Begin Tran
     declare @is_leaf bit
     select top 1 @is_leaf=is_leaf from  dispatch_type_config where [type_id]=@type_id
     --如果為葉子節點
     if(@is_leaf='1')
     begin
      --如果該發文類型從未被使用過,則刪除
      if not exists(select * from dbo.dispatch_info where dispatch_rowid=@type_id)
      begin
       /****刪除樹狀子節點**********/
       delete dispatch_type_config where [type_id]=@type_id
       /****刪除子節點**********/
       delete dispatch_type_leaf where dispatch_rowid=@type_id
   
       declare @pId nvarchar(50)
       select top 1 @pId=[type_id] from  dispatch_type_config where b_type_id=@type_id
       declare @num int
       select @num=count(*) from  dispatch_type_config where [type_id]=@pId
       if(@num>=2)
       begin
        /****父節點中仍有子節點,刪除樹狀關係**********/
        delete dispatch_type_config where b_type_id=@type_id
       end
       else
       begin
        /***父節點中沒有子節點,就將父節點改為葉子節點***/
        update dispatch_type_config set is_leaf='1' where [type_id]=@pId--改為葉子節點
        if exists (select * from dispatch_type_leaf where dispatch_rowid=@pId )--改為葉子節點,并還原其隱藏的數據
        begin
         update dispatch_type_leaf set is_show='1' where dispatch_rowid=@pId--改為葉子節點
        end
       end
      end
      else--否則將葉子節點隱藏
      begin
       update dispatch_type_leaf set is_show='0' where dispatch_rowid=@type_id
      end
     end
     else---父節點,則遞歸刪除其子節點
     begin
      declare @tmp_type_id nvarchar(50)
      declare _cursor cursor local for 
      select b_type_id from dbo.dispatch_type_config where [type_id]=@type_id
  
      open _cursor
      fetch next from _cursor into @tmp_type_id
      while @@FETCH_STATUS=0
      begin
       exec [dbo].[dispatch_GetType_Delete] @tmp_type_id
       fetch next from _cursor into @tmp_type_id
      end
      close _cursor
      deallocate _cursor
     end
    If @@Error <> 0           
    Begin
     Rollback
     Return @@Error
    End    
    Commit Tran

3、查看樹樁節點的信息

    --[dbo].[dispatch_GetType_Item] '05b1077e-9e65-c6b1-0215-e961d3cb42f4'
    ALTER  proc [dbo].[dispatch_GetType_Item]
    (
      @type_id nvarchar(50)
    )
    AS
    Begin
     --該節點如果為葉子節點
     if exists (select * from dispatch_type_config where [type_id]=@type_id and is_leaf='1')
     begin
      select A.type_name_cn,A.type_name_en,A.type_name_tw,is_enable=isnull(A.is_enable,'1'),B.[subject],B.context,has_case=isnull(B.has_case,'0') 
      from dispatch_type_config A left join dispatch_type_leaf B on A.[type_id]=B.dispatch_rowid
      where A.[type_id]=@type_id
     end
     else
     begin
      select type_name_cn,type_name_en,type_name_tw,is_enable
      from dispatch_type_config
      where [type_id]=@type_id
     end
    end

4、編輯樹樁節點的操作

    ALTER  proc [dbo].[dispatch_GetType_Update]
    (
      @type_id nvarchar(50),
      @is_enable bit,
      @type_name_cn nvarchar(200),
      @type_name_en nvarchar(200),
      @type_name_tw nvarchar(200),
      @has_case bit,
      @subject nvarchar(500),
      @content nvarchar(3000)
    )
    AS
    Begin Tran
     update dispatch_type_config 
     set type_name_cn=@type_name_cn,type_name_en=@type_name_en,type_name_tw=@type_name_tw,is_enable=@is_enable
     where [type_id]=@type_id 
 
     --該節點如果為葉子節點
     if exists (select * from dispatch_type_config where [type_id]=@type_id and is_leaf='1')
     begin
      if exists (select * from dispatch_type_leaf where dispatch_rowid=@type_id)
      begin
       update dispatch_type_leaf set [subject]=@subject,context=@content,has_case=@has_case
       where dispatch_rowid=@type_id
      end
      else
      begin
       insert into dispatch_type_leaf(dispatch_rowid,ctrl_type,[subject],context,has_case)
       values(@type_id,'common',@subject,@content,@has_case)
      end
     end
 
    If @@Error <> 0           
    Begin
     Rollback
     Return @@Error
    End    
    Commit Tran

5、移動樹樁節點的操作

    ALTER  proc [dbo].[dispatch_GetType_Move]
    (
      @type_id nvarchar(50),
      @siblings_id nvarchar(50),
      @span int
    )
    AS
    Begin
     declare @sort int
     select @sort=sort from  dispatch_type_config where [type_id]=@type_id
 
     update dispatch_type_config set sort=@sort where [type_id]=@siblings_id
     update dispatch_type_config set sort=@sort+@span where [type_id]=@type_id
    End
原文地址:https://www.cnblogs.com/MasterYao/p/4440844.html