--获取对账结算截止日期 if exists(select * from sysobjects where name='p_soa_getenddate' and xtype='p') drop procedure p_soa_getenddate go create procedure p_soa_getenddate ( @psjscode varchar(1), --0-经销结算1-代销结算2-联营结算3-租金结算 @psorgcode varchar(10), @psfinacode varchar(10), @pssupcode varchar(15), @pscontrno varchar(40), @psenddate varchar(10) output, @psmsg varchar(2000) output ) as declare @nssql nvarchar(4000) declare @optpaysoabyshop varchar(1) declare @optpaysoabyfina varchar(1) declare @sHasDz varchar(1) declare @slastdzdate varchar(10) declare @smonthlastday varchar(10) --上次对账日最后一天 declare @snextmonth1st varchar(10) --上次对账日次月第一天 declare @stheday varchar(2) declare @slastday varchar(2) declare @sjsperiod varchar(1) begin set @psenddate = '' --按门店结算对账选项 select @optpaysoabyshop=itemvalue from t_syscfg where section='SYSTEM' and itemname='PaySoaByShop' --按财务主体结算对账选项 select @optpaysoabyfina=itemvalue from t_syscfg where section='SYSTEM' and itemname='PaySoaByFina' if @psjscode in ('0', '1') --经代销对账 begin set @nssql = 'select @slastdzdate=isnull(max(enddate),'''') from t_paysoa_head where supcode=''' + @pssupcode + '''' if @optpaysoabyshop = '1' set @nssql = @nssql + ' and (orgcode=''' + @psorgcode + ''' or orgcode=''*'')' else if @optpaysoabyfina = '1' set @nssql = @nssql + ' and (finacode=''' + @psfinacode + ''' or finacode=''*'')' else set @nssql = @nssql + ' and orgcode=''*'' and finacode=''*''' if isnull(@pscontrno,'') <> '' set @nssql = @nssql + ' and contrno=''' + @pscontrno + '''' set @nssql = @nssql + ' and rzdate<>'''' and rzdate is not null' end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end /*查找该合同上次对账截止日期*/ exec sp_executesql @nssql,N'@slastdzdate varchar(10) output',@slastdzdate out if @@error<>0 begin set @psmsg = '获取上次对账结算日期出错' return(-1) end /*如果该合同没有对过账,则取合同或供应商的开始日期*/ if @slastdzdate = '' begin set @sHasDz = '0' if isnull(@pscontrno,'') <> '' --取合同开始日期 select @slastdzdate=bgndate from t_contract where contrno = @pscontrno else --取供应商开户日期 select @slastdzdate=opendate from t_supplier where supcode = @pssupcode end else set @sHasDz = '1' if isnull(@slastdzdate,'') = '' begin set @psmsg = '未获取到上次对账结算日期' return(-1) end /*若不按合同控制,则不控制结算期间*/ if isnull(@pscontrno,'') = '' begin select @psenddate=convert(varchar(10),getdate(),120) set @psmsg = '成功' return(1) end --取合同中的结算期间 select @sjsperiod=jsperiod from t_contract where contrno=@pscontrno /*0-无 1-月结 2-半月结 3-旬结 4-周结*/ if @sjsperiod = '0' begin select @psenddate=convert(varchar(10),getdate(),120) set @psmsg = '成功' return(1) end /*以下区分结算期间的不同,计算本次对账截止日期*/ --取上次对账月末日期 select @smonthlastday=convert(varchar(10),dateadd(day,-day(convert(datetime,@slastdzdate,120)),dateadd(month,1,convert(datetime,@slastdzdate,120))),120) --取上次对账次月月初日期 select @snextmonth1st=convert(varchar(10),dateadd(m, 1, convert(datetime,substring(@slastdzdate, 1, 8)+'01',120)),120) if @sjsperiod = '1' begin /* * 月结,区分合同是否对过帐,分别处理 * 如果对过账,则判断上次对账截止日期是否在月末日期上,如果不在,则取上次截止日期所在月的最后一天,否则取上次对账截止日的下月最后一天 * 如果没有对过账,则取合同开始日期所在月的最后一天 */ if (@sHasDz = '1') and (@slastdzdate = @smonthlastday) select @psenddate = convert(varchar(10),dateadd(day,-day(convert(datetime,@snextmonth1st,120)),dateadd(month,1,convert(datetime,@snextmonth1st,120))),120) else set @psenddate = @smonthlastday end else if @sjsperiod = '2' begin /* * 半月结,则查看上次对账日期是月底还是月中,分别处理 * 对于未对过账的合同,则看其开始日期在上半月还是下半月,分别处理 * 对于对过账,但是上次对账截止日期不是15号或月底的,处理方式与未对过账的合同相同 */ if (@sHasDz = '1') and ((@slastdzdate = @smonthlastday) or (@slastdzdate = substring(@slastdzdate, 1, 8) + '15')) /*如果是月底,则取下个月的15号;否则取月底那一天*/ if (@slastdzdate = @smonthlastday) set @psenddate = substring(@snextmonth1st, 1, 8) + '15' else set @psenddate = @smonthlastday else /*如果在上半月,则取当月的15号;否则取月底那一天*/ if (@slastdzdate > (substring(@slastdzdate, 1, 8) + '15')) and (@slastdzdate <= @smonthlastday) set @psenddate = @smonthlastday else set @psenddate = substring(@slastdzdate, 1, 8) + '15' end else if @sjsperiod = '3' begin /*旬结,获取上次对账日期的日部分,判断其属于旬的哪一天,分别处理*/ set @stheday = substring(@slastdzdate, 9, 2) set @slastday = substring(@smonthlastday, 9, 2) if (@sHasDz = '1') and (@stheday in ( '10', '20', @slastday )) if @stheday = '10' /*如果是10号,则取当月的20号*/ set @psenddate = substring(@slastdzdate, 1, 8) + '20' else if @stheday = '20' /*如果是20号,则取当月的最后一天*/ set @psenddate = @smonthlastday else /*如果是当月的最后一天,则取下月的10号*/ set @psenddate = substring(@snextmonth1st, 1, 8) + '10' else if @stheday <= '10' /*如果是上旬,则取当月的10号*/ set @psenddate = substring(@slastdzdate, 1, 8) + '10' else if (@stheday > '10') and (@stheday <= '20') /*如果是中旬,则取当月的20号*/ set @psenddate = substring(@slastdzdate, 1, 8) + '20' else /*如果是下旬,则取当月的最后一天*/ set @psenddate = @smonthlastday end else begin /*周结,即7日结,开始时间为每月1、8、16、23,结束日期为每月7、15、22、每月最后一天。*/ set @stheday = substring(@slastdzdate, 9, 2) set @slastday = substring(@smonthlastday, 9, 2) if (@sHasDz = '1') and (@stheday in ( '07', '15', '22', @slastday )) if @stheday = '07' --如果是07号,则取当月的15号 set @psenddate = substring(@slastdzdate, 1, 8) + '15' else if @stheday = '15' --如果是15号,则取当月的22号 set @psenddate = substring(@slastdzdate, 1, 8) + '22' else if @stheday = '22' --如果是22号,则取当月的最后一天 set @psenddate = @smonthlastday else --如果是当月的最后一天,则取下月的07号 set @psenddate = substring(@snextmonth1st, 1, 8) + '07' else if @stheday <= '07' --如果是第一周,则取当月的07号 set @psenddate = substring(@slastdzdate, 1, 8) + '07' else if (@stheday > '07') and (@stheday <= '15') --如果是第二周,则取当月的15号 set @psenddate = substring(@slastdzdate, 1, 8) + '15' else if (@stheday > '15') and (@stheday <= '22') --如果是第三周,则取当月的22号 set @psenddate = substring(@slastdzdate, 1, 8) + '22' else --如果是最后一周,则取当月的最后一天 set @psenddate = @smonthlastday end set @psmsg = '成功' return(1) end go --对账计算费用条款扣项金额 if exists(select * from sysobjects where name='p_soa_computefeeclause' and xtype='p') drop procedure p_soa_computefeeclause go create procedure p_soa_computefeeclause ( @psbillno varchar(20), @psjscode varchar(1), --结算方式 0-经销结算 1-代销结算 2-联营结算 3-租金结算 @psorgcode varchar(10), @psfinacode varchar(10), @pssupcode varchar(15), @pscontrno varchar(40), @psenddate varchar(10), @psmsg varchar(2000) output ) as declare @nssql nvarchar(4000) declare @nswhere nvarchar(4000) declare @optpaysoabyshop varchar(1) declare @optpaysoabyfina varchar(1) declare @sHasDz varchar(1) declare @slastdzdate varchar(10) declare @sbgndate varchar(10) declare @feejumpflag varchar(1) declare @feemaxenddate varchar(10) declare @feemaxdzlrdate varchar(10) declare @feesoamaxdate varchar(10) declare @feepnflag int --正负标志系数 declare @feebgndate varchar(10) --实际费用计算开始日期 declare @feeenddate varchar(10) --实际费用计算结束日期 declare @feebasetotal numeric(19,4) --按比例/按个计算时取的实际计算基数总金额 declare @feeclausetotal numeric(19,4) --费用条款总金额 declare @icnt int declare @iserialno int declare @tablename varchar(20) declare @tablebgnname varchar(20) declare @tableendname varchar(20) declare @kxclauseorg varchar(10) declare @kxorgcode varchar(10) declare @kxorgname varchar(30) declare @kxitemcode varchar(4) declare @kxitemno varchar(10) declare @kxbgndate varchar(10) declare @kxenddate varchar(10) declare @kxbasetype varchar(4) declare @kxbasetypename varchar(20) declare @kxfeetotal numeric(19,4) declare @kxfeerate numeric(19,4) declare @kxcltype varchar(1) --0-一次性 1-每次 2-每月 3-每年 declare @kxcldate varchar(20) declare @kxcalmode varchar(1) --0-按结算日期区间 1-按条款日期区间 declare @kxcalbgndate varchar(10) declare @kxcalenddate varchar(10) declare @kxclausetype varchar(1) --0-应收 1-应付 declare @kxzftype varchar(1) declare @kxiscalprofit varchar(1) declare @kxisinvoice varchar(1) declare @kxmidclscode varchar(10) declare @kxtendcode varchar(10) declare @kxplucode varchar(20) declare @kxclscode varchar(10) declare @kxbrandcode varchar(10) declare @kxisladderrate varchar(1) declare @kxladdercaltype varchar(1) --0-差额计算 1-全额计算 declare @kxlrdate varchar(10) declare @kxext1 varchar(500) declare @kxext2 varchar(500) declare @kxext3 varchar(500) declare @kxext4 varchar(500) declare @kxext5 varchar(500) declare @kxremark varchar(200) declare @kxladderrate numeric(19,4) declare @tmptotal numeric(19,4) declare @mintotal numeric(19,4) declare @maxtotal numeric(19,4) begin set @iserialno = 0 set @nswhere = '' --按门店结算对账选项 select @optpaysoabyshop=itemvalue from t_syscfg where section='SYSTEM' and itemname='PaySoaByShop' --按财务主体结算对账选项 select @optpaysoabyfina=itemvalue from t_syscfg where section='SYSTEM' and itemname='PaySoaByFina' if @optpaysoabyshop = '1' set @nswhere = @nswhere + ' and (a.orgcode=''' + @psorgcode + ''' or a.orgcode=''*'')' else if @optpaysoabyfina = '1' set @nswhere = @nswhere + ' and (a.finacode=''' + @psfinacode + ''' or a.finacode=''*'')' else set @nswhere = @nswhere + ' and a.orgcode=''*'' and a.finacode=''*''' if isnull(@pscontrno,'') <> '' set @nswhere = @nswhere + ' and a.contrno=''' + @pscontrno + '''' if isnull(@psbillno,'') <> '' set @nswhere = @nswhere + ' and a.billno<>''' + @psbillno + '''' set @nswhere = @nswhere + ' and a.rzdate<>'''' and a.rzdate is not null' if @psjscode in ('0', '1') --经代销对账 begin if isnull(@psbillno,'') <> '' delete from t_paysoa_clause where billno = @psbillno set @nssql = 'select @slastdzdate=isnull(max(enddate),'''') from t_paysoa_head a where a.supcode=''' + @pssupcode + '''' + @nswhere end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end /*查找该合同上次对账截止日期*/ exec sp_executesql @nssql,N'@slastdzdate varchar(10) output',@slastdzdate out if @@error<>0 begin set @psmsg = '获取上次对账结算日期出错' return(-1) end /*如果该合同没有对过账,则取合同或供应商的开始日期*/ if @slastdzdate = '' begin set @sHasDz = '0' if isnull(@pscontrno,'') <> '' --取合同开始日期 select @slastdzdate=bgndate from t_contract where contrno = @pscontrno else --取供应商开户日期 select @slastdzdate=opendate from t_supplier where supcode = @pssupcode end else set @sHasDz = '1' if isnull(@slastdzdate,'') = '' begin set @psmsg = '未获取到上次条款对账日期' return(-1) end --取上次对账日期后一天作为开始日 select @sbgndate = convert(varchar(10),dateadd(day,1, convert(datetime,@slastdzdate,120)),120) /*----非销售类条款计算入口----*/ declare curclause cursor local forward_only for select a.orgcode as clauseorg,b.orgcode,b.orgname,a.itemcode,a.itemno,a.bgndate,a.enddate,a.basetype,c.valuename as basetypename,a.feetotal,a.feerate, a.cltype,a.cldate,a.calmode,a.calbgndate,a.calenddate,a.clausetype,a.zftype,a.iscalprofit,a.isinvoice,a.midclscode,a.tendcode,a.plucode,a.clscode, a.brandcode,a.isladderrate,a.laddercaltype,a.lrdate,a.ext1,a.ext2,a.ext3,a.ext4,a.ext5,a.remark from t_contr_clause a, t_shop b, t_enum_value c where a.basetype=c.valuecode and c.enumcode='100013' and a.contrno=@pscontrno and a.supcode=@pssupcode and (a.orgcode='*' or a.orgcode=b.orgcode) and ((@psorgcode='*' or @psorgcode='') or (@psorgcode<>'*' and @psorgcode<>'' and b.orgcode=@psorgcode)) --and ((@psfinacode='*' or @psfinacode='') or (@psfinacode<>'*' and @psfinacode<>'' and b.finacode=@psfinacode)) --and a.basetype in ('000','001','002','003','004','005','006','007','011','100','101') and (a.calmode='0' and ((@psenddate between a.bgndate and a.enddate) or (a.enddate between @sbgndate and @psenddate)) or a.calmode='1' and ((@psenddate between a.calbgndate and a.calenddate) or (a.calenddate between @sbgndate and @psenddate))) open curclause while 1=1 begin fetch curclause into @kxclauseorg,@kxorgcode,@kxorgname,@kxitemcode,@kxitemno,@kxbgndate,@kxenddate,@kxbasetype,@kxbasetypename,@kxfeetotal, @kxfeerate,@kxcltype,@kxcldate,@kxcalmode,@kxcalbgndate,@kxcalenddate,@kxclausetype,@kxzftype,@kxiscalprofit,@kxisinvoice,@kxmidclscode, @kxtendcode,@kxplucode,@kxclscode,@kxbrandcode,@kxisladderrate,@kxladdercaltype,@kxlrdate,@kxext1,@kxext2,@kxext3,@kxext4,@kxext5,@kxremark if @@fetch_status<>0 break set @feebgndate = '' set @feeenddate = '' set @feebasetotal = 0 set @feeclausetotal = 0 set @feejumpflag = '0' if @kxclausetype = '0' set @feepnflag = 1 --应收为正 else set @feepnflag = -1; --应付为负 --取条款结算对账的最大结束日期 if @psjscode in ('0', '1') --经代销对账 begin set @nssql = 'select @feemaxenddate=isnull(max(enddate),'''') from t_paysoa_head a, t_paysoa_clause b ' + ' where a.billno=b.billno and a.supcode=''' + @pssupcode + ''' and b.itemcode=''' + @kxitemcode + ''' and b.itemno=''' + @kxitemno + '''' + @nswhere end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end exec sp_executesql @nssql,N'@feemaxenddate varchar(10) output',@feemaxenddate out if @@error<>0 begin set @psmsg = '获取上次条款对账结算日期出错' return(-1) end --取条款所在对账单的最大录入日期 if @psjscode in ('0', '1') --经代销对账 begin set @nssql = 'select @feemaxdzlrdate=isnull(max(lrdate),'''') from t_paysoa_head a, t_paysoa_clause b ' + ' where a.billno=b.billno and a.supcode=''' + @pssupcode + ''' and b.itemcode=''' + @kxitemcode + ''' and b.itemno=''' + @kxitemno + '''' + @nswhere end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end exec sp_executesql @nssql,N'@feemaxdzlrdate varchar(10) output',@feemaxdzlrdate out if @@error<>0 begin set @psmsg = '获取上次条款所在对账单录入日期出错' return(-1) end --如果最大结算日期比最大录入日期还要大,说明有提前对账的情况,按最大录入日期 if @feemaxenddate > @feemaxdzlrdate set @feesoamaxdate = @feemaxdzlrdate else set @feesoamaxdate = @feemaxenddate --取到则按+1天作为开始计算日期 if @feesoamaxdate <> '' set @feebgndate = convert(varchar(10),dateadd(day,1, convert(datetime,@feesoamaxdate,120)),120) if @kxcalmode = '0' begin --按结算日期区间 if (@feesoamaxdate = '') or (@kxbgndate > @feebgndate) set @feebgndate = @kxbgndate if @kxcltype = '0' set @feeenddate = @kxenddate --一次性的取扣项定义结束日期 else begin if @psenddate > @kxenddate set @feeenddate = @kxenddate else set @feeenddate = @psenddate end end else begin --按条款日期区间 if (@feesoamaxdate = '') or (@kxcalbgndate > @feebgndate) set @feebgndate = @kxcalbgndate if @kxcltype = '0' set @feeenddate = @kxcalenddate --一次性的取扣项定义结束日期 else begin if @psenddate > @kxcalenddate set @feeenddate = @kxcalenddate else set @feeenddate = @psenddate end end --最大对账日期为空,即第一次对账的情况,上面已处理 --下面为已经有过对账记录,按类型处理逻辑 if @feesoamaxdate <> '' begin --根据处理类型处理 0-一次性 1-每次 2-每月 3-每年 if @kxcltype = '0' begin --0-一次性 set @feejumpflag = '1' --一次性扣项处理过,则跳过 end --else if @kxcltype = '1' --begin --1-每次 --如果扣项开始日期大于上次结算日期,则取扣项开始日期作为本次开始日期 --如果扣项开始日期小于上次结算日期,则取上次结算日期的第二天作为本次开始日期 --上面日期已按此处理 --end else if @kxcltype = '2' begin --2-每月 --判断本次计算截止日期是否与上次对账最大日期在同一个月,如果是,则不计算 if substring(@feeenddate,1,7) = substring(@feesoamaxdate,1,7) set @feejumpflag = '1' else begin if @kxbasetype = '000' --无基数扣项,实际开始月必须为上次对账次月 select @feebgndate=convert(varchar(10),dateadd(m, 1, convert(datetime,substring(@feesoamaxdate, 1, 8)+'01',120)),120) --其他基数取上次结算日期的第二天作为本次开始日期 --上面日期已按此处理 end end else if @kxcltype = '3' begin --3-每年 --判断本次计算截止日期是否与上次对账最大日期在同一年,如果是,则不计算 if substring(@feeenddate,1,4) = substring(@feesoamaxdate,1,4) set @feejumpflag = '1' else begin if @kxbasetype = '000' --无基数扣项,实际开始年必须为上年对账次年 select @feebgndate=convert(varchar(10),dateadd(yy, 1, convert(datetime,substring(@feesoamaxdate, 1, 4)+'-01-01',120)),120) --其他基数取上次结算日期的第二天作为本次开始日期 --上面日期已按此处理 end end end if @kxcltype = '0' begin --当处理类型为一次性且非固定扣项费用时,只有大于区间结束日期的时,才处理 if @kxbasetype <> '000' begin if @psenddate < @feeenddate set @feejumpflag = '1' end end if @feejumpflag = '1' continue ----开始处理非销售类计算条款扣项费用-- --000-无计算基数 if @kxbasetype = '000' begin set @icnt = 1 --每月,按月数计算 if @kxcltype = '2' begin select @icnt = (cast(substring(@feeenddate, 1, 4) as int) - cast(substring(@feebgndate, 1, 4) as int)) * 12 + (cast(substring(@feeenddate, 6, 2) as int) - cast(substring(@feebgndate, 6, 2) as int)) + 1 end --每年,按年数计算 if @kxcltype = '3' begin select @icnt = (cast(substring(@feeenddate, 1, 4) as int) - cast(substring(@feebgndate, 1, 4) as int)) + 1 end set @feeclausetotal = @kxfeetotal * @icnt end --002-含税净进货金额 if @kxbasetype = '002' begin --【扣项比例】设置为实际扣项比例 --合计含税进货金额,直接取本次对账单据明细的合计金额就行 select @feebasetotal=isnull(sum(a.bcjstotal),0)-isnull(sum(a.bczrtotal),0) from t_paysoa_body a where a.billno=@psbillno and a.orgcode=@kxorgcode --按比例计算本次扣款金额 set @feeclausetotal = round(@feebasetotal * @kxfeerate / 100, 2) --to do 通算计算年返差额,可能需要在条款循环外进行 end --003-商品进货数量(不包含退货) if @kxbasetype = '003' begin --【每个扣(元)】字段feerate select @feebasetotal=isnull(sum(b.counts),0) from t_paysoa_body a, t_accept_body b where a.billno=@psbillno and a.orgcode=@kxorgcode and b.plucode=@kxplucode and a.billtype in ('0','3') and a.ywbillno=b.billno set @feeclausetotal = round(@feebasetotal * @kxfeerate, 2) end --017-商品销售数量 if @kxbasetype = '017' begin --【每个扣(元)】字段feerate set @tablebgnname = 't_plusale_' + substring(@feebgndate, 1, 4) + substring(@feebgndate, 6, 2) set @tableendname = 't_plusale_' + substring(@feeenddate, 1, 4) + substring(@feeenddate, 6, 2) set @feebasetotal = 0 declare cur017 cursor local for select name from sysobjects where name between @tablebgnname and @tableendname open cur017 fetch next from cur017 into @tablename while @@fetch_status=0 begin set @tmptotal = 0 set @nssql = 'select @tmptotal=isnull(sum(counts),0) from ' + @tablename + ' a where a.orgcode=''' + @kxorgcode + ''' and a.supcode=''' + @pssupcode + ''' and a.plucode=''' + @kxplucode + ''' and a.accdate between ''' + @feebgndate + ''' and ''' + @feeenddate + '''' exec sp_executesql @nssql,N'@tmptotal numeric(19,4) output',@tmptotal out set @feebasetotal = @feebasetotal + @tmptotal fetch next from cur017 into @tablename end close cur017 deallocate cur017 set @feeclausetotal = round(@feebasetotal * @kxfeerate, 2) end --100-配送中心订单到货率[专用](壳牌专用) if @kxbasetype = '100' begin select @feebasetotal=isnull(sum(c.cost),0) from t_paysoa_body a, t_accept_head b, t_order_head c where a.billno=@psbillno and a.orgcode=@kxorgcode and a.billtype in ('0','3') and a.ywbillno=b.billno and b.orderno=c.billno --and c.state='2' and round(c.dhcount/c.counts,2)*100 '' begin set @kxext1 = '(''' + REPLACE(@kxext1,'|',''',''') + ''')' end --累计净含税进价金额=累计验收含税进价金额-累计退货含税进价金额+累计含税进价调整差额 set @tmptotal = 0 --合计含税进货金额 set @nssql = 'select @tmptotal=isnull(sum(c.cost),0) from t_paysoa_body a, t_accept_head b, t_accept_body c where a.billno=''' + @psbillno + ''' and a.orgcode=''' + @kxorgcode + ''' and a.billtype in (''0'',''3'') and a.ywbillno=b.billno and b.billno=c.billno' if isnull(@kxext1, '') <> '' set @nssql = @nssql + ' and c.plucode not in ' + @kxext1 exec sp_executesql @nssql,N'@tmptotal numeric(19,4) output',@tmptotal out set @feebasetotal = @tmptotal --合计含税退货金额 set @nssql = 'select @tmptotal=isnull(sum(c.cost),0) from t_paysoa_body a, t_return_head b, t_return_body c where a.billno=''' + @psbillno + ''' and a.orgcode=''' + @kxorgcode + ''' and a.billtype in (''1'',''4'') and a.ywbillno=b.billno and b.billno=c.billno' if isnull(@kxext1, '') <> '' set @nssql = @nssql + ' and c.plucode not in ' + @kxext1 exec sp_executesql @nssql,N'@tmptotal numeric(19,4) output',@tmptotal out set @feebasetotal = @feebasetotal - @tmptotal --合计含税进价调整差额 set @nssql = 'select @tmptotal=isnull(sum(c.cjcost),0) from t_paysoa_body a, t_adjbuyprice_head b, t_adjbuyprice_body c where a.billno=''' + @psbillno + ''' and a.orgcode=''' + @kxorgcode + ''' and a.billtype in (''2'',''5'') and a.ywbillno=b.billno and b.billno=c.billno' if isnull(@kxext1, '') <> '' set @nssql = @nssql + ' and c.plucode not in ' + @kxext1 exec sp_executesql @nssql,N'@tmptotal numeric(19,4) output',@tmptotal out set @feebasetotal = @feebasetotal + @tmptotal --按比例计算本次扣款金额 set @feeclausetotal = round(@feebasetotal * @kxfeerate / 100, 2) --to do 通算计算年返差额,可能需要在条款循环外进行 end --102-商品销售数量[专用](壳牌专用) if @kxbasetype = '102' begin --【每单位数量扣】字段feerate --【单位数量】字段ext1 --【返利门槛】字段ext2 set @tablebgnname = 't_plusale_' + substring(@feebgndate, 1, 4) + substring(@feebgndate, 6, 2) set @tableendname = 't_plusale_' + substring(@feeenddate, 1, 4) + substring(@feeenddate, 6, 2) set @feebasetotal = 0 declare cur102 cursor local for select name from sysobjects where name between @tablebgnname and @tableendname open cur102 fetch next from cur102 into @tablename while @@fetch_status=0 begin set @tmptotal = 0 set @nssql = 'select @tmptotal=isnull(sum(counts),0) from ' + @tablename + ' a where a.orgcode=''' + @kxorgcode + ''' and a.supcode=''' + @pssupcode + ''' and a.plucode=''' + @kxplucode + ''' and a.accdate between ''' + @feebgndate + ''' and ''' + @feeenddate + '''' exec sp_executesql @nssql,N'@tmptotal numeric(19,4) output',@tmptotal out set @feebasetotal = @feebasetotal + @tmptotal fetch next from cur102 into @tablename end close cur102 deallocate cur102 if @feebasetotal > convert(numeric(19,4), @kxext2) begin set @feeclausetotal = round(floor(@feebasetotal / @kxext1) * @kxfeerate, 2) end end if @kxisladderrate = '1' begin --首先检查设置得扣项层进比例区间的合法性,如果不合法,则不允许计算 select @mintotal=isnull(min(mintotal),0),@maxtotal=isnull(min(maxtotal),0) from t_contr_clause_rate where contrno = @pscontrno and supcode = @pssupcode and itemcode = @kxitemcode and itemno = @kxitemno and (orgcode = @kxclauseorg or orgcode = '*') if @mintotal <> 0 begin set @psmsg = '当前扣项的阶梯条款区间设置有误:最小区间的金额下限没有从0开始!请修正后再对账!' return(-1) end if @maxtotal <> 0 begin set @psmsg = '当前扣项的阶梯条款区间设置有误:最大区间的金额上限没有设置为0!请修正后再对账!' return(-1) end --检查阶梯条款是否连续 declare curclauserate cursor local for select mintotal,maxtotal,rate from t_contr_clause_rate where contrno = @pscontrno and supcode = @pssupcode and itemcode = @kxitemcode and itemno = @kxitemno and (orgcode = @kxclauseorg or orgcode = '*') order by mintotal open curclauserate fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate set @tmptotal = @maxtotal while @@fetch_status=0 begin fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate if @@fetch_status<>0 break if @mintotal <> @tmptotal begin set @psmsg = '各个比例区间金额必须连续,请修正后再对账!' return(-1) end set @tmptotal = @maxtotal end close curclauserate --将区间金额清零 set @mintotal = 0 set @maxtotal = 0 set @kxladderrate = 0 --将前面计算的扣项金额清零,重新计算 set @feeclausetotal = 0 --差额计算 if @kxladdercaltype='0' begin open curclauserate fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate while @@fetch_status=0 begin --当扣项基数金额小于0时,扣项金额=扣项基数金额*第一个区间的提成比率 if (@feebasetotal<0 and @mintotal=0) begin set @feeclausetotal = round(@feebasetotal * @kxladderrate / 100, 2) end --当扣项基数金额大于金额下限且大于等于金额上限时,扣项金额=扣项金额+(金额上限-金额下限)*扣项比率 if (@feebasetotal>@mintotal and @feebasetotal>=@maxtotal and @maxtotal<>0) begin set @feeclausetotal = @feeclausetotal + round((@maxtotal - @mintotal) * @kxladderrate / 100, 2) end --当扣项基数金额大于等于金额下限且小于金额上限时,扣项=扣项+(总金额-金额下限)*扣项比率 if (@feebasetotal>=@mintotal and @feebasetotal<@maxtotal) begin set @feeclausetotal = @feeclausetotal + round((@feebasetotal - @mintotal) * @kxladderrate / 100, 2) break; end --当扣项基数金额大于等于金额下限且金额上限等于0(无上限)时,扣项=扣项+(总金额-金额下限)*扣项比率 if (@feebasetotal>=@mintotal and @maxtotal=0) begin set @feeclausetotal = @feeclausetotal + round((@feebasetotal - @mintotal) * @kxladderrate / 100, 2) break; end fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate end close curclauserate --因为扣项金额可能会是多个比例计算出的,@kxfeerate的值从扣项表中将会获取0,写入t_paysoa_clause表的时候,扣项比例记为0; end --全额计算 if @kxladdercaltype='1' begin open curclauserate fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate while @@fetch_status=0 begin --当总金额大于等于金额下限且小于金额上限时,取当前区间的提成比率 if (@feebasetotal>=@mintotal and @feebasetotal<@maxtotal) break; --当总金额大于等于金额下限且金额上限为0时,取当前区间的提成比率 if (@feebasetotal>=@mintotal and @maxtotal=0) break; fetch next from curclauserate into @mintotal,@maxtotal,@kxladderrate end close curclauserate set @feeclausetotal = round(@feebasetotal * @kxladderrate / 100, 2) --将最终的计算比例赋值给@kxfeerate,否则@kxfeerate的值将为0 set @kxfeerate = @kxladderrate end deallocate curclauserate end --根据应收/应付确定正负 set @feeclausetotal = @feeclausetotal * @feepnflag if isnull(@psbillno,'') <> '' begin if @feeclausetotal<>0 begin set @iserialno = @iserialno + 1 --插入对账单条款表 if @psjscode in ('0', '1') --经代销对账 begin insert into t_paysoa_clause(billno,serialno,contrno,supcode,orgcode,itemcode,itemno,basetype,feetotal,clausefee,ratebase,feerate,cltype, cldate,zftype,iscalprofit,calmode,calbgndate,calenddate,isinvoice,midclscode,clausetype,tendcode,plucode,clscode,brandcode,isladderrate, laddercaltype,ext1,ext2,ext3,ext4,ext5,remark) values(@psbillno,@iserialno,@pscontrno,@pssupcode,@kxorgcode,@kxitemcode,@kxitemno,@kxbasetype,@feeclausetotal,@kxfeetotal,@feebasetotal, @kxfeerate,@kxcltype,convert(varchar(19),getdate(),120),@kxzftype,@kxiscalprofit,@kxcalmode,@feebgndate,@feeenddate,@kxisinvoice,@kxmidclscode, @kxclausetype,@kxtendcode,@kxplucode,@kxclscode,@kxbrandcode,@kxisladderrate,@kxladdercaltype,@kxext1,@kxext2,@kxext3,@kxext4,@kxext5,@kxremark) end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end end end --else --begin --to do 若纯计算不插入正式对账条款表,则处理此处插入临时表 --end end --更新表头对账总金额 if isnull(@psbillno,'') <> '' begin if @psjscode in ('0', '1') --经代销对账 begin update t_paysoa_head set feetotal = isnull((select sum(feetotal) from t_paysoa_clause where billno = @psbillno),0) where billno = @psbillno update t_paysoa_head set dztotal = bcjstotal - feetotal where billno = @psbillno end else if @psjscode = '2' --联营对账 begin set @psmsg = '暂未支持联营对账' return(-1) end else begin set @psmsg = '暂未支持该结算方式对账' return(-1) end end set @psmsg = '成功' return(1) end go