您好,登錄后才能下訂單哦!
USE MyDB
GO
/**********************************************************************************
*
* Author: Kinwar
* Create Date: 2015-4-X
* Description: 1) 匯總色紗網頁 & KMIS-ODM 的留位數據 并派送 E-mail 通知
* 2) 自動清除網頁色紗 & KMIS-ODM 的到期留位數據
*
* Parameters: 1) @DelayDate 清除超過多少天的留位 默認 40 天
* 2) @priorDate 提前多少天發送郵件 默認 5 天
* 3) @bIsSendEmail 是否需要發送郵件 默認 是
* 4) @bCleanPPCDyReserve 是否清除網頁跟單留位數據 默認 是
* 5) @bCleanPCDyReserve 是否清除 KMIS-ODM 留位數據 默認 是
*
**********************************************************************************/
CREATE PROCEDURE USP_CheckDyReserveTimeout
@DelayDate INT = 40,
@priorDate INT = 5,
@bIsSendEmail BIT = 0,
@bCleanPPCDyReserve BIT = 1,
@bCleanPCDyReserve BIT = 0
AS
BEGIN
/*
DECLARE @DelayDate INT = 40
DECLARE @priorDate INT = 5
DECLARE @bIsSendEmail BIT = 1
DECLARE @bCleanPPCDyReserve BIT = 0
DECLARE @bCleanPCDyReserve BIT = 0
*/
/* 測試模式 */
DECLARE @bIsTestMode BIT = 1
DECLARE @pSubjectText NVARCHAR(255) = ''
DECLARE @strProfile_name NVARCHAR(255) = ''
DECLARE @pBodyText NVARCHAR(max) = ''
DECLARE @pRecipients NVARCHAR(max) = ''
DECLARE @strHeadHTML NVARCHAR(MAX) = ''
DECLARE @strpcHTML NVARCHAR(MAX) = ''
DECLARE @strppcHTML NVARCHAR(MAX) = ''
DECLARE @MailSuffix NVARCHAR(20)
DECLARE @strEmail NVARCHAR(2000) = ''
DECLARE @strCRLF NVARCHAR(10)
SET @strCRLF = NCHAR(13) + NCHAR(10)
SET @MailSuffix = '@esquel.com'
SET NOCOUNT ON;
/* 匯總資料 --> e-mail */
/* 原則上一個庫存對應一個缸號, 故以缸號分組 */
IF @bIsSendEmail=1
BEGIN
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 開始匯總到期的色紗留位并發送 E-Mail ' + @strCRLF + @strCRLF
/* 網頁 跟單色紗留位 匯總 */
SELECT TOP 1000
id = IDENTITY(INT,1,1),
MAX(a.Color_code) AS Color_code,
a.Batch_no,
SUM(a.Reserve_Qty) AS Reserve_Qty,
MAX(a.Reserve_Time) AS Reserve_Time,
a.PPO_NO,
a.Operator,
MAX(a.Operator)+@MailSuffix AS OperatorMail
INTO #Temp_ppcDYReserve_Mail
FROM DB..ppcDyReserve a
INNER JOIN DB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE a.Flag='K' AND a.Status='1' AND a.Batch_no<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
b.Weight>0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND --b.Reserve_Weight>0 AND /* 由于之前網頁留位沒有同步過來,所以不能加這個條件 */
DATEDIFF(DD, Reserve_Time, GETDATE())>@DelayDate-@priorDate
GROUP BY a.PPO_NO, a.Batch_No, a.Operator
ORDER BY a.Operator, Reserve_Time DESC
SET @strppcHTML =
N'<H5>[網頁跟單] 留位即將到期數據:<br></H5>' +
N'<table border=1>' + --表示表邊框大細,0表示不可見,1,2,3依次小到大
N'<tr style="background-color:Silver">'+
N'<th><H5>序號</H5></th>'+ --<th>--</th>表示標題列將在單元格中居中并以粗體顯示,<td>--</td>
N'<th><H5>色號</H5></th>'+
N'<th><H5>缸號</H5></th>' +
N'<th><H5>留位重量</H5></th>' +
N'<th><H5>留位時間</H5></th>'+
N'<th><H5>訂單號</H5></th>'+
N'<th><H5>留位操作人</H5></th>' +
N'<th><H5>E-mail</H5></th></tr>' +
CAST (
(SELECT
td = '<font SIZE=2>'+CONVERT(NVARCHAR(10),id)+'</SIZE>', '',
td = '<font SIZE=2>'+Color_code+'</SIZE>', '',
td = '<font SIZE=2>'+Batch_no+'</SIZE>', '',
td = '<font SIZE=2>'+CONVERT(NVARCHAR(20),Reserve_Qty)+'</SIZE>', '',
td = '<font SIZE=2>'+CONVERT(NVARCHAR(16),Reserve_Time,120)+'</SIZE>', '',
td = '<font SIZE=2>'+PPO_NO+'</SIZE>', '',
td = '<font SIZE=2>'+Operator+'</SIZE>', '',
td = '<font SIZE=2>'+OperatorMail+'</SIZE>', ''
FROM #Temp_ppcDYReserve_Mail
--ORDER BY Operator, Reserve_Time DESC
FOR XML PATH('tr'), TYPE )
AS NVARCHAR(MAX) ) +
N'</table></br>' ;
SET @strppcHTML=replace(replace(@strppcHTML,'<','<'),'>','>')
PRINT @strppcHTML
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 完成匯總網頁到期的色紗... ' + @strCRLF + @strCRLF
/* ODM 色紗留位 匯總 */
SELECT TOP 1000
id = IDENTITY(INT,1,1),
a.Job_No,
MAX(a.Gk_No) AS Gk_No,
MAX(a.Yarn_Type) AS Yarn_Type,
MAX(a.Yarn_Count) AS Yarn_Count,
MAX(a.Color_Code) AS Color_Code,
a.Batch_No,
SUM(a.Reserve_Weight) AS Reserve_Weight_Count,
a.Operator,
MAX(a.Operator_Time) AS Operator_Time,
MAX(a.Operator)+@MailSuffix AS OperatorMail
INTO #Temp_pcDYReserve_Mail
FROM pcDYReserve a
INNER JOIN DB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE b.Batch_No<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
a.Status<>'C' AND a.Taken_Weight=0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND
b.Weight>0 AND --b.Reserve_Weight>0 AND /* 由于之前網頁留位沒有同步過來,所以不能加這個條件 */
DATEDIFF(DD, a.Update_Time, GETDATE())>@DelayDate-@priorDate
GROUP BY a.Job_No, a.Batch_No, a.Operator
ORDER BY a.Operator, Operator_Time DESC
SET @strpcHTML =
N'<H5>[KMIS-ODM] 留位即將到期數據:<br></H5>' +
N'<table border=1>' + --表示表邊框大細,0表示不可見,1,2,3依次小到大
N'<tr style="background-color:Silver">'+
N'<th><H5>序號</H5></th>'+ --<th>--</th>表示標題列將在單元格中居中并以粗體顯示,<td>--</td>
N'<th><H5>排單號</H5></th>'+
N'<th><H5>品名</H5></th>' +
N'<th><H5>紗類</H5></th>' +
N'<th><H5>紗支</H5></th>' +
N'<th><H5>色號</H5></th>' +
N'<th><H5>缸號</H5></th>' +
N'<th><H5>留位重量</H5></th>' +
N'<th><H5>留位操作人</H5></th>' +
N'<th><H5>留位時間</H5></th>' +
N'<th><H5>E-mail</H5></th></tr>' +
CAST (
(SELECT
td = '<font SIZE=2>'+CONVERT(NVARCHAR(10),id)+'</SIZE>', '',
td = '<font SIZE=2>'+Job_No+'</SIZE>', '',
td = '<font SIZE=2>'+Gk_No+'</SIZE>', '',
td = '<font SIZE=2>'+Yarn_Type+'</SIZE>', '',
td = '<font SIZE=2>'+Yarn_Count+'</SIZE>', '',
td = '<font SIZE=2>'+Color_Code+'</SIZE>', '',
td = '<font SIZE=2>'+Batch_No+'</SIZE>', '',
td = '<font SIZE=2>'+CONVERT(NVARCHAR(20),Reserve_Weight_Count)+'</SIZE>', '',
td = '<font SIZE=2>'+Operator+'</SIZE>', '',
td = '<font SIZE=2>'+CONVERT(NVARCHAR(16),Operator_Time,120)+'</SIZE>', '',
td = '<font SIZE=2>'+OperatorMail+'</SIZE>', ''
FROM #Temp_pcDYReserve_Mail
--ORDER BY Operator, Operator_Time
FOR XML PATH('tr'), TYPE )
AS NVARCHAR(MAX) ) +
N'</table></br>' ;
SET @strpcHTML=replace(replace(@strpcHTML,'<','<'),'>','>')
PRINT @strpcHTML
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 完成匯總 ODM 到期的色紗... ' + @strCRLF + @strCRLF
SET @strHeadHTML = N'<H5>Dear All,<br></H5> '
SET @strHeadHTML += N'<H5><br>本信件由 <<色紗網頁留位>> 監控系統自動發送。<br></H5>'
SET @strHeadHTML += N'<H5><br>詳細色紗留位統計數據,可連進本公司網址查詢:<br></H5>'
IF @bIsTestMode=1
SET @strHeadHTML += N'<H5>--> http://192.168.7.X/newweb/gkMIS/DyReserve/index.asp <br></H5>'
ELSE
SET @strHeadHTML += N'<H5>--> http://192.168.7.X/newweb/gkmis/DyReserve/index.asp <br></H5>'
SET @strHeadHTML += N'<H5>本次統計即將留位到期數據如下: <br></H5>'
SET @pBodyText = @strHeadHTML + @strppcHTML + @strpcHTML
/* 統計郵件列表 & 設置 SQL Profile_name */
IF @bIsTestMode=1
BEGIN
SET @strEmail = 'XX@esquel.com'
SET @strProfile_name = 'MSSQLProfile'
SET @pSubjectText = N'<<<溢達 [色紗留位] 監控系統警示通知>>> **測試狀態** ' + CONVERT(NVARCHAR(10), GETDATE(), 120)
END
ELSE
BEGIN
SELECT @strEmail += OperatorMail + ';' FROM (
SELECT DISTINCT OperatorMail FROM #Temp_ppcDYReserve_Mail
UNION ALL
SELECT DISTINCT OperatorMail FROM #Temp_pcDYReserve_Mail ) a
SET @strProfile_name = 'kmisdatabasemail'
SET @pSubjectText = N'<<<溢達 [色紗留位] 監控系統警示通知>>> ' + CONVERT(NVARCHAR(10), GETDATE(), 120)
END
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + ' 獲取郵件列表... ' + @strCRLF + @strCRLF + @strEmail
/* 發送郵件 */
EXEC msdb.dbo.sp_send_dbmail
@profile_name = @strProfile_name,
@recipients = @strEmail,
@body = @pBodyText,
@body_format = 'HTML',
@subject = @pSubjectText
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 完成匯總到期的色紗留位并成功發送 E-Mail... ' + @strCRLF + @strCRLF
END
/* 下面開始處理到期的色紗留位,系統自動清除 */
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 下面開始處理到期的色紗留位,系統將自動清除留位... ' + @strCRLF + @strCRLF
/* 處理 網頁跟單 中的留位數據 */
IF @bCleanPPCDyReserve=1
BEGIN
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 開始處理 網頁跟單 中的留位數據...' + @strCRLF + @strCRLF
/* 以缸號 統計 網頁留位數量 */
SELECT TOP 1000
a.Batch_no,
SUM(a.Reserve_Qty) AS Reserve_Qty
INTO #CET_Temp_ppcDyReserve_Total
FROM YarnStoreDB..ppcDyReserve a
INNER JOIN YarnStoreDB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE a.Flag='K' AND a.Status='1' AND a.Batch_no<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
b.Weight>0 AND b.Reserve_Weight>0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND
DATEDIFF(DD, Reserve_Time, GETDATE())>@DelayDate --@DelayDate
GROUP BY a.Batch_No
ORDER BY a.Batch_No
BEGIN TRANSACTION Tran_ppcDyReserve
BEGIN TRY
/* 更新公共庫存表 yarntotalstore */
UPDATE YarnStoreDB.dbo.yarntotalstore
SET Reserve_Weight = CASE WHEN ISNULL(a.Reserve_Weight,0) - ISNULL(b.Reserve_Qty,0) > 0 THEN
ISNULL(a.Reserve_Weight,0) - ISNULL(b.Reserve_Qty,0)
ELSE 0 END
FROM YarnStoreDB.dbo.yarntotalstore a
INNER JOIN #CET_Temp_ppcDyReserve_Total b ON a.batch_NO=b.Batch_No
WHERE a.Batch_no<>'N/A' AND (a.Stock_Type='寄存' OR a.Stock_Type='留用') AND
a.Weight>0 AND a.Reserve_Weight>0 AND a.warehouse_code='DY' AND a.yarn_sort='DY'
/* 清除到期的 PPC網頁留位 數據 */
DELETE FROM YarnStoreDB..ppcDyReserve
FROM YarnStoreDB..ppcDyReserve a
INNER JOIN YarnStoreDB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE a.Flag='K' AND a.Status='1' AND a.Batch_no<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
b.Weight>0 AND b.Reserve_Weight>0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND
DATEDIFF(DD, Reserve_Time, GETDATE())>@DelayDate --@DelayDate
COMMIT TRANSACTION Tran_ppcDyReserve
END TRY
BEGIN CATCH
SELECT ERROR_NUMBER() AS ErrorNumber
ROLLBACK TRANSACTION Tran_ppcDyReserve
END CATCH;
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 開始處理 網頁跟單 中的留位數據完成....' + @strCRLF + @strCRLF
END
/* 處理 ODM 中的留位數據 */
IF @bCleanPCDyReserve=1
BEGIN
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 開始處理 ODM 中的留位數據....' + @strCRLF + @strCRLF
/* 以缸號 統計 ODM 留位數量 */
SELECT TOP 1000
a.Batch_No,
SUM(a.Reserve_Weight) AS Reserve_Weight_Count
INTO #CET_Temp_pcDYReserve_Total
FROM pcDYReserve a
INNER JOIN YarnStoreDB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE b.Batch_No<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
a.Status<>'C' AND a.Taken_Weight=0 AND
b.Weight>0 AND b.Reserve_Weight>0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND
DATEDIFF(DD, a.Update_Time, GETDATE())>40
GROUP BY a.Batch_No
ORDER BY a.Batch_No
BEGIN TRANSACTION Tran_pcDyReserve
BEGIN TRY
/* 更新排單明細的留位pcArrangeDetail */
UPDATE pcArrangeDetail
--SET DY_Reserved_Qty = DY_Reserved_Qty-c.Reserve_Weight
SET DY_Reserved_Qty = 0
FROM pcArrangeMain a
INNER JOIN pcArrangeDetail b ON a.Job_ID=b.Job_ID
INNER JOIN dbo.pcDYReserve c ON b.Job_Item_Id=c.Job_Item_Id
INNER JOIN #CET_Temp_pcDYReserve_Total d ON c.Batch_No=d.Batch_No
WHERE b.Dy_Plan_Qty>0 AND b.Closed<>'Y' AND
ISNULL(a.Confirmed,'')<>'C' AND c.Reserve_Weight>0 AND
b.Color_Code<>'GREY' AND c.Status<>'C' AND c.Taken_Weight=0 AND c.Batch_No<>'N/A' AND
DATEDIFF(DD, c.Update_Time, GETDATE())>@DelayDate
/* 更新公共庫存表 yarntotalstore */
UPDATE YarnStoreDB.dbo.yarntotalstore
SET Reserve_Weight = CASE WHEN ISNULL(a.Reserve_Weight,0) - ISNULL(b.Reserve_Weight_Count,0) > 0 THEN
ISNULL(a.Reserve_Weight,0) - ISNULL(b.Reserve_Weight_Count,0)
ELSE 0 END
FROM YarnStoreDB.dbo.yarntotalstore a
INNER JOIN #CET_Temp_pcDYReserve_Total b ON a.batch_NO=b.Batch_No
WHERE a.Batch_No<>'N/A' AND (a.Stock_Type='寄存' OR a.Stock_Type='留用') AND
a.Weight>0 AND a.Reserve_Weight>0 AND a.warehouse_code='DY' AND a.yarn_sort='DY'
/* 更新取消標識 */
UPDATE pcDyReserve SET Status='C'
FROM pcDYReserve a
INNER JOIN YarnStoreDB..yarntotalstore b ON a.Batch_no=b.Batch_No
WHERE b.Batch_No<>'N/A' AND (b.Stock_Type='寄存' OR b.Stock_Type='留用') AND
a.Status<>'C' AND a.Taken_Weight=0 AND
b.Weight>0 AND b.Reserve_Weight>0 AND b.warehouse_code='DY' AND b.yarn_sort='DY' AND
DATEDIFF(DD, a.Update_Time, GETDATE())>40
COMMIT TRANSACTION Tran_pcDyReserve
END TRY
BEGIN CATCH
SELECT ERROR_NUMBER() AS ErrorNumber
ROLLBACK TRANSACTION Tran_pcDyReserve
END CATCH;
END
/* 清空臨時表 */
IF @bIsSendEmail=1
BEGIN
DROP TABLE #Temp_ppcDYReserve_Mail
DROP TABLE #Temp_pcDYReserve_Mail
END
IF @bCleanPPCDyReserve=1 DROP TABLE #CET_Temp_ppcDyReserve_Total
IF @bCleanPCDyReserve=1 DROP TABLE #CET_Temp_pcDYReserve_Total
PRINT CONVERT(NVARCHAR(10),GETDATE(),120) + N' 處理完成...' + @strCRLF + @strCRLF
SET NOCOUNT OFF;
END
GO
免責聲明:本站發布的內容(圖片、視頻和文字)以原創、轉載和分享為主,文章觀點不代表本網站立場,如果涉及侵權請聯系站長郵箱:is@yisu.com進行舉報,并提供相關證據,一經查實,將立刻刪除涉嫌侵權內容。