You can not select more than 25 topics
Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
427 lines
13 KiB
427 lines
13 KiB
/*
|
|
|
|
SELECT * FROM TAccessDict
|
|
WHERE FKey LIKE 'EmployeeWage%'
|
|
|
|
|
|
INSERT TAccessDict(FKey,FSequence,FName,FValueType,FDefaultValue,FIsPublic,FLevelMode)
|
|
SELECT 'EmployeeWage_Excellent',901,'优秀员工',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_WashHairs',902,'洗头数',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_Fine',903,'罚款',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_Cost',904,'成本',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_Subsidy',905,'补贴',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_ActBaseWage',906,'实发底薪',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_OrigBaseWage',907,'原底薪',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_ActWage',908,'实发工资',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_Memo',909,'备注',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_AttendDays',910,'出勤天数',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'EmployeeWage_ShouldAttendDays',911,'应出勤天数',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'WorkAge',912,'工龄',1,1,0,1
|
|
UNION ALL
|
|
SELECT 'WorkAgeWage',913,'工龄工资',1,1,0,1
|
|
|
|
|
|
INSERT TFunctionAccessDict(FFunctionName,FAccessKey,FDefaultValue)
|
|
SELECT 'WYSEmployeeWage',FKey,1
|
|
FROM TAccessDict
|
|
WHERE FKey LIKE 'EmployeeW%'
|
|
|
|
DELETE TFunctionAccessDict WHERE FFunctionName = 'WYSEmployeeWage'
|
|
|
|
*/
|
|
|
|
IF Object_id('PRptYSWageReportBase') IS NOT NULL
|
|
DROP PROC PRptYSWageReportBase
|
|
GO
|
|
|
|
CREATE PROCEDURE PRptYSWageReportBase
|
|
(
|
|
@IParam VARCHAR(8000)
|
|
)
|
|
AS
|
|
BEGIN
|
|
|
|
/*
|
|
EXEC dbo.PDropTempTables
|
|
|
|
|
|
DECLARE @IParam VARCHAR(8000)
|
|
SET @IParam='FromDate="2017-05-10"ToDate="2017-05-10"FromEmpNo=""ToEmpNo=""FromItemTypeNo=""ToItemTypeNo=""CompNo="001"IncChild="1"'
|
|
|
|
EXEC PRptWageReport03 @IParam
|
|
|
|
*/
|
|
|
|
DECLARE @CompId BIGINT
|
|
DECLARE @CompNo VARCHAR(1000)
|
|
DECLARE @Month CHAR(7)
|
|
DECLARE @FromDate CHAR(10)
|
|
DECLARE @ToDate CHAR(10)
|
|
DECLARE @EmpNo VARCHAR(1000)
|
|
DECLARE @DeptId BIGINT
|
|
DECLARE @DeptNo VARCHAR(30)
|
|
DECLARE @DelEmpVisible BIT
|
|
DECLARE @PosNo VARCHAR(1000)
|
|
|
|
SELECT @CompNo = ISNULL(dbo.FNGetParamValue(@IParam,'CompNo'),'')
|
|
SELECT @Month = CONVERT(CHAR(7),dbo.FNGetParamValue(@IParam,'Month'),23)
|
|
SELECT @EmpNo = ISNULL(dbo.FNGetParamValue(@IParam,'EmpNo'),'')
|
|
|
|
SELECT @DeptNo = ISNULL(dbo.FNGetParamValue(@IParam,'DeptNo'),'')
|
|
SELECT @PosNo = ISNULL(dbo.FNGetParamValue(@IParam,'PosNo'),'')
|
|
|
|
SELECT @DelEmpVisible = ISNULL(dbo.FNGetParamValue(@IParam,'DelEmpVisible'),1)
|
|
|
|
IF ISNULL(@CompNo,'') = ''
|
|
OR ISNULL(@Month,'') = ''
|
|
OR @FromDate > @ToDate
|
|
BEGIN
|
|
RETURN
|
|
END
|
|
|
|
|
|
SELECT @FromDate = @Month + '-01'
|
|
SELECT @ToDate = CONVERT(CHAR(10),DATEADD(DAY,-1,DATEADD(MONTH,1,@FromDate)),23)
|
|
|
|
|
|
SELECT @CompId = FId FROM TCompany WITH(NOLOCK) WHERE FNo = @CompNo
|
|
|
|
SELECT @DeptId = FId FROM TBasicType WITH(NOLOCK) WHERE FNo = @DeptNo
|
|
SELECT @DeptId = ISNULL(@DeptId,0)
|
|
/*
|
|
INSERT TYSEmployeeWage(FId,FEmpId,FMonth,FExcellent)
|
|
SELECT dbo.FNNewId(),E.FId,'2018-07',111
|
|
FROM TEmployee AS E
|
|
*/
|
|
|
|
CREATE TABLE #Result
|
|
(
|
|
EmpId BIGINT,
|
|
EmpNo VARCHAR(50),
|
|
EmpName VARCHAR(50),
|
|
PosName VARCHAR(50),
|
|
ItemCashPay DECIMAL(18,6) DEFAULT 0, --项目现金业绩
|
|
ItemCardPay DECIMAL(18,6) DEFAULT 0, --项目划卡业绩
|
|
ItemBigCashPay DECIMAL(18,6) DEFAULT 0, --大项目现金业绩
|
|
ItemBigCardPay DECIMAL(18,6) DEFAULT 0, --大项目划卡业绩
|
|
ItemSmallCashPay DECIMAL(18,6) DEFAULT 0, --小项目现金业绩
|
|
ItemSmallCardPay DECIMAL(18,6) DEFAULT 0, --小项目划卡业绩
|
|
CardAll DECIMAL(18,6) DEFAULT 0, --卡金业绩
|
|
GoodsCashPay DECIMAL(18,6) DEFAULT 0, --产品现金
|
|
GoodsCardPay DECIMAL(18,6) DEFAULT 0, --产品划卡
|
|
CashPay DECIMAL(18,6) DEFAULT 0, --总现金
|
|
Comm DECIMAL(18,6) DEFAULT 0, --提成
|
|
PerfBonus DECIMAL(18,6) DEFAULT 0, --超额奖
|
|
Excellent DECIMAL(18,6) DEFAULT 0, --优秀员工
|
|
WashHairs DECIMAL(18,6) DEFAULT 0,
|
|
Fine DECIMAL(18,6) DEFAULT 0, --罚款
|
|
Cost DECIMAL(18,6) DEFAULT 0, --成本
|
|
Subsidy DECIMAL(18,6) DEFAULT 0, --补贴
|
|
ActBaseWage DECIMAL(18,6) DEFAULT 0, --实发底薪
|
|
OrigBaseWage DECIMAL(18,6) DEFAULT 0, --原底薪
|
|
ActWage DECIMAL(18,6) DEFAULT 0, --实发工资
|
|
Memo VARCHAR(1000) DEFAULT '', --备注
|
|
AttendDays DECIMAL(18,6) DEFAULT 0, --出勤天数
|
|
ShouldAttendDays DECIMAL(18,6) DEFAULT 0, --应出勤天数
|
|
WorkAge DECIMAL(18,6) DEFAULT 0, --工龄
|
|
WorkAgeWage DECIMAL(18,6) DEFAULT 0 --工龄工资
|
|
)
|
|
|
|
|
|
CREATE TABLE #Company
|
|
(
|
|
FCompId BIGINT,
|
|
FCompNo VARCHAR(20)
|
|
)
|
|
|
|
INSERT #Company (FCompID,FCompNo)
|
|
VALUES(@CompId,'')
|
|
|
|
DECLARE @Error INT
|
|
EXEC @Error = PRptGenerateEmpPerf 0,@FromDate,@ToDate
|
|
IF @Error != 0
|
|
BEGIN
|
|
RETURN -1
|
|
END
|
|
|
|
--把所有符合条件的数据拿到临时表中 #EmpPerfDetail
|
|
SELECT A.*,
|
|
CAST('' AS VARCHAR(20)) AS FPayTypeCatg , /*支付大类(现金,卡,其他)*/
|
|
CAST('' AS VARCHAR(50)) AS FItemNo,
|
|
CAST('' AS VARCHAR(50)) AS FItemName,
|
|
CAST(0 AS BIGINT) AS FItemTypeId
|
|
INTO #EmpPerfDetail
|
|
FROM VEmpPerfDetail# AS A WITH(NOLOCK),#Company AS C
|
|
WHERE A.FWorkDate BETWEEN @FromDate AND @ToDate
|
|
AND C.FCompId = A.FCompId
|
|
-- AND A.FEmpId = E.FEmpId
|
|
|
|
|
|
--初始化员工表
|
|
--生成员工列表
|
|
SELECT A.FId AS FEmpId,A.FNo AS FEmpNo ,A.FName AS FEmpName,ISNULL(S.FName,'') AS FPosName
|
|
INTO #Employee
|
|
FROM TEmployee AS A WITH(NOLOCK)
|
|
LEFT JOIN TBasicType AS S ON S.FId = A.FPosId
|
|
INNER JOIN TEmployeeSub AS B ON B.FEmpId = A.FId AND B.FCompId = @CompId
|
|
WHERE A.FId != 0
|
|
|
|
--AND B.FCompID = @CompId
|
|
AND (@DeptId = 0 OR A.FDeptId = @DeptId)
|
|
AND (@PosNo = '' OR A.FPosId IN(
|
|
(SELECT FId FROM TBasicType WITH(NOLOCK) WHERE FKey = 'Position' AND FNo IN(SELECT Field FROM dbo.FNStrSplit(@PosNo))))
|
|
AND (@EmpNo = '' OR A.FNo IN (select Field from dbo.FNStrSplit(@EmpNo))) )
|
|
--AND (EXISTS(SELECT 1 FROM #EmpPerfDetail AS P WHERE P.FEmpId = A.FId)
|
|
-- OR EXISTS(SELECT 1 FROM TYSEmployeeWage AS S WITH(NOLOCK) WHERE S.FMonth))
|
|
AND A.FDeleted = 0
|
|
AND A.FState = 1
|
|
|
|
--初始化编号名称类别
|
|
EXEC PRptInitEmpPerfTempTable
|
|
|
|
--计算动态算法业绩
|
|
EXEC PRptCalcDynamicEmpComm @CompId,0
|
|
|
|
INSERT #Result(EmpId,EmpNo,EmpName,PosName)
|
|
SELECT FEmpId,FEmpNo,FEmpName,FPosName
|
|
FROM #Employee AS E
|
|
|
|
--大项目现金,大于100的就是大项目
|
|
--设置支付大类
|
|
UPDATE A
|
|
SET A.FPayTypeCatg = CASE WHEN ISNULL(S.FIsCashPerf,0) = 1 THEN 'Cash' --现金
|
|
WHEN (A.FPayTypeId IN(6) OR ISNULL(S.FIsAccount,0) = 1) THEN 'Card' --卡付
|
|
ELSE 'Other' END --支付大类, 2 现金,1 卡付, 3其他
|
|
FROM #EmpPerfDetail AS A,TPayAccount AS S WITH(NOLOCK)
|
|
-- LEFT JOIN TPayAccount AS S2 WITH(NOLOCK) ON S2.FId = S.FId
|
|
WHERE A.FPayTypeId = S.FId
|
|
|
|
UPDATE A
|
|
SET A.ItemCashPay = ISNULL(B.ItemCashPay,0),
|
|
A.ItemCardPay = ISNULL(B.ItemCardPay,0),
|
|
A.ItemBigCashPay = ISNULL(B.ItemBigCashPay,0),
|
|
A.ItemSmallCashPay = ISNULL(B.ItemSmallCashPay,0),
|
|
A.ItemBigCardPay = ISNULL(B.ItemBigCardPay,0),
|
|
A.ItemSmallCardPay = ISNULL(B.ItemSmallCardPay,0),
|
|
A.CardAll = ISNULL(B.CardAll,0),
|
|
A.GoodsCardPay = ISNULL(B.GoodsCardPay,0),
|
|
A.GoodsCashPay = ISNULL(B.GoodsCashPay,0),
|
|
A.CashPay = ISNULL(B.CashPay,0),
|
|
A.Comm = ISNULL(B.Comm,0)
|
|
FROM #Result AS A,
|
|
(SELECT FEmpId,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Cash' THEN FPerf END) AS ItemCashPay,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Card' THEN FPerf END) AS ItemCardPay,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Cash' AND FAmt >= 100 THEN FPerf END) AS ItemBigCashPay,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Cash' AND FAmt < 100 THEN FPerf END) AS ItemSmallCashPay,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Card' AND FAmt >= 100 THEN FPerf END) AS ItemBigCardPay,
|
|
SUM(CASE WHEN FCategory = 'Item' AND FPayTypeCatg = 'Card' AND FAmt < 100 THEN FPerf END) AS ItemSmallCardPay ,
|
|
SUM(CASE WHEN FCategory IN('CardSale','CardRchg','CourseSale','CoursePackSale') THEN FPerf END) AS CardAll,
|
|
SUM(CASE WHEN FCategory = 'Goods' AND FPayTypeCatg = 'Card' THEN FPerf END) AS GoodsCardPay ,
|
|
SUM(CASE WHEN FCategory = 'Goods' AND FPayTypeCatg = 'Cash' THEN FPerf END) AS GoodsCashPay ,
|
|
SUM(CASE WHEN FPayTypeCatg = 'Cash' THEN FPerf END) AS CashPay ,
|
|
SUM(FComm) AS Comm
|
|
FROM #EmpPerfDetail
|
|
GROUP BY FEmpId) AS B
|
|
WHERE A.EmpID = B.FEmpId
|
|
|
|
--超额奖
|
|
--设计师:25000--35000 提1%;35000-45000提1.5%,45000-55000提2%,55000以上提2.5%
|
|
--美容师:个人现金总业绩分段提,15000--20000提1%;20000-25000提2%,25000-35000提3%,35000以上提4%
|
|
--助理:20000-25000提0.5%,25000-30000提1%,30000-35000提1.5%,35000以上提2%
|
|
|
|
--PerfBonus
|
|
UPDATE #Result SET PerfBonus = 0
|
|
UPDATE A
|
|
SET A.PerfBonus = B.FBonus * A.CashPay
|
|
FROM #BonusSection AS B,#Result AS A
|
|
WHERE A.CashPay >= B.FFromValue AND A.CashPay < B.FToValue
|
|
|
|
|
|
UPDATE A
|
|
SET A.Excellent = B.FExcellent, --优秀员工
|
|
A.Fine = B.FFine, --罚款
|
|
A.Cost = B.FCost, --成本
|
|
A.Subsidy = B.FSubsidy, --补贴
|
|
A.ActBaseWage = B.FActBaseWage, --实发底薪
|
|
A.OrigBaseWage = B.FOrigBaseWage, --原底薪
|
|
A.ActWage = B.FActWage, --实发工资
|
|
A.Memo = B.FMemo, --备注
|
|
A.AttendDays = B.FAttendDays, --出勤天数
|
|
A.ShouldAttendDays = B.FShouldAttendDays, --应出勤天数
|
|
A.WorkAge = B.FWorkAge, --工龄
|
|
A.WorkAgeWage = B.FWorkAgeWage, --工龄工资
|
|
A.WashHairs = B.FWashHairs
|
|
FROM #Result AS A,TYSEmployeeWage AS B
|
|
WHERE A.EmpId = B.FEmpId
|
|
AND B.FMonth = @Month
|
|
|
|
SELECT * FROM #Result
|
|
SELECT SUM(ItemCashPay) AS ItemCashPay,
|
|
SUM(ItemCardPay) AS ItemCardPay,
|
|
SUM(ItemBigCashPay) AS ItemBigCashPay,
|
|
SUM(ItemSmallCashPay) AS ItemSmallCashPay,
|
|
SUM(ItemBigCardPay) AS ItemBigCardPay,
|
|
SUM(ItemSmallCardPay) AS ItemSmallCardPay,
|
|
SUM(CardAll) AS CardAll,
|
|
SUM(GoodsCardPay) AS GoodsCardPay,
|
|
SUM(GoodsCashPay) AS GoodsCashPay,
|
|
SUM(CashPay) AS CashPay,
|
|
SUM(Comm ) AS Comm,
|
|
SUM(Excellent) AS Excellent,
|
|
SUM(Fine) AS Fine,
|
|
SUM(Cost) AS Cost,
|
|
SUM(Subsidy) AS Subsidy,
|
|
SUM(ActBaseWage) AS ActBaseWage,
|
|
SUM(OrigBaseWage) AS OrigBaseWage,
|
|
SUM(ActWage) AS ActWage,
|
|
'' AS Memo,
|
|
SUM(AttendDays) AS AttendDays,
|
|
SUM(ShouldAttendDays) AS ShouldAttendDays,
|
|
SUM(WorkAge) AS WorkAge,
|
|
SUM(WorkAgeWage) AS WorkAgeWage
|
|
|
|
FROM #Result
|
|
END
|
|
|
|
GO
|
|
|
|
IF OBJECT_ID('PRptYSWageReport51') IS NOT NULL
|
|
DROP PROC PRptYSWageReport51
|
|
GO
|
|
CREATE PROC PRptYSWageReport51
|
|
(
|
|
@IParam VARCHAR(8000)
|
|
)
|
|
AS
|
|
BEGIN
|
|
CREATE TABLE #BonusSection
|
|
(
|
|
FIndex INT,
|
|
FFromValue DECIMAL(18,6),
|
|
FToValue DECIMAL(18,6),
|
|
FBonus DECIMAL(18,6)
|
|
)
|
|
INSERT #BonusSection(FIndex,FFromValue,FToValue,FBonus)
|
|
SELECT 1,25000,35000,0.005
|
|
UNION ALL
|
|
SELECT 2,35000,45000,0.015
|
|
UNION ALL
|
|
SELECT 3,45000,55000,0.02
|
|
UNION ALL
|
|
SELECT 3,55000,99999999,0.025
|
|
EXEC PRptYSWageReportBase @IParam
|
|
END
|
|
GO
|
|
|
|
|
|
IF OBJECT_ID('PRptYSWageReport52') IS NOT NULL
|
|
DROP PROC PRptYSWageReport52
|
|
GO
|
|
CREATE PROC PRptYSWageReport52
|
|
(
|
|
@IParam VARCHAR(8000)
|
|
)
|
|
AS
|
|
BEGIN
|
|
CREATE TABLE #BonusSection
|
|
(
|
|
FIndex INT,
|
|
FFromValue DECIMAL(18,6),
|
|
FToValue DECIMAL(18,6),
|
|
FBonus DECIMAL(18,6)
|
|
)
|
|
|
|
|
|
--助理:20000-25000提0.5%,25000-30000提1%,30000-35000提1.5%,35000以上提2%
|
|
INSERT #BonusSection(FIndex,FFromValue,FToValue,FBonus)
|
|
SELECT 1,25000,25000,0.005
|
|
UNION ALL
|
|
SELECT 2,25000,30000,0.001
|
|
UNION ALL
|
|
SELECT 3,30000,35000,0.015
|
|
UNION ALL
|
|
SELECT 3,35000,99999999,0.02
|
|
EXEC PRptYSWageReportBase @IParam
|
|
|
|
|
|
END
|
|
GO
|
|
|
|
|
|
IF OBJECT_ID('PRptYSWageReport53') IS NOT NULL
|
|
DROP PROC PRptYSWageReport53
|
|
GO
|
|
CREATE PROC PRptYSWageReport53
|
|
(
|
|
@IParam VARCHAR(8000)
|
|
)
|
|
AS
|
|
BEGIN
|
|
CREATE TABLE #BonusSection
|
|
(
|
|
FIndex INT,
|
|
FFromValue DECIMAL(18,6),
|
|
FToValue DECIMAL(18,6),
|
|
FBonus DECIMAL(18,6)
|
|
)
|
|
|
|
|
|
--美容师:个人现金总业绩分段提,15000--20000提1%;20000-25000提2%,25000-35000提3%,35000以上提4%
|
|
INSERT #BonusSection(FIndex,FFromValue,FToValue,FBonus)
|
|
SELECT 1,15000,20000,0.01
|
|
UNION ALL
|
|
SELECT 2,20000,25000,0.02
|
|
UNION ALL
|
|
SELECT 3,25000,35000,0.03
|
|
UNION ALL
|
|
SELECT 3,35000,99999999,0.4
|
|
EXEC PRptYSWageReportBase @IParam
|
|
|
|
|
|
END
|
|
GO
|
|
|
|
|
|
|
|
IF OBJECT_ID('PRptYSWageReport54') IS NOT NULL
|
|
DROP PROC PRptYSWageReport54
|
|
GO
|
|
CREATE PROC PRptYSWageReport54
|
|
(
|
|
@IParam VARCHAR(8000)
|
|
)
|
|
AS
|
|
BEGIN
|
|
CREATE TABLE #BonusSection
|
|
(
|
|
FIndex INT,
|
|
FFromValue DECIMAL(18,6),
|
|
FToValue DECIMAL(18,6),
|
|
FBonus DECIMAL(18,6)
|
|
)
|
|
|
|
EXEC PRptYSWageReportBase @IParam
|
|
END
|
|
GO
|
|
|
|
|
|
|
|
DECLARE @IParam VARCHAR(8000)
|
|
SET @IParam='FromDate="2018-07-01"Month="2018-07"FromEmpNo=""ToEmpNo=""FromItemTypeNo=""ToItemTypeNo=""CompNo="003"IncChild="1"'
|
|
|
|
/*
|
|
|
|
*/
|
|
|
|
|