379 lines
17 KiB
Transact-SQL
379 lines
17 KiB
Transact-SQL
|
||
ALTER TABLE dbo.Pipeline_WeldJoint DROP CONSTRAINT FK_Pipeline_Weldline_Base_Consumables
|
||
ALTER TABLE dbo.Pipeline_WeldJoint DROP CONSTRAINT FK_Pipeline_Weldline_Base_Consumables1
|
||
GO
|
||
ALTER TABLE dbo.Pipeline_WeldJoint ALTER COLUMN WeldSilkId NVARCHAR(200) NULL
|
||
GO
|
||
INSERT INTO Sys_ButtonToMenu(ButtonToMenuId,MenuId,ButtonName,ButtonEnName,SortIndex)
|
||
VALUES('5EFA45FD-D335-473A-B6A2-0EFB2D24E7D7','3ACE25CE-C5CE-4CEC-AD27-0D5CF1DF2F01','手动生成委托单','HandGenerate',1)
|
||
GO
|
||
|
||
ALTER VIEW [dbo].[View_Pipeline_WeldJoint]
|
||
AS
|
||
/************焊口信息视图*****************/
|
||
SELECT WeldJoint.WeldJointId,
|
||
WeldJoint.ProjectId,
|
||
WeldJoint.PipelineId,
|
||
WeldJoint.WeldJointCode,
|
||
dbo.Fun_GetParseInt(WeldJoint.WeldJointCode) AS ConvertWeldJoint,
|
||
WeldJoint.WeldTypeId,
|
||
WeldJoint.Material1Id,
|
||
WeldJoint.Material2Id,
|
||
WeldJoint.ANSISCH,
|
||
WeldJoint.Thickness,
|
||
WeldJoint.Dia,
|
||
WeldJoint.Size,
|
||
WeldJoint.JointAttribute,
|
||
WeldJoint.JointArea,
|
||
WeldJoint.WeldingMethodId,
|
||
WeldJoint.IsHotProess,
|
||
WeldJoint.WeldingLocationId,
|
||
WeldJoint.WeldMatId,
|
||
WeldJoint.WeldSilkId,
|
||
WeldJoint.GrooveTypeId,
|
||
WeldJoint.PipeSegment,
|
||
WeldJoint.PipeAssembly1Id,
|
||
WeldJoint.PipeAssembly2Id,
|
||
WeldJoint.PipeAssemblyCount,
|
||
WeldJoint.HeartNo1,
|
||
WeldJoint.HeartNo2,
|
||
WeldJoint.LastTemp,
|
||
WeldJoint.CellTemp,
|
||
WeldJoint.PrepareTemp,
|
||
WeldJoint.Electricity,
|
||
WeldJoint.SystemNumber,
|
||
WeldJoint.Remark,
|
||
WeldJoint.DoneDin,
|
||
WeldJoint.Voltage,
|
||
WeldJoint.TestPackageNo,
|
||
WeldJoint.WeldingDailyCode,
|
||
WeldJoint.WeldingDailyId,
|
||
WeldJoint.BackingWelderId,
|
||
WeldJoint.CoverWelderId,
|
||
WeldJoint.PipingClassId,
|
||
WeldJoint.Specification,
|
||
WeldJoint.CancelResult,
|
||
Project.ProjectCode,
|
||
Project.ProjectName,
|
||
Pipeline.PipelineCode,
|
||
Pipeline.InstallationId,
|
||
Pipeline.UnitId,
|
||
Pipeline.SingleNumber,
|
||
Pipeline.WorkAreaId,
|
||
WeldType.WeldTypeCode,
|
||
Material1.MaterialCode AS Material1Code,
|
||
Material2.MaterialCode AS Material2Code,
|
||
WeldingMethod.WeldingMethodCode,
|
||
WeldingLocation.WeldingLocationCode,
|
||
WeldMat.ConsumablesCode AS WeldMatCode,
|
||
--WeldSilk.ConsumablesCode AS WeldSilkCode,
|
||
'' AS WeldSilkCode,
|
||
GrooveType.GrooveTypeCode,
|
||
CASE WHEN WeldJoint.WeldingDailyId IS NULL THEN '否' ELSE '是' END AS Is_hjName,
|
||
CASE WHEN WeldJoint.IsHotProess=1 THEN '是' ELSE '否' END AS IsHotProessStr,
|
||
Components1.ComponentsCode AS ComponentsCode1,
|
||
Components2.ComponentsCode AS ComponentsCode2,
|
||
BackingWelder.WelderCode AS BackingWelderCode,
|
||
BackingWelder.WelderName AS BackingWelderName,
|
||
CoverWelder.WelderCode AS CoverWelderCode,
|
||
CoverWelder.WelderName AS CoverWelderName,
|
||
(CASE WHEN CoverWelder.WelderCode IS NOT NULL AND BackingWelder.WelderCode IS NOT NULL
|
||
THEN CoverWelder.WelderCode + '/' + BackingWelder.WelderCode
|
||
ELSE (ISNULL(CoverWelder.WelderCode,'') + ISNULL(BackingWelder.WelderCode,'')) END) AS WelderCode, --焊工
|
||
(CASE WHEN Material1.MaterialCode IS NOT NULL AND Material2.MaterialCode IS NOT NULL
|
||
THEN Material1.MaterialCode + '/' + Material2.MaterialCode
|
||
ELSE (ISNULL(Material1.MaterialCode,'') + ISNULL(Material2.MaterialCode,'')) END) AS MaterialCode, --材质
|
||
pipingClass.PipingClassCode,
|
||
CONVERT(VARCHAR(100), WeldingDaily.WeldingDate, 23) AS WeldingDate,
|
||
WeldJoint.IsCancel,
|
||
WeldJoint.IsGoldJoint,
|
||
WeldJoint.WPQId,wps.WPQCode,
|
||
WeldJoint.DetectionType,
|
||
WeldJoint.PageNum
|
||
FROM Pipeline_WeldJoint AS WeldJoint
|
||
LEFT JOIN Base_Project AS Project ON Project.ProjectId=WeldJoint.ProjectId
|
||
LEFT JOIN Pipeline_Pipeline AS Pipeline ON Pipeline.PipelineId = WeldJoint.PipelineId
|
||
LEFT JOIN Base_WeldType AS WeldType ON WeldType.WeldTypeId=WeldJoint.WeldTypeId
|
||
LEFT JOIN Base_Material AS Material1 ON Material1.MaterialId = WeldJoint.Material1Id
|
||
LEFT JOIN Base_Material AS Material2 ON Material2.MaterialId = WeldJoint.Material2Id
|
||
LEFT JOIN Base_WeldingMethod AS WeldingMethod ON WeldingMethod.WeldingMethodId=WeldJoint.WeldingMethodId
|
||
LEFT JOIN Base_WeldingLocation AS WeldingLocation ON WeldingLocation.WeldingLocationId=WeldJoint.WeldingLocationId
|
||
LEFT JOIN Base_Consumables AS WeldMat ON WeldMat.ConsumablesId=WeldJoint.WeldMatId
|
||
--LEFT JOIN Base_Consumables AS WeldSilk ON WeldSilk.ConsumablesId=WeldJoint.WeldSilkId
|
||
LEFT JOIN Base_GrooveType AS GrooveType ON GrooveType.GrooveTypeId=WeldJoint.GrooveTypeId
|
||
LEFT JOIN Base_Components AS Components1 ON Components1.ComponentsId = WeldJoint.PipeAssembly1Id
|
||
LEFT JOIN Base_Components AS Components2 ON Components2.ComponentsId = WeldJoint.PipeAssembly2Id
|
||
LEFT JOIN Welder_Welder AS BackingWelder ON BackingWelder.WelderId=WeldJoint.BackingWelderId
|
||
LEFT JOIN Welder_Welder AS CoverWelder ON CoverWelder.WelderId=WeldJoint.CoverWelderId
|
||
LEFT JOIN Pipeline_WeldingDaily AS WeldingDaily ON WeldingDaily.WeldingDailyId=WeldJoint.WeldingDailyId
|
||
LEFT JOIN Base_PipingClass AS pipingClass ON pipingClass.PipingClassId=WeldJoint.PipingClassId
|
||
LEFT JOIN dbo.WPQ_WPQList wps ON wps.WPQId=WeldJoint.WPQId
|
||
|
||
|
||
GO
|
||
|
||
|
||
ALTER PROC [dbo].[sp_rpt_JointComprehensive]
|
||
@projectId NVARCHAR(50),
|
||
@workAreaId NVARCHAR(50)=NULL,
|
||
@pipelineIds NVARCHAR(MAX) = NULL
|
||
|
||
AS
|
||
/**********焊口综合信息**********/
|
||
SELECT
|
||
weldJoint.WeldJointId,
|
||
weldJoint.ProjectId,
|
||
WorkArea.WorkAreaId,
|
||
WorkArea.WorkAreaCode,
|
||
weldJoint.SystemNumber,
|
||
weldJoint.TestPackageNo,
|
||
pipeline.SingleNumber,
|
||
pipeline.PipelineCode,
|
||
weldJoint.PipeSegment,--所属管段
|
||
(CASE WHEN weldJoint.JointAttribute='固定F' THEN 'F'+weldJoint.WeldJointCode ELSE 'S'+weldJoint.WeldJointCode END) AS WeldJointCode,
|
||
weldType.WeldTypeCode,
|
||
weldJoint.JointAttribute,
|
||
wl.WeldingLocationCode,
|
||
weldJoint.Dia,
|
||
weldJoint.Thickness,--壁厚
|
||
weldJoint.HeartNo1,
|
||
weldJoint.HeartNo2,
|
||
com1.ComponentsName AS PipeAssembly1,
|
||
com2.ComponentsName AS PipeAssembly2,
|
||
--material.MaterialCode,
|
||
mat1.MaterialCode AS MaterialCode1,
|
||
mat2.MaterialCode AS MaterialCode2,
|
||
cw.WelderCode AS CoverWelderCode,
|
||
fw.WelderCode AS BackingWelderCode,
|
||
WeldMethod.WeldingMethodName,
|
||
medium.MediumName,
|
||
weldingDaily.WeldingDate,
|
||
weldingDaily.WeldingDailyCode,
|
||
trust.TrustBatchCode,
|
||
--TrustBatchCode.DetectionRateCode,
|
||
--TrustBatchCode.AcceptLevel,
|
||
(CASE WHEN weldJoint.IsHotProess=1 THEN '是' ELSE '否' END) AS IsHotProess,
|
||
null as TrustBatchCode,
|
||
null as DetectionRateCode,
|
||
null as AcceptLevel,
|
||
nde.NDEDate AS CHT_CHECKDATE,
|
||
ndeItem.NDEReportNo,
|
||
CAST(CAST(ISNULL(weldJoint.Size,0) AS REAL) AS NVARCHAR(8)) AS JOT_Size,
|
||
WeldMaterialMat.ConsumablesCode AS WMT_MatCode,
|
||
WeldMaterialMat.ConsumablesName AS WMT_Matname,
|
||
weldJoint.WeldSilkId,
|
||
--WeldMaterialSilk.ConsumablesCode AS hsCode,
|
||
--WeldMaterialSilk.ConsumablesName AS hsname,
|
||
--WeldMaterialSilk.UserFlux,
|
||
weldJoint.Specification,
|
||
wps.WPQCode,ndttype.DetectionTypeCode,NULL AS HotReportCode,
|
||
|
||
(CASE WHEN (PointBatchItem.PointState='1' OR PointBatchItem.PointState='2') then '是' ELSE '否' END) AS if_dk
|
||
FROM Pipeline_WeldJoint AS weldJoint
|
||
LEFT JOIN Pipeline_Pipeline AS pipeline ON pipeline.PipelineId = weldJoint.PipelineId
|
||
LEFT JOIN Project_WorkArea AS WorkArea ON WorkArea.WorkAreaId = pipeline.WorkAreaId
|
||
LEFT JOIN Base_Material AS mat1 ON mat1.MaterialId = weldJoint.Material1Id
|
||
LEFT JOIN Base_Material AS mat2 ON mat2.MaterialId = weldJoint.Material2Id
|
||
LEFT JOIN Base_WeldingMethod AS WeldMethod ON WeldMethod.WeldingMethodId = weldJoint.WeldingMethodId
|
||
LEFT JOIN dbo.Base_WeldType weldType ON weldType.WeldTypeId = weldJoint.WeldTypeId
|
||
LEFT JOIN dbo.Base_WeldingLocation wl ON wl.WeldingLocationId = weldJoint.WeldingLocationId
|
||
LEFT JOIN Base_Medium AS medium ON medium.MediumId = pipeline.MediumId
|
||
LEFT JOIN Base_Components com1 ON com1.ComponentsId=weldJoint.PipeAssembly1Id
|
||
LEFT JOIN Base_Components com2 ON com2.ComponentsId=weldJoint.PipeAssembly2Id
|
||
LEFT JOIN Pipeline_WeldingDaily AS weldingDaily ON weldingDaily.WeldingDailyId = weldJoint.WeldingDailyId
|
||
LEFT JOIN dbo.WPQ_WPQList wps ON wps.WPQId = weldJoint.WPQId
|
||
left join Welder_Welder AS fw on weldJoint.BackingWelderId = fw.WelderId
|
||
left join Welder_Welder AS cw on weldJoint.CoverWelderId = cw.WelderId
|
||
LEFT JOIN Base_Consumables AS WeldMaterialMat ON WeldMaterialMat.ConsumablesId =weldJoint.WeldMatId
|
||
--LEFT JOIN Base_Consumables AS WeldMaterialSilk ON WeldMaterialSilk.ConsumablesId =weldJoint.WeldSilkId
|
||
LEFT JOIN Batch_PointBatchItem AS PointBatchItem ON PointBatchItem.WeldJointId =weldJoint.WeldJointId
|
||
LEFT JOIN dbo.Batch_PointBatch point ON point.PointBatchId = PointBatchItem.PointBatchId
|
||
LEFT JOIN dbo.Base_DetectionType ndttype ON ndttype.DetectionTypeId = point.DetectionTypeId
|
||
LEFT JOIN dbo.Batch_BatchTrustItem trustItem ON trustItem.PointBatchItemId = PointBatchItem.PointBatchItemId
|
||
LEFT JOIN dbo.Batch_BatchTrust trust ON trust.TrustBatchId = trustItem.TrustBatchId
|
||
LEFT JOIN dbo.Batch_NDEItem ndeItem ON ndeItem.TrustBatchItemId = trustItem.TrustBatchItemId
|
||
LEFT JOIN dbo.Batch_NDE nde ON nde.NDEID = ndeItem.NDEID
|
||
|
||
WHERE weldJoint.ProjectId=@projectId
|
||
AND(pipeline.WorkAreaId=@workAreaId OR @workAreaId IS NULL)
|
||
AND (CHARINDEX(weldJoint.PipelineId,@pipelineIds)>0 or @pipelineIds IS NULl)
|
||
--AND(pipeline.PipelineCode=@pipelineCode OR @pipelineCode IS NULl)
|
||
|
||
GO
|
||
|
||
|
||
|
||
ALTER VIEW [dbo].[View_Batch_PointBatchItem]
|
||
AS
|
||
/*************点口明细表*************/
|
||
SELECT PointBatchItem.PointBatchItemId,
|
||
PointBatchItem.PointBatchId,
|
||
PointBatch.ProjectId,
|
||
PointBatch.InstallationId,
|
||
PointBatch.UnitId,
|
||
PointBatch.PointBatchCode,
|
||
PointBatch.DetectionTypeId,
|
||
Pipeline.WorkAreaId,
|
||
PointBatchItem.WeldJointId,
|
||
PointBatchItem.PointState AS PState,
|
||
(CASE PointBatchItem.PointState WHEN '1' THEN '点口' WHEN '2' THEN '扩透' END) AS PointState,
|
||
--(CASE PointBatchItem.IsAudit WHEN 1 THEN '是' ELSE '否' END) AS PointIsAudit,
|
||
--(CASE WHEN PointBatchItem.IsAudit=1 THEN '是'
|
||
-- WHEN (PointBatchItem.IsAudit IS NULL OR PointBatchItem.IsAudit=0) AND PointBatchItem.PointState IS NOT NULL THEN '否'
|
||
-- WHEN (PointBatchItem.IsAudit IS NULL OR PointBatchItem.IsAudit=0) AND PointBatchItem.PointState IS NULL THEN '' END) AS PointIsAudit,
|
||
PointBatchItem.PointDate,--点口日期
|
||
PointBatchItem.RepairDate,--返修日期
|
||
PointBatchItem.CutDate,--切除日期
|
||
PointBatchItem.RepairRecordId,
|
||
PointBatchItem.IsBuildTrust,--是否委托
|
||
WorkArea.WorkAreaCode,--工区号
|
||
jot.WeldJointCode,--焊口号
|
||
jot.BackingWelderId AS WelderId, --焊工ID
|
||
jot.JointArea,--焊接区域
|
||
jot.Dia,
|
||
jot.Size,--实际寸径
|
||
WeldingDaily.WeldingDate,--焊接日期
|
||
jot.PipelineId, --管线ID
|
||
jot.Material1Id AS Mat, --材质
|
||
jot.Specification, --规格
|
||
weldType.Flag, --焊缝类型
|
||
Pipeline.PipelineCode, --管线号
|
||
PipingClass.PipingClassName, --管道等级
|
||
PointBatchItem.IsWelderFirst,
|
||
(CASE WHEN PointBatchItem.JLAudit IS NOT NULL THEN userJL.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS JLAudit,
|
||
(CASE WHEN PointBatchItem.GLGSAudit IS NOT NULL THEN userGLGS.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS GLGSAudit,
|
||
(CASE WHEN PointBatchItem.QTAudit IS NOT NULL THEN userQT.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS QTAudit,
|
||
(CASE WHEN jot.BackingWelderId!=jot.CoverWelderId THEN backingWelder.WelderCode+'/'+coverWelder.WelderCode ELSE backingWelder.WelderCode END) AS WelderCode, --焊工号
|
||
(CASE WHEN PointBatchItem.JLAudit IS NOT NULL AND PointBatchItem.GLGSAudit IS NOT NULL THEN 1 ELSE 0 END) AS IsPointAudit
|
||
FROM Batch_PointBatchItem AS PointBatchItem
|
||
LEFT JOIN Batch_PointBatch AS PointBatch ON PointBatch.PointBatchId=PointBatchItem.PointBatchId
|
||
LEFT JOIN Pipeline_WeldJoint AS jot ON jot.WeldJointId=PointBatchItem.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS Pipeline ON Pipeline.PipelineId=jot.PipelineId
|
||
LEFT JOIN dbo.Base_WeldType weldType ON weldType.WeldTypeId = jot.WeldTypeId
|
||
LEFT JOIN dbo.Welder_Welder backingWelder ON backingWelder.WelderId = jot.BackingWelderId
|
||
LEFT JOIN dbo.Welder_Welder coverWelder ON coverWelder.WelderId = jot.CoverWelderId
|
||
LEFT JOIN Project_WorkArea AS WorkArea ON WorkArea.WorkAreaId=Pipeline.WorkAreaId
|
||
LEFT JOIN Pipeline_WeldingDaily AS WeldingDaily ON WeldingDaily.WeldingDailyId=jot.WeldingDailyId
|
||
LEFT JOIN Base_PipingClass AS PipingClass ON PipingClass.PipingClassId=Pipeline.PipingClassId
|
||
LEFT JOIN dbo.Sys_User userJL ON userJL.UserId = PointBatchItem.JLAudit
|
||
LEFT JOIN dbo.Sys_User userGLGS ON userGLGS.UserId = PointBatchItem.GLGSAudit
|
||
LEFT JOIN dbo.Sys_User userQT ON userQT.UserId = PointBatchItem.GLGSAudit
|
||
|
||
|
||
GO
|
||
|
||
|
||
ALTER VIEW [dbo].[View_Batch_PointBatchItem]
|
||
AS
|
||
/*************点口明细表*************/
|
||
SELECT PointBatchItem.PointBatchItemId,
|
||
PointBatchItem.PointBatchId,
|
||
PointBatch.ProjectId,
|
||
PointBatch.InstallationId,
|
||
PointBatch.UnitId,
|
||
PointBatch.PointBatchCode,
|
||
PointBatch.DetectionTypeId,
|
||
Pipeline.WorkAreaId,
|
||
PointBatchItem.WeldJointId,
|
||
PointBatchItem.PointState AS PState,
|
||
(CASE PointBatchItem.PointState WHEN '1' THEN '点口' WHEN '2' THEN '扩透' END) AS PointState,
|
||
--(CASE PointBatchItem.IsAudit WHEN 1 THEN '是' ELSE '否' END) AS PointIsAudit,
|
||
--(CASE WHEN PointBatchItem.IsAudit=1 THEN '是'
|
||
-- WHEN (PointBatchItem.IsAudit IS NULL OR PointBatchItem.IsAudit=0) AND PointBatchItem.PointState IS NOT NULL THEN '否'
|
||
-- WHEN (PointBatchItem.IsAudit IS NULL OR PointBatchItem.IsAudit=0) AND PointBatchItem.PointState IS NULL THEN '' END) AS PointIsAudit,
|
||
PointBatchItem.PointDate,--点口日期
|
||
PointBatchItem.RepairDate,--返修日期
|
||
PointBatchItem.CutDate,--切除日期
|
||
PointBatchItem.RepairRecordId,
|
||
PointBatchItem.IsBuildTrust,--是否委托
|
||
WorkArea.WorkAreaCode,--工区号
|
||
jot.WeldJointCode,--焊口号
|
||
jot.BackingWelderId AS WelderId, --焊工ID
|
||
jot.JointArea,--焊接区域
|
||
jot.Dia,
|
||
jot.Size,--实际寸径
|
||
WeldingDaily.WeldingDate,--焊接日期
|
||
jot.PipelineId, --管线ID
|
||
jot.Material1Id AS Mat, --材质
|
||
jot.Specification, --规格
|
||
jot.JointAttribute,
|
||
weldType.Flag, --焊缝类型
|
||
Pipeline.PipelineCode, --管线号
|
||
PipingClass.PipingClassName, --管道等级
|
||
PointBatchItem.IsWelderFirst,
|
||
(CASE WHEN PointBatchItem.JLAudit IS NOT NULL THEN userJL.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS JLAudit,
|
||
(CASE WHEN PointBatchItem.GLGSAudit IS NOT NULL THEN userGLGS.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS GLGSAudit,
|
||
(CASE WHEN PointBatchItem.QTAudit IS NOT NULL THEN userQT.UserName ELSE (CASE WHEN PointBatchItem.PointState IS NOT NULL THEN '未审核' ELSE '' END) END) AS QTAudit,
|
||
(CASE WHEN jot.BackingWelderId!=jot.CoverWelderId THEN backingWelder.WelderCode+'/'+coverWelder.WelderCode ELSE backingWelder.WelderCode END) AS WelderCode, --焊工号
|
||
(CASE WHEN PointBatchItem.JLAudit IS NOT NULL AND PointBatchItem.GLGSAudit IS NOT NULL THEN 1 ELSE 0 END) AS IsPointAudit
|
||
FROM Batch_PointBatchItem AS PointBatchItem
|
||
LEFT JOIN Batch_PointBatch AS PointBatch ON PointBatch.PointBatchId=PointBatchItem.PointBatchId
|
||
LEFT JOIN Pipeline_WeldJoint AS jot ON jot.WeldJointId=PointBatchItem.WeldJointId
|
||
LEFT JOIN Pipeline_Pipeline AS Pipeline ON Pipeline.PipelineId=jot.PipelineId
|
||
LEFT JOIN dbo.Base_WeldType weldType ON weldType.WeldTypeId = jot.WeldTypeId
|
||
LEFT JOIN dbo.Welder_Welder backingWelder ON backingWelder.WelderId = jot.BackingWelderId
|
||
LEFT JOIN dbo.Welder_Welder coverWelder ON coverWelder.WelderId = jot.CoverWelderId
|
||
LEFT JOIN Project_WorkArea AS WorkArea ON WorkArea.WorkAreaId=Pipeline.WorkAreaId
|
||
LEFT JOIN Pipeline_WeldingDaily AS WeldingDaily ON WeldingDaily.WeldingDailyId=jot.WeldingDailyId
|
||
LEFT JOIN Base_PipingClass AS PipingClass ON PipingClass.PipingClassId=Pipeline.PipingClassId
|
||
LEFT JOIN dbo.Sys_User userJL ON userJL.UserId = PointBatchItem.JLAudit
|
||
LEFT JOIN dbo.Sys_User userGLGS ON userGLGS.UserId = PointBatchItem.GLGSAudit
|
||
LEFT JOIN dbo.Sys_User userQT ON userQT.UserId = PointBatchItem.GLGSAudit
|
||
|
||
|
||
|
||
GO
|
||
|
||
|
||
|
||
|
||
|
||
ALTER PROCEDURE [dbo].[SpGetNewCode]
|
||
@tableName VARCHAR(50),/*表名*/
|
||
@columnName VARCHAR(50),/*列名*/
|
||
@projectId NVARCHAR(50),/*项目*/
|
||
@prefix VARCHAR(50),/*流水号编码前缀*/
|
||
@returnVal NVARCHAR(50) OUTPUT
|
||
AS
|
||
/*获取一个新的流水号(后五位上增加)*/
|
||
DECLARE
|
||
@sql NVARCHAR(500),
|
||
@old NVARCHAR(50),
|
||
@newid VARCHAR(50),
|
||
@maxId NVARCHAR(50)/*已分配的最大值*/
|
||
SELECT @sql=N'SELECT @maxId=MAX('+@columnName+') from '+@tableName+' where ProjectId = ''' + @projectId + ''' and ' + @columnName+' like ' + '''%' + @prefix + '%'''
|
||
EXEC sp_executesql @sql, N'@maxId nvarchar(50) OUTPUT', @maxId OUTPUT
|
||
/*因为最后字串包括R1,K1,所以这么处理*/
|
||
SET @old=REVERSE(SUBSTRING(REVERSE(@maxId),1,CHARINDEX('-',REVERSE(@maxId))-1))
|
||
|
||
IF(@old IS NULL)
|
||
BEGIN
|
||
SET @newid=@prefix+'0001'
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
--表示为数字
|
||
IF(ISNUMERIC(@old)=1)
|
||
BEGIN
|
||
SET @newid = (SELECT MAX(LEFT(@old,4)))+1
|
||
SET @newid = @prefix +RIGHT('0000'+@newid,4)
|
||
END
|
||
ELSE
|
||
BEGIN
|
||
SET @old =SUBSTRING(@maxId,0,len(@maxId)-len(@old))
|
||
SET @newid = (SELECT MAX(RIGHT(@old,4)))+1
|
||
SET @newid = @prefix +RIGHT('0000'+@newid,4)
|
||
END
|
||
END
|
||
|
||
SET @returnVal=@newid
|
||
|
||
GO
|
||
|
||
|
||
|
||
|
||
|
||
|
||
|