|
|
|
# 数据库存储过程和自定义函数说明
|
|
|
|
|
|
|
|
# 分区脚本,需要先在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]内置字符串分表
|
|
|
|
|
|
|
|
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
|
|
|
|
# EDI同步脚本脚本中数据[BJEDI],需要批量替换成EDI数据库名
|
|
|
|
# 例如:[10.62.103.22].[EDI]
|
|
|
|
|
|
|
|
# 自动同步BBAC_EDI数据
|
|
|
|
|
|
|
|
|
|
|
|
/****** Object: StoredProcedure [dbo].[p_bbac_edi] Script Date: 2023/10/20 14:06:21 ******/
|
|
|
|
SET
|
|
|
|
ANSI_NULLS ON
|
|
|
|
GO
|
|
|
|
SET
|
|
|
|
QUOTED_IDENTIFIER ON
|
|
|
|
GO
|
|
|
|
|
|
|
|
CREATE proc [dbo].[p_bbac_edi]
|
|
|
|
@begindate datetime,
|
|
|
|
@enddate datetime
|
|
|
|
AS
|
|
|
|
BEGIN
|
|
|
|
TRY
|
|
|
|
|
|
|
|
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
INTO
|
|
|
|
#temp_bbac
|
|
|
|
FROM
|
|
|
|
(
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
FROM
|
|
|
|
[10.60.5.60].[BJEDI].[dbo].[View_BBAC_JIS]
|
|
|
|
) 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
|
|
|
|
|
|
|
|
# 手工同步BBAC_EDI数据
|
|
|
|
|
|
|
|
/****** Object: StoredProcedure [dbo].[p_bbacimport] 手动同步BBAC,EDI数据 Script Date: 2023/10/20 14:06:21 ******/
|
|
|
|
SET
|
|
|
|
ANSI_NULLS ON
|
|
|
|
GO
|
|
|
|
SET
|
|
|
|
QUOTED_IDENTIFIER ON
|
|
|
|
GO
|
|
|
|
CREATE proc [dbo].[p_bbacimport]
|
|
|
|
@begindate datetime,
|
|
|
|
@enddate datetime
|
|
|
|
|
|
|
|
AS
|
|
|
|
BEGIN TRY
|
|
|
|
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
INTO
|
|
|
|
#temp_bbac
|
|
|
|
FROM
|
|
|
|
(
|
|
|
|
SELECT
|
|
|
|
RIGHT(REPLACE(CONVERT(varchar(10),
|
|
|
|
a.time,
|
|
|
|
23),
|
|
|
|
'-',
|
|
|
|
''),
|
|
|
|
6) AS Version,
|
|
|
|
ISNULL(a.time,
|
|
|
|
GETDATE()) AS CreationTime,
|
|
|
|
CAST(b.productionNumber AS varchar(50)) AS PN,
|
|
|
|
b.itemNumber AS LU,
|
|
|
|
b.quantity AS Qty,
|
|
|
|
CAST(b.sequenceNumber AS varchar(50)) AS SeqNumber,
|
|
|
|
ISNULL(b.assemblyDate,
|
|
|
|
GETDATE()) AS BeginDate,
|
|
|
|
a.CarModelCode AS Extend4,
|
|
|
|
a.productionPoint AS Site,
|
|
|
|
a.BillNo AS Extend1,
|
|
|
|
a.partType AS Extend2,
|
|
|
|
a.LastSequence AS Extend3,
|
|
|
|
a.BarCode AS InjectionCode,
|
|
|
|
b.总成号 AS AssemblyCode,
|
|
|
|
b.lineStationCode,
|
|
|
|
REPLACE(ISNULL(a.productionNumber,
|
|
|
|
''),
|
|
|
|
' ',
|
|
|
|
'') + REPLACE(ISNULL(a.itemNumber,
|
|
|
|
''),
|
|
|
|
' ',
|
|
|
|
'') AS KeyCode,
|
|
|
|
REPLACE(b.itemNumber,
|
|
|
|
' ',
|
|
|
|
'') AS CustomerPartCodeNoSpace
|
|
|
|
FROM
|
|
|
|
[10.60.5.60].[BJEDI].dbo.t_Edi_Actual AS a WITH (nolock)
|
|
|
|
INNER JOIN
|
|
|
|
[10.60.5.60].[BJEDI].dbo.t_Edi_Planned AS b WITH (nolock) ON
|
|
|
|
a.productionNumber = b.productionNumber
|
|
|
|
AND a.partType = b.partType
|
|
|
|
WHERE
|
|
|
|
a.AssemblyDate >= @begindate
|
|
|
|
AND a.AssemblyDate <= @enddate
|
|
|
|
|
|
|
|
|
|
|
|
) 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
|
|
|
|
# 自动同步HBPO_EDI数据
|
|
|
|
/****** Object: StoredProcedure [dbo].[p_hbpo_edi] 自动同步HBPO EDI数据 Script Date: 2023/10/20 14:06:21 ******/
|
|
|
|
SET
|
|
|
|
ANSI_NULLS ON
|
|
|
|
GO
|
|
|
|
SET
|
|
|
|
QUOTED_IDENTIFIER ON
|
|
|
|
GO
|
|
|
|
CREATE proc [dbo].[p_hbpo_edi]
|
|
|
|
@BeginDate varchar(50) ,
|
|
|
|
@EndDate varchar(50)
|
|
|
|
AS
|
|
|
|
BEGIN TRY
|
|
|
|
|
|
|
|
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
INTO
|
|
|
|
#temp_hbpo
|
|
|
|
FROM
|
|
|
|
(
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
FROM
|
|
|
|
[10.60.5.60].[BJEDI].[dbo].[View_HBPO_JIS]
|
|
|
|
) 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
|
|
|
|
|
|
|
|
# 手工同步HBPO_EDI数据
|
|
|
|
|
|
|
|
/****** Object: StoredProcedure [dbo].[p_importhbpo] 手工HBPO同步数据 Script Date: 2023/10/20 14:06:21 ******/
|
|
|
|
SET
|
|
|
|
ANSI_NULLS ON
|
|
|
|
GO
|
|
|
|
SET
|
|
|
|
QUOTED_IDENTIFIER ON
|
|
|
|
GO
|
|
|
|
|
|
|
|
|
|
|
|
CREATE proc [dbo].[p_importhbpo]
|
|
|
|
|
|
|
|
@BeginDate varchar(50) ,
|
|
|
|
@EndDate varchar(50)
|
|
|
|
|
|
|
|
|
|
|
|
AS
|
|
|
|
BEGIN TRY
|
|
|
|
SELECT
|
|
|
|
*
|
|
|
|
INTO
|
|
|
|
#temp_hbpo
|
|
|
|
FROM
|
|
|
|
(
|
|
|
|
SELECT
|
|
|
|
b.AddTime AS CreationTime,
|
|
|
|
b.BillNo AS SeqNumber,
|
|
|
|
a.[Production no.] AS PN,
|
|
|
|
b.[Shift no.] AS InjectionCode,
|
|
|
|
b.[Date OF JIS CALL] AS Version,
|
|
|
|
a.[Part number] AS LU,
|
|
|
|
a.Quantity AS Qty,
|
|
|
|
REPLACE(ISNULL(a.[Production no.],
|
|
|
|
N''),
|
|
|
|
' ',
|
|
|
|
'')
|
|
|
|
+ REPLACE(ISNULL(a.[Part number],
|
|
|
|
N''),
|
|
|
|
' ',
|
|
|
|
'')
|
|
|
|
AS KeyCode,
|
|
|
|
REPLACE(a.[Part number],
|
|
|
|
' ',
|
|
|
|
'') AS CustomerPartCodeNoSpace
|
|
|
|
FROM
|
|
|
|
[10.60.5.60].[BJEDI].dbo.t_MqDetail AS a WITH (nolock)
|
|
|
|
INNER JOIN
|
|
|
|
[10.60.5.60].[BJEDI].dbo.t_MqHead AS b WITH (nolock) ON
|
|
|
|
a.[Production no.] = b.[Production no.]
|
|
|
|
WHERE
|
|
|
|
b.[Date OF JIS CALL]>= @BeginDate
|
|
|
|
AND b.[Date OF JIS CALL]<= @EndDate
|
|
|
|
) 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
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|