# 数据库存储过程和自定义函数说明 # 分区脚本,需要先在SQL SERVER清空数据,手工创建多个NDF物理文件,2022,、2023、2024等 USE [BQ_SA] GO /****** Object: PartitionScheme [part_version_rang_schema] Script Date: 2023/10/8 8:48:30 ******/ CREATE PARTITION SCHEME [part_version_rang_schema] AS PARTITION [part_version_rang_func] TO ([PRIMARY], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2022], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2023], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2024], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2025], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2026], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2027], [2028], [2028], [2028], [2028], [2028], [2028], [2028], [2028], [2028], [2028], [2028], [2028]) GO USE [BQ_SA] GO /****** Object: PartitionFunction [part_version_rang_func] Script Date: 2023/10/8 8:49:27 ******/ DROP PARTITION FUNCTION [part_version_rang_func] GO /****** Object: PartitionFunction [part_version_rang_func] Script Date: 2023/10/8 8:49:27 ******/ CREATE PARTITION FUNCTION [part_version_rang_func](int) AS RANGE LEFT FOR VALUES (201801, 201802, 201803, 201804, 201805, 201806, 201807, 201808, 201809, 201810, 201811, 201812, 201901, 201902, 201903, 201904, 201905, 201906, 201907, 201908, 201909, 201910, 201911, 201912, 202001, 202002, 202003, 202004, 202005, 202006, 202007, 202008, 202009, 202010, 202011, 202012, 202101, 202102, 202103, 202104, 202105, 202106, 202107, 202108, 202109, 202110, 202111, 202112, 202201, 202202, 202203, 202204, 202205, 202206, 202207, 202208, 202209, 202210, 202211, 202212, 202301, 202302, 202303, 202304, 202305, 202306, 202307, 202308, 202309, 202310, 202311, 202312, 202401, 202402, 202403, 202404, 202405, 202406, 202407, 202408, 202409, 202410, 202411, 202412, 202501, 202502, 202503, 202504, 202505, 202506, 202507, 202508, 202509, 202510, 202511, 202512, 202601, 202602, 202603, 202604, 202605, 202606, 202607, 202608, 202609, 202610, 202611, 202612, 202701, 202702, 202703, 202704, 202705, 202706, 202707, 202708, 202709, 202710, 202711, 202712, 202801, 202802, 202803, 202804, 202805, 202806, 202807, 202808, 202809, 202810, 202811, 202812) GO # 脚本中数据[BJEDI],需要批量替换成EDI数据库名 # 例如:[10.62.103.22].[EDI] USE [BQ_SA] GO /****** Object: UserDefinedFunction [dbo].[func_splitstring] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE function [dbo].[func_splitstring] (@str nvarchar(max),@split varchar(10)) returns @t Table (c1 varchar(50) ) as begin declare @i int declare @s int set @i = 1 set @s = 1 while (@i > 0 ) begin set @i = charindex(@split ,@str,@s) if (@i > 0 ) begin insert @t(c1) values(substring(@str,@s,@i - @s)) end else begin insert @t(c1) values(substring(@str,@s, len (@str) - @s + 1 )) end set @s = @i + 1 end return end GO /****** Object: UserDefinedFunction [dbo].[func_splitstring_int] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO create function [dbo].[func_splitstring_int] (@str nvarchar(max),@split varchar(10)) returns @t Table (c1 int ) as begin declare @i int declare @s int set @i = 1 set @s = 1 while (@i > 0 ) begin set @i = charindex(@split ,@str,@s) if (@i > 0 ) begin insert @t(c1) values(substring(@str,@s,@i - @s)) end else begin insert @t(c1) values(substring(@str,@s, len (@str) - @s + 1 )) end set @s = @i + 1 end return end GO /****** Object: StoredProcedure [dbo].[p_get_bbac_jis_edi] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE proc [dbo].[p_get_bbac_jis_edi] as BEGIN TRY select * into #temp_bbac from ( SELECT * FROM [BJEDI].[dbo].[View_BBAC_JIS] /* select RIGHT( REPLACE(CONVERT(varchar(10), a.time , 23),'-',''),6) Version, a.time CreationTime , cast(B.productionNumber as varchar(50)) PN, cast(B.itemNumber as varchar(50)) LU, B.quantity Qty, cast( B.sequenceNumber as varchar(50)) SeqNumber, B.assemblyDate BeginDate, A.CarModelCode Extend4, A.productionPoint Site, A.BillNo Extend1, a.partType Extend2, a.LastSequence Extend3, A.MatchNumber AssemblyCode, A.BarCode [InjectionCode], (REPLACE(isnull(A.[productionNumber],''),' ','') + REPLACE(isnull(A.[itemNumber],''),' ','')) KeyCode from t_Edi_Actual a inner join t_Edi_Planned b on a.productionNumber=b.productionNumber and a.partType=b.partType */ ) a MERGE INTO Set_BBAC_SE_EDI a USING #temp_bbac b on b.PN=a.PN AND b.Version>a.VERSION when Matched then update set a.IsDeleted=1; MERGE INTO Set_BBAC_SE_EDI a USING #temp_bbac b on b.PN=a.PN AND b.Version=a.VERSION and a.LU=B.LU when NOT MATCHED then INSERT ( [Id] ,[KeyCode] ,[Version] ,[LU] ,[PN] ,[SeqNumber] ,[AssemblyCode] ,[InjectionCode] ,[Qty] ,[BeginDate] ,[CreationTime] ,[CreatorId] ,[IsDeleted] ,[Extend1] ,[Extend2] ,[Extend3] ,[Extend4] ,[lineStationCode] ,CustomerPartCodeNoSpace ) VALUES (newid() , KeyCode, Version, LU, PN, SeqNumber, [AssemblyCode] , [InjectionCode], Qty, BeginDate, CreationTime, newid(), 0, Extend1, Extend2, Extend3, Extend4, [lineStationCode], CustomerPartCodeNoSpace ); END TRY BEGIN CATCH SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage; END CATCH; DROP TABLE #temp_bbac GO /****** Object: StoredProcedure [dbo].[p_get_hbpo_jis_edi] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE proc [dbo].[p_get_hbpo_jis_edi] as BEGIN TRY select * into #temp_hbpo from ( SELECT * FROM [BJEDI].[dbo].[View_HBPO_JIS] --select [AddTime] CreationTime, [BillNo] SeqNumber, A.[Production no#] PN, [Shift no#] InjectionCode, [Date of JIS call] Version,[Part number] LU, --Quantity Qty,(REPLACE(isnull(A.[Production no#],''),' ','') + REPLACE(isnull([Part number],''),' ','')) KeyCode --from --t_MqDetail a --inner join --t_MqHead b --on a.[Production no#]=b.[Production no#] ) a MERGE INTO Set_HBPO_SE_EDI a USING #temp_hbpo b on b.PN=a.PN AND b.Version>a.VERSION when Matched then update set a.IsDeleted=1; MERGE INTO Set_HBPO_SE_EDI a USING #temp_hbpo b on b.PN=a.PN AND b.Version=a.VERSION and a.LU=B.LU when NOT MATCHED then INSERT ([Id] ,[KeyCode] ,[Version] ,[LU] ,[PN] ,[SeqNumber] ,[AssemblyCode] ,[InjectionCode] ,[Qty] ,[BeginDate] ,[CreationTime] ,[CreatorId] ,[IsDeleted] ,CustomerPartCodeNoSpace ) VALUES (newid() , KeyCode, Version, LU, PN, SeqNumber, '', InjectionCode, Qty, CreationTime, CreationTime, newid(), 0, CustomerPartCodeNoSpace ); END TRY BEGIN CATCH SELECT ERROR_NUMBER() AS ErrorNumber, ERROR_MESSAGE() AS ErrorMessage; END CATCH; DROP TABLE #temp_hbpo GO /****** Object: StoredProcedure [dbo].[p_Invoice_generation_change] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO -- ============================================= -- Author: -- Create date: -- Description: -- ============================================= CREATE PROCEDURE [dbo].[p_Invoice_generation_change] @invbillnum varchar(50), @groupNum varchar(max), @businessType varchar(50) AS BEGIN -- SET NOCOUNT ON added to prevent extra result sets from -- interfering with SELECT statements. SET NOCOUNT ON; UPDATE Set_BBAC_CAN_SA_DETAIL SET InvbillNum=@invbillnum FROM Set_BBAC_CAN_SA_DETAIL T1 INNER JOIN (select c1 from func_splitstring(@groupNum,',')) T2 ON T1.GroupNum=T2.c1 SET NOCOUNT OFF; END GO /****** Object: StoredProcedure [dbo].[p_reBuildIndex] Script Date: 2023/10/8 8:42:20 ******/ SET ANSI_NULLS ON GO SET QUOTED_IDENTIFIER ON GO CREATE proc [dbo].[p_reBuildIndex] as declare @statement NVARCHAR(1000) declare mycursor cursor for SELECT 'ALTER INDEX [' + ix.name + '] ON [' + s.name + '].[' + t.name + '] REBUILD WITH ( PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON, SORT_IN_TEMPDB = OFF, ONLINE = OFF )' as sqlStr FROM sys.indexes AS ix INNER JOIN sys.tables t ON t.object_id = ix.object_id INNER JOIN sys.schemas s ON t.schema_id = s.schema_id INNER JOIN (SELECT object_id , index_id , avg_fragmentation_in_percent, partition_number FROM sys.dm_db_index_physical_stats (DB_ID(), NULL, NULL, NULL, NULL) ) ps ON t.object_id = ps.object_id AND ix.index_id = ps.index_id INNER JOIN (SELECT object_id, index_id , COUNT(DISTINCT partition_number) AS partition_count FROM sys.partitions GROUP BY object_id, index_id ) pc ON t.object_id = pc.object_id AND ix.index_id = pc.index_id WHERE ps.avg_fragmentation_in_percent > 0 AND ix.name IS NOT NULL open mycursor fetch next from mycursor into @statement while(@@fetch_status=0) --如果数据集里一直有数据 begin EXEC sp_executesql @statement --select @statement fetch next from mycursor into @statement end close mycursor deallocate mycursor GO