/*************************************************************************** 会员存储过程脚本 ****************************************************************************/ if exists (select * from sysobjects where id = object_id(N'p_vip_get_vip') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_get_vip go create procedure p_vip_get_vip @vipcode varchar(20), @orgcode varchar(10), @vipname varchar(30) output, @dsccode varchar(4) output, @smessage varchar(100) output with encryption as declare @scardtype varchar(1) declare @canuse varchar(1) declare @candsc varchar(1) declare @canjf varchar(1) declare @validdate varchar(10) declare @currdate varchar(10) begin select @scardtype=v.cardtype,@canuse=v.canuse,@vipname=isnull(v.vipname,'') ,@dsccode=isnull(t.dsccode,''), @validdate=validdate,@candsc=isnull(t.candsc,''),@canjf=isnull(t.canpt,'') from t_vip v left join t_viptype t on v.viptype=t.lxcode where vipcode=@vipcode and exists(select * from t_viptype_org where viptype=v.viptype and (orgcode='*' or orgcode=@orgcode)) if @@rowcount=0 begin select @smessage='卡号不存在或不允许在该机构使用' return (-1) end else if @canuse='0' begin select @smessage='卡禁用' return (-1) end else if (@candsc<>'1') and (@canjf<>'1') begin select @smessage='非积分优惠卡' return (-1) end if @validdate<>'' and @validdate is not null begin set @currdate=convert(varchar(10),getdate(),120) if @validdate<@currdate begin select @smessage='有效期为'+@validdate+',卡已过期' return(-1) end end if @@error<>0 begin select @smessage='查询异常' return (-1) end else return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_get_vip_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_get_vip_total go create procedure p_vip_get_vip_total @vipcode varchar(20), @orgcode varchar(10), @vipname varchar(20) output, @vipsex varchar(1) output, @total numeric(19,4) output, @mincktotal numeric(19,4) output, @passwd varchar(100) output, @verifymark varchar(13) output, @smessage varchar(100) output with encryption as declare @cardtype varchar(1) declare @canuse varchar(1) declare @locktotal numeric(19,4) declare @lockmark varchar(13) declare @validdate varchar(10) declare @currdate varchar(10) declare @canstore varchar(1) declare @viptype varchar(4) begin select @cardtype=cardtype,@canuse=canuse,@canstore=canstore,@total=overtotal,@passwd=isnull(passwd,'') , @verifymark=isnull(verifymark,''), @locktotal=isnull(locktotal,0),@lockmark=isnull(lockmark,''),@validdate=validdate from t_vip_pos where vipcode=@vipcode select @vipname=isnull(vipname,''),@vipsex=vipsex,@viptype=viptype from t_vip where vipcode=@vipcode and isnull(sxdate,'') <> '' and exists(select * from t_viptype_org where viptype=t_vip.viptype and (orgcode='*' or orgcode=@orgcode)) select @mincktotal=mincktotal from t_viptype where lxcode=@viptype if @@rowcount=0 begin select @smessage='卡号不存在或不允许在该机构使用或还没有发售' return (-1) end else if @canuse='0' begin select @smessage='卡禁用' return (-1) end if (@locktotal<>0) or ((@lockmark is not null) and (@lockmark<>'')) begin select @smessage='卡已被锁定' return (-1) end if @canstore<>'1' begin select @smessage='非充值卡' return(-1) end if @cardtype='1' begin select @smessage='必须刷ic卡' return(-1) end if @validdate<>'' and @validdate<>' - - ' and @validdate is not null begin set @currdate=convert(varchar(10),getdate(),120) if @validdate<@currdate begin select @smessage='有效期为'+@validdate+',卡已过期' return(-1) end end if @@error<>0 begin select @smessage='查询异常' return (-1) end else return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_send_xfjf_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_send_xfjf_total go create procedure p_vip_send_xfjf_total @orgcode varchar(10), @posno varchar(6), @sdate varchar(10), @stime varchar(8), @serialno varchar(50), @trantype varchar(1), @vipcode varchar(20), @total numeric(19,4), @flxftotal numeric(19,4), @xfjftotal numeric(19,4), @posaccdate varchar(10), @smessage varchar(100) output with encryption as begin select vipcode from t_vippt_flow where orgcode=@orgcode and posno=@posno and sdate=@sdate and stime=@stime and serialno=@serialno and trantype=@trantype if @@rowcount=0 begin insert into t_vippt_flow(orgcode,posno,sdate,stime,serialno,trantype,vipcode,accdate,total,flxftotal,xfjftotal,posaccdate) values(@orgcode,@posno,@sdate,@stime,@serialno,@trantype,@vipcode,'',@total,@flxftotal,@xfjftotal,@posaccdate) end else begin update t_vippt_flow set posaccdate=@posaccdate where orgcode=@orgcode and posno=@posno and sdate=@sdate and stime=@stime and serialno=@serialno and trantype=@trantype end if @@error<>0 begin select @smessage='积分上传失败' return (-1) end else return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_get_xfjf_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_get_xfjf_total go create procedure p_vip_get_xfjf_total @vipcode varchar(20), @orgcode varchar(10), @vipname varchar(30) output, @xfjftotal numeric(19,4) output, @smessage varchar(100) output with encryption as begin select @xfjftotal=isnull(sum(xfjftotal),0) from t_vippt_flow where vipcode=@vipcode and (accdate='' or accdate is null) select @vipname=isnull(vipname,''),@xfjftotal=@xfjftotal+(sumxfjftotal-sumfljftotal) from t_vip where vipcode=@vipcode and exists(select * from t_viptype_org where viptype=t_vip.viptype and (orgcode='*' or orgcode=@orgcode)) if @@rowcount=0 begin select @smessage='卡号不存在或不允许在该机构使用' return (-1) end return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_ins_trade_info') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_ins_trade_info go create procedure p_vip_ins_trade_info @msgserialno varchar(12), @shopcode varchar(13), @posno varchar(6) , @serialno varchar(50), @trantype varchar(1), @vipcode varchar(20), @total numeric(19,4), @vipdate varchar(10), @viptime varchar(8), @recdate varchar(10), @rectime varchar(8), @verifymark varchar(13) with encryption as begin insert into t_viptrade(msgserialno,orgcode,posno,serialno,vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag,datatype) values (@msgserialno,@shopcode,@posno,@serialno,@vipcode,@trantype,@total,@vipdate,@viptime,@recdate,@rectime,'1','0') update t_vip_pos set locktotal=@total,lockmark=@verifymark,msgserialno=@msgserialno where vipcode=@vipcode if @@error<>0 return (-1) else return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_open_msg_lock') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_open_msg_lock go create procedure p_vip_open_msg_lock @vipcoden varchar(1200), @msgserialno varchar(12), @type varchar(1) with encryption as begin if @type='2' exec('update t_viptrade set lockflag=''2'' where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+''' and datatype=''0''') exec('update a set overtotal=overtotal-locktotal, overcztotal=overcztotal-(case when locktotal>overcztotal then overcztotal else locktotal end), overzstotal=overzstotal-(case when locktotal>overcztotal then locktotal-overcztotal else 0.00 end), verifymark=lockmark,locktotal=0,lockmark='''',msgserialno='''' from t_vip_pos a where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+'''') if @@error<>0 return (-1) else return (0) end go if exists (select * from sysobjects where id = object_id(N'p_vip_del_msg_lock') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_del_msg_lock go create procedure p_vip_del_msg_lock @vipcoden varchar(1200), @msgserialno varchar(12), @type varchar(1) with encryption as declare @srecdate varchar(10) declare @viptradeyyyy varchar(20) declare @sql varchar(2000) begin if @srecdate is null set @srecdate=convert(varchar(10),getdate(),120) select @viptradeyyyy='t_viptrade_'+substring(@srecdate,1,4) exec ('if not exists (select name from dbo.sysobjects where name ='''+ @viptradeyyyy+''' and xtype=''u'' ) create table '+ @viptradeyyyy+'( msgserialno varchar (12) not null, orgcode varchar (10) not null, posno varchar (6) not null, serialno varchar (50) not null, trantype varchar (1) not null, vipcode varchar (20) not null, total numeric (19,4) not null, vipdate varchar (10) not null, viptime varchar (8) not null, recdate varchar (10) not null, rectime varchar (8) not null, lockflag varchar (1) not null, datatype varchar (1) not null)') exec('insert into ' + @viptradeyyyy+'(msgserialno,orgcode,posno,serialno, vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag,datatype) select msgserialno,orgcode,posno,serialno,vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag='''+@type+''',datatype from t_viptrade where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+'''') exec('delete from t_viptrade where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+'''') exec('update a set locktotal=0,lockmark='''',msgserialno='''' from t_vip_pos a where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+'''') if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_lock_ic_supply_data') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_lock_ic_supply_data go create procedure p_vip_lock_ic_supply_data @vipcode varchar(20), @shopcode varchar(10), @posno varchar(6), @type varchar(1), @icstorecount integer output, @icsumstoretotal numeric(19,4) output, @icstoredatan varchar(2000) output, @smessage varchar(100) output with encryption as declare @scardtype varchar(1) declare @scanuse varchar(1) declare @svaliddate varchar(10) declare @scurdate varchar(10) declare @scurtime varchar(8) declare @slockflag varchar(1) declare @sicstoredata varchar(45) declare @smemotxt varchar(60) begin set @scurdate=convert(varchar(10),getdate(),120) set @scurtime=convert(varchar(8),getdate(),108) select @scardtype=cardtype,@scanuse=canuse,@svaliddate=validdate from t_vip where vipcode=@vipcode and exists(select * from t_viptype_org where viptype=t_vip.viptype and (orgcode='*' or orgcode=@shopcode)) if @@rowcount=0 begin select @smessage='卡号不存在或不允许在该机构使用' return (-1) end if @scanuse<>'1' or @scanuse is null begin select @smessage='卡禁用' return (-1) end if @svaliddate<>'' if @svaliddate<@scurdate begin select @smessage='卡过期' return (-1) end if @scardtype<>'1' begin select @smessage='该卡不需要补登' return (-1) end select top 1 @slockflag=lockflag from t_vipstore where vipcode=@vipcode and lockflag<>'0' if @slockflag is not null begin select @smessage='存在已经锁定的充值数据' return (-1) end select @icstorecount=isnull(count(*),0) from t_vipstore where vipcode=@vipcode if @icstorecount=0 begin select @smessage='不存在需要处理的存取款数据' return (-1) end if @type='0' begin if @icstorecount>50 begin select @smessage='未补登记录超过50,请去服务台补登' return (-1) end end if @type='0' set @smemotxt='店编码:'+@shopcode+'收款台:'+@posno+' '+@scurdate+' '+@scurtime+'锁定' else if @type='1' set @smemotxt='' else set @smemotxt='' update t_vipstore set lockflag='1',remark=case when @type='0' then @smemotxt else (case billtype when '0' then '充值'+billno when '1' then '取款'+billno when '2' then '前台交易'+rtrim(billno)+' 日期'+rtrim(bizdate)+' '+rtrim(rzdate) else '' end) end where vipcode=@vipcode and lockflag='0' select @icsumstoretotal=isnull(sum(storetotal),0) from t_vipstore where vipcode=@vipcode and lockflag='1' declare cur_store cursor for select ltrim(rtrim(rzdate))+':'+ltrim(rtrim(convert(varchar(23),storetotal))) from t_vipstore where vipcode=@vipcode and lockflag='1' open cur_store set @icstoredatan='' fetch next from cur_store into @sicstoredata while @@fetch_status=0 begin if @icstoredatan='' set @icstoredatan=@icstoredatan+@sicstoredata else set @icstoredatan=@icstoredatan+';'+@sicstoredata fetch next from cur_store into @sicstoredata end close cur_store deallocate cur_store if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'[dbo].[p_vip_open_lock_ic_supply_data]') and objectproperty(id, N'isprocedure') = 1) drop procedure [dbo].[p_vip_open_lock_ic_supply_data] go create procedure p_vip_open_lock_ic_supply_data @vipcode varchar(20), @shopcode varchar(10), @posno varchar(6), @usercode varchar(6), @username varchar(10), @type varchar(1), @cltype varchar(1) with encryption as declare @scurdate varchar(10) declare @scurtime varchar(8) declare @smemotxt varchar(60) begin set @scurdate=convert(varchar(10),getdate(),120) set @scurtime=convert(varchar(8),getdate(),108) if @cltype='0' and @type='0' set @smemotxt='前台补登' else if @cltype='0' and @type='1' set @smemotxt='后台补登' else if @cltype='1' set @smemotxt='后台删除' else if @cltype='2' set @smemotxt='店编码:'+@shopcode+'收款台:'+@posno+' '+@scurdate+' '+@scurtime+'取消补登' else if @cltype='3' set @smemotxt='补登失败' else if @cltype='4' set @smemotxt='解除锁定' else set @smemotxt='' if @cltype='0' or @cltype='1' or @cltype='3' or @cltype='4' begin insert into t_viplog_icrw(bookdate,booktime,vipcode,memotxt,usercode,username,fstotal) select @scurdate,@scurtime,vipcode,ltrim(rtrim(remark)+' '+@smemotxt) as memotxt, @usercode as usercode,@username as username,storetotal as fstotal from t_vipstore where vipcode=@vipcode and lockflag='1' end if @cltype='0' or @cltype='1' delete from t_vipstore where vipcode=@vipcode and lockflag='1' else if @cltype='2' or @cltype='3' or @cltype='4' update t_vipstore set lockflag='0',remark=@smemotxt where vipcode=@vipcode and lockflag='1' if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_get_limt_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_get_limt_total go create procedure p_vip_get_limt_total @vipcode varchar(20), @dsccode varchar(20), @dstimeno varchar(20), @plucode varchar(20), @cycletype varchar(1), @cycledate varchar(10), @xscount numeric(19,4) output, @sumcount numeric(19,4) output with encryption as declare @nowdate varchar(10) declare @firstdate varchar(10) declare @nowweek int declare @nowday int declare @firstday varchar(2) declare @tempstr varchar(100) declare @tempdate datetime begin set @nowdate = convert(varchar(10),getdate(),120) set @nowweek = datepart(weekday, getdate() + @@datefirst - 1) set @nowday = datepart(day, @nowdate) if @cycletype = '0' begin set @firstdate = '1900-01-01' end else if @cycletype = '1' begin set @firstdate = '9999-99-99' end else if @cycletype = '2' begin set @firstdate = @nowdate end else if @cycletype = '3' begin set @firstday = convert(int,@cycledate) if @nowweek >= @firstday begin set @tempdate = dateadd(day, -1 * (@nowweek - @firstday), @nowdate) set @firstdate = convert(varchar(10),@tempdate,120) end else begin set @tempdate = dateadd(day, -1 * (7 - @firstday + @nowweek), @nowdate) set @firstdate = convert(varchar(10),@tempdate,120) end end else if @cycletype = '4' begin set @firstday = convert(int,@cycledate) if @nowday >= @firstday begin set @tempstr = convert(varchar(4),year(@nowdate)) + '-' + convert(varchar(2),month(@nowdate)) + '-' + convert(varchar(2),@firstday) set @tempdate = convert(datetime,@tempstr) set @firstdate = convert(varchar(10),@tempdate,120) end else begin set @tempstr = dateadd(month, -1 , @nowdate) set @tempstr = convert(varchar(4),year(@tempstr)) + '-' + convert(varchar(2),month(@tempstr)) + '-' + convert(varchar(2),@firstday) if isdate(@tempstr) = 0 begin set @tempstr = dateadd(month, -1 , @nowdate) set @tempstr = convert(varchar(10),dateadd(month,1,dateadd(day,-day(@tempstr),@tempstr)),120) end set @tempdate = convert(datetime,@tempstr) set @firstdate = convert(varchar(10),@tempdate,120) end end else set @firstdate = '9999-99-99' select @xscount=sum(xscount) from t_vipdsc_limit where vipcode =@vipcode and dsccode =@dsccode and dstimeno =@dstimeno and plucode =@plucode and saledate >= @firstdate and saledate <= @nowdate if @xscount is null set @xscount=0 select @sumcount=sum(xscount) from t_vipdsc_limit where dsccode =@dsccode and dstimeno =@dstimeno and plucode =@plucode and saledate >= @firstdate and saledate <= @nowdate if @sumcount is null set @sumcount=0 if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_upt_limt_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_upt_limt_total go create procedure p_vip_upt_limt_total @vipcode varchar(20), @dsccode varchar(20), @dstimeno varchar(20), @plucode varchar(20), @xscount numeric(19,4) with encryption as declare @currxscount numeric(19,4) declare @saledate varchar(10) begin if @vipcode = '' set @saledate = '' else set @saledate = convert(varchar(10),getdate(),120) select @currxscount=xscount from t_vipdsc_limit where vipcode =@vipcode and dsccode =@dsccode and dstimeno =@dstimeno and plucode =@plucode and saledate =@saledate if (@currxscount is null) insert into t_vipdsc_limit(vipcode,dsccode,dstimeno,plucode,xscount,saledate) values(@vipcode,@dsccode,@dstimeno,@plucode,@xscount,@saledate) else update t_vipdsc_limit set xscount=xscount+@xscount where vipcode=@vipcode and dsccode=@dsccode and dstimeno=@dstimeno and plucode=@plucode and saledate=@saledate if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_nml_get_limt_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_nml_get_limt_total go create procedure p_nml_get_limt_total @dsccode varchar(20), @dstimeno varchar(20), @plucode varchar(20), @lmtcount numeric(19,4), @curcount numeric(19,4), @xscount numeric(19,4) output with encryption as declare @fyxscount numeric(19,4) begin select @fyxscount=isnull(xscount,0) from t_vipdsc_limit where dsccode=@dsccode and dstimeno=@dstimeno and plucode=@plucode if @fyxscount is null set @fyxscount=0 set @fyxscount=@lmtcount-@fyxscount if @fyxscount<0 set @fyxscount=0 if @fyxscount<@curcount select @xscount=@fyxscount else select @xscount=@curcount if exists(select * from t_vipdsc_limit where vipcode='' and dsccode=@dsccode and dstimeno=@dstimeno and plucode=@plucode) update t_vipdsc_limit set xscount=xscount+@xscount where vipcode='' and dsccode=@dsccode and dstimeno=@dstimeno and plucode=@plucode else insert into t_vipdsc_limit(dsccode,dstimeno,vipcode,plucode,xscount,saledate) values(@dsccode,@dstimeno,'',@plucode,@xscount,'') update t_vipdsc_limit set xscount=0 where vipcode='' and dsccode=@dsccode and dstimeno=@dstimeno and plucode=@plucode and xscount<0 if @@error<>0 return (-1) else return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_fl') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_fl go create procedure p_vip_fl @vipcode varchar(20), @fljftotal numeric(19,4), @fltotal numeric(19,4), @yfljftotal numeric(19,4), @yfltotal numeric(19,4), @orgcode varchar(10), @zdrname varchar(10), @sjflplus varchar(500), @fltype varchar(1), @remark varchar(100), @billno varchar(20), @smessage varchar(100) output with encryption as declare @vipflbill varchar(20) declare @vipbk varchar(20) declare @sql varchar(8000) begin select a.vipcode from t_vip a left join (select vipcode,sum(xfjftotal) xfjftotal from t_vippt_flow where accdate='' or accdate is null group by vipcode) t on a.vipcode=t.vipcode where a.vipcode=@vipcode and a.sumxfjftotal+isnull(xfjftotal,0)-a.sumfljftotal<@fljftotal if @@rowcount>0 begin select @smessage='会员可返利积分不足' return (-1) end update t_vip set sumfljftotal=sumfljftotal+@fljftotal,sumfltotal=sumfltotal+@fltotal,chgdate=convert(varchar(19),getdate(),120) where vipcode=@vipcode if @@error<>0 begin select @smessage='修改会员返利信息失败' return (-1) end select vipcode from t_vip_currpt where vipcode=@vipcode if @@rowcount=0 begin insert into t_vip_currpt(vipcode,storetotal,picktotal,fltotal,fljftotal,xfjftotal) values(@vipcode,0.00,0.00,@fltotal,@fljftotal,0.00) end else begin update t_vip_currpt set fltotal=fltotal+@fltotal,fljftotal=fljftotal+@fljftotal where vipcode=@vipcode end if @@error<>0 begin select @smessage='修改会员当前业务统计报表失败' return (-1) end select @vipflbill='t_viprtn_bill_'+left(convert(char(10),getdate(),112),4) set @sql='insert into '+@vipflbill+' (billno,lrdate,accdate,orgcode,zdrname,prntimes,vipcode, yflxf,yfltotal,yfljftotal,sjflxf,sjfltotal,sjfljf,sjflplus,fltype,remark) values ('''+@billno+''',convert(varchar(10),getdate(),120),convert(varchar(10),getdate(),120),'''+@orgcode+''', '''+@zdrname+''',0,'''+@vipcode+''',0.00,'+convert(varchar(23),@yfltotal)+','+convert(varchar(23),@yfljftotal)+',0.00, '+convert(varchar(23),@fltotal)+','+convert(varchar(23),@fljftotal)+','''+@sjflplus+''','''+@fltype+''','''+@remark+''')' exec(@sql) if @@error<>0 begin select @smessage='生成会员返利单失败' return (-1) end select @vipbk='t_vipbk_'+left(convert(char(10),getdate(),112),6) set @sql='insert into '+@vipbk+' (bookdate,booktime,bizdate,vipcode,billno,memotxt,username,ywname,tendtotal,ctotal,sumtendtotal,overtotal) select convert(varchar(10),getdate(),120),convert(varchar(10),getdate(),108),lrdate,vipcode,billno, ''会员返利'',zdrname,zdrname,0.00,sjfltotal,isnull((select sumtendtotal from t_vip where vipcode=h.vipcode),0.00), isnull((select sumstoretotal-sumpaytotal from t_vip where vipcode=h.vipcode),0.00) from '+@vipflbill+' h where billno='''+@billno+''' and vipcode='''+@vipcode+'''' exec(@sql) if @@error<>0 begin select @smessage='记录会员台账失败' return (-1) end return (0) end go if exists(select * from sysobjects where name='solardata' and xtype='u') drop table solardata go create table solardata ( yearid int not null, data varchar(7) not null, dataint int not null ) go insert into solardata select 1900,'0x04bd8',19416 union all select 1901,'0x04ae0',19168 union all select 1902,'0x0a570',42352 union all select 1903,'0x054d5',21717 union all select 1904,'0x0d260',53856 union all select 1905,'0x0d950',55632 union all select 1906,'0x16554',91476 union all select 1907,'0x056a0',22176 union all select 1908,'0x09ad0',39632 union all select 1909,'0x055d2',21970 union all select 1910,'0x04ae0',19168 union all select 1911,'0x0a5b6',42422 union all select 1912,'0x0a4d0',42192 union all select 1913,'0x0d250',53840 union all select 1914,'0x1d255',119381 union all select 1915,'0x0b540',46400 union all select 1916,'0x0d6a0',54944 union all select 1917,'0x0ada2',44450 union all select 1918,'0x095b0',38320 union all select 1919,'0x14977',84343 union all select 1920,'0x04970',18800 union all select 1921,'0x0a4b0',42160 union all select 1922,'0x0b4b5',46261 union all select 1923,'0x06a50',27216 union all select 1924,'0x06d40',27968 union all select 1925,'0x1ab54',109396 union all select 1926,'0x02b60',11104 union all select 1927,'0x09570',38256 union all select 1928,'0x052f2',21234 union all select 1929,'0x04970',18800 union all select 1930,'0x06566',25958 union all select 1931,'0x0d4a0',54432 union all select 1932,'0x0ea50',59984 union all select 1933,'0x06e95',28309 union all select 1934,'0x05ad0',23248 union all select 1935,'0x02b60',11104 union all select 1936,'0x186e3',100067 union all select 1937,'0x092e0',37600 union all select 1938,'0x1c8d7',116951 union all select 1939,'0x0c950',51536 union all select 1940,'0x0d4a0',54432 union all select 1941,'0x1d8a6',120998 union all select 1942,'0x0b550',46416 union all select 1943,'0x056a0',22176 union all select 1944,'0x1a5b4',107956 union all select 1945,'0x025d0',9680 union all select 1946,'0x092d0',37584 union all select 1947,'0x0d2b2',53938 union all select 1948,'0x0a950',43344 union all select 1949,'0x0b557',46423 union all select 1950,'0x06ca0',27808 union all select 1951,'0x0b550',46416 union all select 1952,'0x15355',86869 union all select 1953,'0x04da0',19872 union all select 1954,'0x0a5d0',42448 union all select 1955,'0x14573',83315 union all select 1956,'0x052d0',21200 union all select 1957,'0x0a9a8',43432 union all select 1958,'0x0e950',59728 union all select 1959,'0x06aa0',27296 union all select 1960,'0x0aea6',44710 union all select 1961,'0x0ab50',43856 union all select 1962,'0x04b60',19296 union all select 1963,'0x0aae4',43748 union all select 1964,'0x0a570',42352 union all select 1965,'0x05260',21088 union all select 1966,'0x0f263',62051 union all select 1967,'0x0d950',55632 union all select 1968,'0x05b57',23383 union all select 1969,'0x056a0',22176 union all select 1970,'0x096d0',38608 union all select 1971,'0x04dd5',19925 union all select 1972,'0x04ad0',19152 union all select 1973,'0x0a4d0',42192 union all select 1974,'0x0d4d4',54484 union all select 1975,'0x0d250',53840 union all select 1976,'0x0d558',54616 union all select 1977,'0x0b540',46400 union all select 1978,'0x0b5a0',46496 union all select 1979,'0x195a6',103846 union all select 1980,'0x095b0',38320 union all select 1981,'0x049b0',18864 union all select 1982,'0x0a974',43380 union all select 1983,'0x0a4b0',42160 union all select 1984,'0x0b27a',45690 union all select 1985,'0x06a50',27216 union all select 1986,'0x06d40',27968 union all select 1987,'0x0af46',44870 union all select 1988,'0x0ab60',43872 union all select 1989,'0x09570',38256 union all select 1990,'0x04af5',19189 union all select 1991,'0x04970',18800 union all select 1992,'0x064b0',25776 union all select 1993,'0x074a3',29859 union all select 1994,'0x0ea50',59984 union all select 1995,'0x06b58',27480 union all select 1996,'0x055c0',21952 union all select 1997,'0x0ab60',43872 union all select 1998,'0x096d5',38613 union all select 1999,'0x092e0',37600 union all select 2000,'0x0c960',51552 union all select 2001,'0x0d954',55636 union all select 2002,'0x0d4a0',54432 union all select 2003,'0x0da50',55888 union all select 2004,'0x07552',30034 union all select 2005,'0x056a0',22176 union all select 2006,'0x0abb7',43959 union all select 2007,'0x025d0',9680 union all select 2008,'0x092d0',37584 union all select 2009,'0x0cab5',51893 union all select 2010,'0x0a950',43344 union all select 2011,'0x0b4a0',46240 union all select 2012,'0x0baa4',47780 union all select 2013,'0x0ad50',44368 union all select 2014,'0x055d9',21977 union all select 2015,'0x04ba0',19360 union all select 2016,'0x0a5b0',42416 union all select 2017,'0x15176',86390 union all select 2018,'0x052b0',21168 union all select 2019,'0x0a930',43312 union all select 2020,'0x07954',31060 union all select 2021,'0x06aa0',27296 union all select 2022,'0x0ad50',44368 union all select 2023,'0x05b52',23378 union all select 2024,'0x04b60',19296 union all select 2025,'0x0a6e6',42726 union all select 2026,'0x0a4e0',42208 union all select 2027,'0x0d260',53856 union all select 2028,'0x0ea65',60005 union all select 2029,'0x0d530',54576 union all select 2030,'0x05aa0',23200 union all select 2031,'0x076a3',30371 union all select 2032,'0x096d0',38608 union all select 2033,'0x04bd7',19415 union all select 2034,'0x04ad0',19152 union all select 2035,'0x0a4d0',42192 union all select 2036,'0x1d0b6',118966 union all select 2037,'0x0d250',53840 union all select 2038,'0x0d520',54560 union all select 2039,'0x0dd45',56645 union all select 2040,'0x0b5a0',46496 union all select 2041,'0x056d0',22224 union all select 2042,'0x055b2',21938 union all select 2043,'0x049b0',18864 union all select 2044,'0x0a577',42359 union all select 2045,'0x0a4b0',42160 union all select 2046,'0x0aa50',43600 union all select 2047,'0x1b255',111189 union all select 2048,'0x06d20',27936 union all select 2049,'0x0ada0',44448 if exists(select * from sysobjects where name='p_get_days_of_year' and xtype='p') drop procedure p_get_days_of_year go create procedure p_get_days_of_year @year int,@ydays int output as begin declare @mleap int declare @mleapnum int declare @ilunar int declare @j int set @ydays=348 --如果农历每月29天,没有闰月则共计348天 set @mleapnum=0 select @ilunar=dataint from solardata where yearid=@year set @j=32768 --1000 0000 0000 0000b while @j>8 begin if @ilunar & @j >0 set @ydays=@ydays+1 set @j=@j/2 end set @mleap = @ilunar & 15 if @mleap > 0 begin if @ilunar & 65536 > 0 -- 1 0000 0000 1110 0000b 看闰月的大小 set @mleapnum=30 else set @mleapnum=29 set @ydays=@ydays+@mleapnum end return (1) end go if exists(select * from sysobjects where name='p_get_solar_day' and xtype='p') drop procedure p_get_solar_day go create procedure p_get_solar_day @lunarday varchar(10), @solarday varchar(10) output as begin declare @i int declare @j int declare @year int declare @month int declare @day int declare @mdays int declare @totaldays int declare @ilunar int declare @mleap int declare @mleapnum int declare @slunarday varchar(10) declare @ydays int set @lunarday=cast(@lunarday as varchar(10)) set @slunarday=convert(varchar(10),@lunarday,120) set @i=1900 set @totaldays=0 set @year = cast(substring(@slunarday,1,4) as int) while @i< @year begin exec p_get_days_of_year @i,@ydays out set @totaldays=@totaldays+ @ydays set @i=@i+1 end set @i=1 set @mdays=0 set @month = cast(substring(@slunarday,6,2) as int) select @ilunar=dataint from solardata where yearid=@year set @j=32768 while @i < @month begin if @ilunar & @j >0 set @totaldays=@totaldays+30 else set @totaldays=@totaldays+29 set @j=@j/2 set @i=@i+1 end set @mleap = @ilunar & 15 if @mleap >0 and @mleap < @month begin if @ilunar & 65536 > 0 set @mleapnum=30 else set @mleapnum=29 set @totaldays=@totaldays+@mleapnum end set @day=cast(substring(@slunarday,9,2) as int) set @totaldays=@totaldays+@day set @solarday='1900-01-30' set @solarday=convert(varchar(10),dateadd(day,@totaldays,@solarday),120) return (1) end go if exists(select * from sysobjects where name='p_get_next_birthday' and xtype='p') drop procedure p_get_next_birthday go create procedure p_get_next_birthday @lunarbirthday varchar(10), @solarbirthday varchar(10) output, @days int output as begin declare @year varchar(4) declare @intyear int declare @month varchar(2) declare @day varchar(2) declare @slunarbirhtday varchar(10) declare @tmplunarday varchar(10) declare @daysofyear int set @slunarbirhtday=convert(varchar(10),@lunarbirthday,120) set @intyear=cast(substring(convert(varchar(10),getdate(),120),1,4) as int)-1 set @month=substring(@slunarbirhtday,6,2) set @day=substring(@slunarbirhtday,9,2) set @year=cast(@intyear as varchar(4)) set @tmplunarday = @year+'-'+@month+'-'+@day exec p_get_solar_day @tmplunarday,@solarbirthday out while datediff(day,getdate(),@solarbirthday)<0 begin set @intyear=@intyear+1 set @year=cast(@intyear as varchar(4)) set @tmplunarday = @year+'-'+@month+'-'+@day exec p_get_solar_day @tmplunarday,@solarbirthday out end set @solarbirthday=convert(varchar(10),@solarbirthday,120) set @days =datediff(day,convert(char(10),getdate(),120), convert(char(10),@solarbirthday)) return (1) end go if exists(select * from sysobjects where name='p_update_vip_birthday' and xtype='p') drop procedure p_update_vip_birthday go create procedure p_update_vip_birthday as begin declare @vipcode varchar(20) declare @birthday varchar(20) declare @birthdaytype varchar(1) declare @nextbirthday varchar(10) declare @curyear varchar(4) declare @intcuryear int update t_vip set birth='' where birth<>'' and birth is not null and isdate(birth)<>1 update t_vip set nextbirth='' where nextbirth<>'' and nextbirth is not null and isdate(nextbirth)<>1 update t_vip set birth=convert(varchar(10),convert(datetime,birth),120) where birth<>'' and birth<>convert(varchar(10),convert(datetime,birth),120) update t_vip set nextbirth=convert(varchar(10),convert(datetime,nextbirth),120) where nextbirth<>'' and nextbirth<>convert(varchar(10),convert(datetime,nextbirth),120) declare cur_birthday cursor for select vipcode,birth,birthtype from t_vip where isdate(birth)=1 and cast(nextbirth- getdate() as int)<0 and t_vip.birth is not null select convert(varchar(20),getdate(),114) open cur_birthday fetch next from cur_birthday into @vipcode,@birthday,@birthdaytype while @@fetch_status=0 begin if @birthdaytype='0' and @birthday is not null and @birthday<>'' begin set @intcuryear = cast(substring(convert(varchar(10),getdate(),120),1,4) as int) if substring(@birthday,6,5)='02-29' begin set @intcuryear=cast(substring(@birthday,1,4) as int) set @nextbirthday=cast(@intcuryear as varchar(4)) + substring(@birthday,5,6) if isdate(@nextbirthday)<>1 begin close cur_birthday deallocate cur_birthday return (-1) end while datediff(day,getdate(),@nextbirthday )<0 begin set @intcuryear = @intcuryear+4 set @nextbirthday=cast(@intcuryear as varchar(4)) + substring(@birthday,5,6) end end else begin set @nextbirthday=cast(@intcuryear as varchar(4)) + substring(@birthday,5,6) if isdate(@nextbirthday)<>1 begin close cur_birthday deallocate cur_birthday return (-1) end while datediff(day,getdate(),@nextbirthday )<0 begin set @intcuryear = @intcuryear+1 set @nextbirthday=cast(@intcuryear as varchar(4)) + substring(@birthday,5,6) end end end else if @birthdaytype='1' and @birthday is not null and @birthday<>'' begin exec p_get_next_birthday @birthday,@nextbirthday out,null end else set @nextbirthday='1900-01-30' update t_vip set t_vip.nextbirth=@nextbirthday where t_vip.vipcode=@vipcode fetch next from cur_birthday into @vipcode,@birthday,@birthdaytype end close cur_birthday deallocate cur_birthday return (0) end go if exists(select * from sysobjects where name='p_check_lunar_day' and xtype='p') drop procedure p_check_lunar_day go create procedure p_check_lunar_day @lunarday varchar(10), @flag int output as begin declare @year varchar(4) declare @month varchar(2) declare @day varchar(2) declare @data int declare @j int declare @i int set @flag = 1 set @year = substring(@lunarday,1,4) set @month = substring(@lunarday,6,2) set @day = substring(@lunarday,9,2) if cast(@year as int)>2048 or cast(@year as int)<1900 begin set @flag = 0 return end if cast(@month as int)>12 or cast(@month as int) <0 begin set @flag = 0 return end select @data=dataint from solardata where yearid=cast(@year as int) set @i=1 set @j=32768 while @i<@month and @j>16 begin set @i=@i+1 set @j=@j/2 end if cast(@day as int)>case when @data&@j=0 then 29 when @data&@j>0 then 30 end or cast(@day as int)<=0 begin set @flag = 0 return end set @flag=1 return 0 end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_min_fljf_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_min_fljf_total go create procedure p_vip_min_fljf_total @vipcode varchar(20), @orgcode varchar(10), @vipfltotal numeric(19,4), @vipminfljftotal numeric(19,4) output, @smessage varchar(100) output with encryption as begin declare @vipname varchar(30) declare @xfjftotal numeric(19,4) declare @rtnmsg varchar(100) declare @rtnvalue int; set @vipminfljftotal = null exec @rtnvalue = p_vip_get_xfjf_total @vipcode,@orgcode,@vipname output ,@xfjftotal output,@rtnmsg output if @rtnvalue <> 0 begin set @vipminfljftotal = -1 select @smessage='无法查询扣除积分额度' return (-1) end select top 1 @vipminfljftotal = sjjf from (select *, case when flmode = '0' then mintotal * flrate/100 when flmode = '1' then fltotal * mintotal / flstep end as minfltotal, case when flmode = '0' then maxtotal * flrate/100 when flmode = '1' then fltotal * maxtotal / flstep end as maxfltotal, case when flmode = '0' then @vipfltotal*100/flrate when flmode = '1' then @vipfltotal*flstep/fltotal end as sjjf from t_viprtn_project where flmode <> '2' and mintotal < @xfjftotal and maxtotal >= @xfjftotal) t order by sjjf if @vipminfljftotal is null begin set @vipminfljftotal = -1 select @smessage='无法查询扣除积分额度' return (-1) end else set @vipminfljftotal = floor(@vipminfljftotal) return (0) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_max_fl_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_max_fl_total go create procedure p_vip_max_fl_total @vipcode varchar(20), @vipfljftotal numeric(19,4), @vipmaxfltotal numeric(19,4) output, @smessage varchar(100) output with encryption as begin set @vipmaxfltotal = null select top 1 @vipmaxfltotal = maxfltotal from (select *, case when flmode = '0' then floor(@vipfljftotal * flrate)/100 when flmode = '1' then fltotal * floor(@vipfljftotal / flstep) end as maxfltotal from t_viprtn_project where flmode <> '2' and mintotal < @vipfljftotal and maxtotal >= @vipfljftotal) t order by maxfltotal desc if @vipmaxfltotal is null begin set @vipmaxfltotal = -1 select @smessage='积分不在返利方案范围区间,无法查询最大返利额度' return (-1) end else set @vipmaxfltotal = floor(@vipmaxfltotal*100)/100 return (0) end go if exists (select name from sysobjects where name='p_vip_day_over_plugin' and xtype='p') drop procedure p_vip_day_over_plugin go create procedure p_vip_day_over_plugin @accdate varchar(10), @usercode varchar(10), @sysdbname varchar(20), @message varchar(200) out as declare @psmsg varchar(200) begin set @message = '' return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_get_ecw_total') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_get_ecw_total go create procedure p_vip_get_ecw_total @vipcode varchar(20), @orgcode varchar(10), @vipname varchar(20) output, @total numeric(19,4) output, @verifymark varchar(13) output, @smessage varchar(100) output with encryption as declare @canuse varchar(1) declare @locktotal numeric(19,4) declare @lockmark varchar(13) declare @validdate varchar(10) declare @currdate varchar(10) declare @viptype varchar(4) begin select @canuse=canuse,@total=ecwovertotal,@verifymark=isnull(ecwverifymark,''), @locktotal=isnull(ecwlocktotal,0),@lockmark=isnull(ecwlockmark,''),@validdate=validdate from t_vip_pos where vipcode=@vipcode select @vipname=isnull(vipname,''),@viptype=viptype from t_vip where vipcode=@vipcode and isnull(sxdate,'') <> '' and exists(select * from t_viptype_org where viptype=t_vip.viptype and (orgcode='*' or orgcode=@orgcode)) if @@rowcount=0 begin select @smessage='卡号不存在或不允许在该机构使用或还没有发售' return (-1) end else if @canuse='0' begin select @smessage='卡禁用' return (-1) end if (@locktotal<>0) or ((@lockmark is not null) and (@lockmark<>'')) begin select @smessage='零钱包账户已被锁定' return (-1) end if @validdate<>'' and @validdate<>' - - ' and @validdate is not null begin set @currdate=convert(varchar(10),getdate(),120) if @validdate<@currdate begin select @smessage='有效期为'+@validdate+',卡已过期' return(-1) end end if @@error<>0 begin select @smessage='查询异常' return (-1) end else return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_ecw_store') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_ecw_store go create procedure p_vip_ecw_store @msgserialno varchar(12), @shopcode varchar(13), @posno varchar(6) , @serialno varchar(8) , @trantype varchar(1), @vipcode varchar(20), @total numeric(19,4), @vipdate varchar(10), @viptime varchar(8), @recdate varchar(10), @rectime varchar(8), @verifymark varchar(13), @ecwtotal numeric(19,4) output with encryption as begin insert into t_viptrade(msgserialno,orgcode,posno,serialno, vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag,datatype) values (@msgserialno,@shopcode,@posno,@serialno, @vipcode,@trantype,@total,@vipdate,@viptime,@recdate,@rectime,'0','2') update t_vip_pos set ecwovertotal=ecwovertotal+@total, ecwverifymark=@verifymark where vipcode= @vipcode if @@error<>0 begin return (-1) end select @ecwtotal = ecwovertotal from t_vip_pos where vipcode = @vipcode return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_ecw_sale_lock') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_ecw_sale_lock go create procedure p_vip_ecw_sale_lock @msgserialno varchar(12), @shopcode varchar(13), @posno varchar(6) , @serialno varchar(8) , @trantype varchar(1), @vipcode varchar(20), @total numeric(19,4), @vipdate varchar(10), @viptime varchar(8), @recdate varchar(10), @rectime varchar(8), @verifymark varchar(13) with encryption as begin insert into t_viptrade(msgserialno,orgcode,posno,serialno, vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag,datatype) values (@msgserialno,@shopcode,@posno,@serialno, @vipcode,@trantype,@total,@vipdate,@viptime,@recdate,@rectime,'1','1') update t_vip_pos set ecwlocktotal=@total, ecwlockmark=@verifymark, ecwmsgserialno=@msgserialno where vipcode= @vipcode if @@error<>0 return (-1) else return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_open_ecw_msg_lock') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_open_ecw_msg_lock go create procedure p_vip_open_ecw_msg_lock @vipcoden varchar(1200), @msgserialno varchar(12), @type varchar(1) with encryption as begin if @type='2' exec('update t_viptrade set lockflag=''2'' where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+''' and datatype=''1''' ) exec('update a set ecwovertotal=ecwovertotal-ecwlocktotal,ecwverifymark=ecwlockmark,ecwlocktotal=0,ecwlockmark='''',ecwmsgserialno='''' from t_vip_pos a where vipcode in '+@vipcoden+' and ecwmsgserialno='''+@msgserialno+''' ' ) if @@error<>0 return (-1) else return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_del_ecw_msg_lock') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_del_ecw_msg_lock go create procedure p_vip_del_ecw_msg_lock @vipcoden varchar(1200), @msgserialno varchar(12), @type varchar(1) with encryption as declare @srecdate varchar(10) declare @viptradeyyyy varchar(20) declare @sql varchar(2000) begin if @srecdate is null set @srecdate=convert(varchar(10),getdate(),120) select @viptradeyyyy='t_viptrade_'+substring(@srecdate,1,4) exec ('if not exists (select name from dbo.sysobjects where name='''+ @viptradeyyyy+''' and xtype=''u'' ) create table '+ @viptradeyyyy+'( msgserialno varchar (12) not null , orgcode varchar (10) not null , posno varchar (6) not null , serialno varchar (8) not null , trantype varchar (1) not null , vipcode varchar (20) not null , total numeric (19,4) not null , vipdate varchar (10) not null , viptime varchar (8) not null , recdate varchar (10) not null , rectime varchar (8) not null , lockflag varchar (1) not null, datatype varchar (1) not null)') exec('insert into ' + @viptradeyyyy+'(msgserialno,orgcode,posno,serialno,vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag,datatype) select msgserialno,orgcode,posno,serialno,vipcode,trantype,total,vipdate,viptime,recdate,rectime,lockflag='''+@type+''',datatype from t_viptrade where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+''' and datatype=''1''') exec('delete from t_viptrade where vipcode in '+@vipcoden+' and msgserialno='''+@msgserialno+''' and datatype=''1''') exec('update a set ecwlocktotal=0,ecwlockmark='''',ecwmsgserialno='''' from t_vip_pos a where vipcode in '+@vipcoden+' and ecwmsgserialno='''+@msgserialno+'''') if @@error<>0 return (-1) else return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_update_grade') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_update_grade go create procedure p_vip_update_grade @sysdbname varchar(20), @accdate varchar(10), @message varchar(200) out with encryption as declare @lxcode varchar(4), @uptolxcode varchar(4), @sumtendtotalx numeric(19,4), @sumxfjftotalx numeric(19,4), @daytenddaysn int, @daytendtotalx numeric(19,4), @dayxfjfdaysn int, @dayxfjftotalx numeric(19,4), @viprpttbl varchar(20), @nowdate varchar(10), @bgndate varchar(10), @vipbktbl varchar(20), @shopname varchar(50), @sql varchar(2000), @nsql nvarchar(2000), @smsgeg varchar(500), @smsg varchar(500), @destphoneno varchar(20), @vipcode varchar(20), @vipname varchar(20), @vipsex varchar(10), @oldlxname varchar(20), @newlxname varchar(20) begin select @nowdate = convert(varchar(10),getdate(),120), @vipbktbl = 't_vipbk_' + substring(@accdate,1,4) + substring(@accdate,6,2) set @nsql ='select @shopname = itemvalue from ' + @sysdbname + '..t_syscfg where section=''SYSTEM'' and itemname=''ShopName''' exec sp_executesql @nsql, N'@shopname varchar(200) output', @shopname out set @nsql ='select @smsgeg = itemvalue from ' + @sysdbname + '..t_syscfg where section=''SMSG'' and itemname=''VipUpdate''' exec sp_executesql @nsql, N'@smsgeg varchar(200) output', @smsgeg out if exists(select name from tempdb..sysobjects where name='##tmpvipupdate' and xtype='u') drop table ##tmpvipupdate create table ##tmpvipupdate (vipcode varchar(20) not null,oldlxcode varchar(4) not null,newlxcode varchar(4) not null,condition varchar(10) null,remark varchar(200)) if exists(select name from tempdb..sysobjects where name='##tmpviptotal' and xtype='u') drop table ##tmpviptotal create table ##tmpviptotal (vipcode varchar(20) not null,viptotal numeric(19,4)) if exists(select 1 from t_viptype where isnull(uptolxcode,'')<>'' and sumtendtotalx>0) begin insert into ##tmpvipupdate(vipcode,oldlxcode,newlxcode,condition,remark) select v.vipcode,v.viptype,t.uptolxcode,'a' as condition, '累计消费金额' + cast(cast(v.sumtendtotal as money) as varchar) + '达到' + cast(cast(t.sumtendtotalx as money) as varchar) + ',' + t.lxcode + '升' + t.uptolxcode as remark from t_vip v,t_viptype t where v.viptype=t.lxcode and isnull(uptolxcode,'')<>'' and sumtendtotalx>0 and v.sumtendtotal>=t.sumtendtotalx if @@error <> 0 begin set @message = '处理升级条件a失败' return (-1) end end if exists(select 1 from t_viptype where isnull(uptolxcode,'')<>'' and sumxfjftotalx>0) begin insert into ##tmpvipupdate(vipcode,oldlxcode,newlxcode,condition,remark) select v.vipcode,v.viptype,t.uptolxcode,'b' as condition, '累计消费积分' + cast(cast(v.sumxfjftotal as money) as varchar) + '达到' + cast(cast(t.sumxfjftotalx as money) as varchar) + ',' + t.lxcode + '升' + t.uptolxcode as remark from t_vip v,t_viptype t where v.viptype=t.lxcode and isnull(uptolxcode,'')<>'' and sumxfjftotalx>0 and v.sumxfjftotal>=t.sumxfjftotalx if @@error <> 0 begin set @message = '处理升级条件b失败' return (-1) end end if exists(select 1 from t_viptype where isnull(uptolxcode,'')<>'' and daytenddaysn>0 and daytendtotalx>0) begin delete from ##tmpviptotal declare cur_viptype cursor for select lxcode,uptolxcode,daytenddaysn,daytendtotalx from t_viptype where isnull(uptolxcode,'')<>'' and daytenddaysn>0 and daytendtotalx>0 order by lxlevel open cur_viptype fetch next from cur_viptype into @lxcode, @uptolxcode, @daytenddaysn, @daytendtotalx while @@fetch_status = 0 begin set @bgndate = convert(varchar(10),dateadd(day, -1*@daytenddaysn, getdate()),120) declare cur_viprpt cursor for select name from sysobjects where name like 't_viprpt_[0-9][0-9][0-9][0-9][0-9][0-9]' and name>='t_viprpt_' + substring(@bgndate,1,4) + substring(@bgndate,6,2) and name<='t_viprpt_' + substring(@accdate,1,4) + substring(@accdate,6,2) open cur_viprpt fetch next from cur_viprpt into @viprpttbl while @@fetch_status = 0 begin if exists(select name from sysobjects where name=@viprpttbl and xtype='u') begin set @sql = 'insert into ##tmpviptotal (vipcode,viptotal) select t.vipcode,sum(t.tendtotal) viptotal from ' + @viprpttbl + ' t,t_vip v where t.orgcode=''*'' and t.vipcode=v.vipcode and v.viptype=''' + @lxcode + ''' and ( isnull(v.lastupdate,'''')<>'''' and v.lastupdate>=''' + @bgndate + ''' and t.accdate>v.lastupdate or isnull(v.lastupdate,'''')<''' + @bgndate + ''' and t.accdate>''' + @bgndate + ''') group by t.vipcode ' exec(@sql) if @@error <> 0 begin set @message = '处理升级条件c失败-汇总会员消费数据' return (-1) end end fetch next from cur_viprpt into @viprpttbl end close cur_viprpt deallocate cur_viprpt insert into ##tmpvipupdate(vipcode,oldlxcode,newlxcode,condition,remark) select v.vipcode,@lxcode as viptype,@uptolxcode as uptolxcode,'c' as condition, '最近' + cast(@daytenddaysn as varchar) + '天内消费金额' + cast(cast(x.viptotal as money) as varchar) + '达到' + cast(cast(@daytendtotalx as money) as varchar) + ',' + @lxcode + '升' + @uptolxcode as remark from (select vipcode,sum(viptotal) viptotal from ##tmpviptotal group by vipcode) x, t_vip v where x.vipcode=v.vipcode and v.viptype=@lxcode and x.viptotal>=@daytendtotalx if @@error <> 0 begin set @message = '处理升级条件c失败-插入临时表数据' return (-1) end fetch next from cur_viptype into @lxcode, @uptolxcode, @daytenddaysn, @daytendtotalx end close cur_viptype deallocate cur_viptype end if exists(select 1 from t_viptype where isnull(uptolxcode,'')<>'' and dayxfjfdaysn>0 and dayxfjftotalx>0) begin delete from ##tmpviptotal declare cur_viptype cursor for select lxcode,uptolxcode,dayxfjfdaysn,dayxfjftotalx from t_viptype where isnull(uptolxcode,'')<>'' and dayxfjfdaysn>0 and dayxfjftotalx>0 order by lxlevel open cur_viptype fetch next from cur_viptype into @lxcode, @uptolxcode, @dayxfjfdaysn, @dayxfjftotalx while @@fetch_status = 0 begin set @bgndate = convert(varchar(10),dateadd(day, -1*@dayxfjfdaysn, getdate()),120) declare cur_viprpt cursor for select name from sysobjects where name like 't_viprpt_[0-9][0-9][0-9][0-9][0-9][0-9]' and name>='t_viprpt_' + substring(@bgndate,1,4) + substring(@bgndate,6,2) and name<='t_viprpt_' + substring(@accdate,1,4) + substring(@accdate,6,2) open cur_viprpt fetch next from cur_viprpt into @viprpttbl while @@fetch_status = 0 begin if exists(select name from sysobjects where name=@viprpttbl and xtype='u') begin set @sql = 'insert into ##tmpviptotal (vipcode,viptotal) select t.vipcode,sum(t.xfjftotal) viptotal from ' + @viprpttbl + ' t,t_vip v where t.orgcode=''*'' and t.vipcode=v.vipcode and v.viptype=''' + @lxcode + ''' and ( isnull(v.lastupdate,'''')<>'''' and v.lastupdate>=''' + @bgndate + ''' and t.accdate>v.lastupdate or isnull(v.lastupdate,'''')<''' + @bgndate + ''' and t.accdate>''' + @bgndate + ''') group by t.vipcode ' exec(@sql) if @@error <> 0 begin set @message = '处理升级条件d失败-汇总会员积分数据' return (-1) end end fetch next from cur_viprpt into @viprpttbl end close cur_viprpt deallocate cur_viprpt insert into ##tmpvipupdate(vipcode,oldlxcode,newlxcode,condition,remark) select v.vipcode,@lxcode as viptype,@uptolxcode as uptolxcode,'d' as condition, '最近' + cast(@dayxfjfdaysn as varchar) + '天内消费积分' + cast(cast(x.viptotal as money) as varchar) + '达到' + cast(cast(@dayxfjftotalx as money) as varchar) + ',' + @lxcode + '升' + @uptolxcode as remark from (select vipcode,sum(viptotal) viptotal from ##tmpviptotal group by vipcode) x, t_vip v where x.vipcode=v.vipcode and v.viptype=@lxcode and x.viptotal>=@dayxfjftotalx if @@error <> 0 begin set @message = '处理升级条件d失败-插入临时表数据' return (-1) end fetch next from cur_viptype into @lxcode, @uptolxcode, @dayxfjfdaysn, @dayxfjftotalx end close cur_viptype deallocate cur_viptype end update v set viptype=t.newlxcode, lastupdate=@accdate, v.canstore = p.canstore from t_vip v, (select distinct vipcode,oldlxcode,newlxcode from ##tmpvipupdate) t,t_viptype p where v.vipcode=t.vipcode and v.viptype=t.oldlxcode and p.lxcode = t.newlxcode update v set viptype=t.newlxcode, v.canstore = p.canstore from t_vip_pos v, (select distinct vipcode,oldlxcode,newlxcode from ##tmpvipupdate) t,t_viptype p where v.vipcode=t.vipcode and v.viptype=t.oldlxcode and p.lxcode = t.newlxcode set @sql = 'insert into ' + @vipbktbl + '(bookdate, booktime, bizdate, vipcode, billno, memotxt) select convert(varchar(10),getdate(),120) as bookdate, convert(varchar(8),getdate(),108) as booktime, ''' + @accdate + ''' as bizdate, vipcode, ''满足升级条件'' + condition as billno, remark as memotxt from ##tmpvipupdate t ' exec (@sql) if @@error <> 0 begin set @message = '生成会员台账失败' return (-1) end if @smsgeg = '' begin set @sql = 'insert into ' + @sysdbname + '..tmsgsend (destphoneno,msgcontent,createtime,remark) select case when isnull(v.mobile1,'''')<>'''' then v.mobile1 else v.mobile2 end as destphoneno, ''尊敬的{'' + v.vipname + ''}{'' + case v.vipsex when ''0'' then ''先生'' when ''1'' then ''女士'' else ''先生/女士'' end + ''},您近期的消费已符合会员升级标准,会员等级已从{'' + t.oldlxname + ''}升级为{'' + t.newlxname + ''},欢迎您再次光临。{' + @shopname + '} '' as msgcontent, getdate() as createtime,''日结会员升级生成1'' as remark from t_vip v, (select distinct x.vipcode,x.oldlxcode,x.newlxcode,a.lxname as oldlxname,b.lxname as newlxname from ##tmpvipupdate x left join t_viptype a on x.oldlxcode=a.lxcode left join t_viptype b on x.newlxcode=b.lxcode) t where v.vipcode=t.vipcode and (isnull(v.mobile1,'''')<>'''' or isnull(v.mobile2,'''')<>'''') ' exec (@sql) if @@error <> 0 begin set @message = '生成会员短信任务失败' return (-1) end end else begin declare cur_vip cursor for select case when isnull(v.mobile1,'')<>'' then v.mobile1 else v.mobile2 end as destphoneno, v.vipcode, v.vipname, case v.vipsex when '0' then '先生' when '1' then '女士' else '先生/女士' end as vipsex, t.oldlxname, t.newlxname from t_vip v, (select distinct x.vipcode,x.oldlxcode,x.newlxcode,a.lxname as oldlxname,b.lxname as newlxname from ##tmpvipupdate x left join t_viptype a on x.oldlxcode=a.lxcode left join t_viptype b on x.newlxcode=b.lxcode) t where v.vipcode=t.vipcode and (isnull(v.mobile1,'')<>'' or isnull(v.mobile2,'')<>'') open cur_vip fetch next from cur_vip into @destphoneno, @vipcode, @vipname, @vipsex, @oldlxname, @newlxname while @@fetch_status = 0 begin set @smsg = @smsgeg set @smsg = replace(@smsg,'%会员编码%',@vipcode) set @smsg = replace(@smsg,'%会员姓名%',@vipname) set @smsg = replace(@smsg,'%性别%',@vipsex) set @smsg = replace(@smsg,'%原类型名称%',@oldlxname) set @smsg = replace(@smsg,'%新类型名称%',@newlxname) set @smsg = replace(@smsg,'%店名%',@shopname) set @sql = 'insert into ' + @sysdbname + '..tmsgsend (destphoneno,msgcontent,createtime,remark) select ''' + @destphoneno + ''' as destphoneno,''' + @smsg + ''' as msgcontent, getdate() as createtime,''日结会员升级生成2'' as remark ' exec(@sql) if @@error <> 0 begin set @message = '生成会员模板短信任务失败' return (-1) end fetch next from cur_vip into @destphoneno, @vipcode, @vipname, @vipsex, @oldlxname, @newlxname end close cur_vip deallocate cur_vip end if exists(select name from tempdb..sysobjects where name='##tmpvipupdate' and xtype='u') drop table ##tmpvipupdate if exists(select name from tempdb..sysobjects where name='##tmpviptotal' and xtype='u') drop table ##tmpviptotal set @message = '' return (1) end go if exists (select * from dbo.sysobjects where id = object_id(N'p_vip_store') and objectproperty(id, N'isprocedure') = 1) drop procedure p_vip_store go create procedure p_vip_store @sysdbname varchar(20), @vipcode varchar(20), @billno varchar(20), @bizdate varchar(10), @ywusercode varchar(6), @ywusername varchar(10), @yworgcode varchar(10), @iswriteic varchar(1), @usercode varchar(6), @username varchar(10), @storetotal numeric(19,4), @zstotal numeric(19,4), @prjcode varchar(20), @storetendcode varchar(1), @message varchar(200) out with encryption as declare @sql varchar(2000) declare @ssql nvarchar(2000) declare @cardtype varchar(1) declare @verifymark varchar(13) declare @overtotal numeric(19,4) declare @overcztotal numeric(19,4) declare @overzstotal numeric(19,4) declare @locktotal numeric(19,4) declare @mincktotal numeric(19,4) declare @sumstoretotal numeric(19,4) declare @sumpaytotal numeric(19,4) declare @vipbk varchar(20) declare @vipstorename varchar(20) declare @vipvaliddate varchar(10) declare @vipcanuse varchar(1) declare @vipcanstore varchar(1) begin select @cardtype=a.cardtype,@verifymark=b.verifymark, @sumstoretotal=a.sumstoretotal,@sumpaytotal=a.sumpaytotal,@overtotal=b.overtotal, @locktotal=isnull(b.locktotal,0),@mincktotal=isnull(c.mincktotal,0), @vipvaliddate=isnull(a.validdate,''),@vipcanuse=a.canuse,@vipcanstore=a.canstore, @overcztotal = b.overcztotal, @overzstotal = b.overzstotal from t_vip a left join t_vip_pos b on a.vipcode=b.vipcode left join t_viptype c on a.viptype=c.lxcode where a.vipcode=@vipcode if @vipvaliddate='' begin set @message='此会员编码尚未注册' return (-1) end if (@vipvaliddate<>' - - ') and (datediff(day,@vipvaliddate,convert(varchar(10),getdate(),120))>0) begin set @message='此会员编码已过期' return (-1) end if @vipcanuse<>'1' begin set @message='此会员编码已禁用' return (-1) end if @vipcanstore<>'1' begin set @message='此会员编码不能充值' return (-1) end if @locktotal<>0 begin set @message='此会员卡已被锁定,不能进行充值操作' return (-1) end if @mincktotal>@sumstoretotal-@sumpaytotal+@storetotal begin set @message='此会员卡充值后金额低于最低充值金额,不能进行充值操作' return (-1) end if @cardtype='0' or @cardtype='2' begin if @verifymark<>dbo.p_vip_remark(@vipcode,@overtotal) begin set @message='会员"' + @vipcode + '"的结余金额校验位出错,请查看' return (-1) end end set @vipstorename='t_vipstore_'+left(convert(char(10),getdate(),120),4) exec('if not exists(select * from sysobjects where xtype=''u'' and name='''+@vipstorename+''') create table '+@vipstorename+'( billno varchar(20) not null, vipcode varchar(20) not null, bizdate varchar(10) null, rzdate varchar(10) null, rztime varchar(8) null, zdrcode varchar(6) null, zdrname varchar(10) null, storetotal numeric(19,4) null, ywusercode varchar(6) null, ywusername varchar(10) null, yworgcode varchar(10) null, tendcode varchar(4) null, sstotal numeric(19,4) not null default(0), zstotal numeric(19,4) not null default(0), prjcode varchar(20) null, constraint pk_' + @vipstorename + ' primary key(billno,vipcode))') set @vipbk='t_vipbk_'+left(convert(char(10),getdate(),112),6) exec('if not exists(select * from sysobjects where xtype=''u'' and name='''+@vipbk+''') create table '+@vipbk+'( bookdate varchar(10) not null, booktime varchar(8) not null, bizdate varchar(10) not null, vipcode varchar(20) not null, billno varchar(20) null, memotxt varchar(50) null, username varchar(10) null, ywname varchar(10) null, tendtotal numeric(19,4) null, ctotal numeric(19,4) null, sumtendtotal numeric(19,4) null, overtotal numeric(19,4) null, tag varchar(1) null)') if @billno='' begin set @ssql='exec '+@sysdbname+'.dbo.f_get_billno ''cc'','''+@yworgcode+''',''1'',@billno output' exec sp_executesql @ssql,N'@billno varchar(20) output',@billno out if @billno is null begin set @message = '生成会员充值单据号失败' return(-1) end end set @sql='insert into '+@vipstorename+'(billno,vipcode,bizdate,rzdate,rztime,zdrcode,zdrname,storetotal,ywusercode,ywusername,yworgcode,tendcode,sstotal,zstotal,prjcode) values('''+@billno+''','''+@vipcode+''',convert(varchar(10),getdate(),120),'''+@bizdate+''',convert(varchar(8),getdate(),108), '''+@usercode+''','''+@username+''','+cast(@storetotal as varchar)+','''+@ywusercode+''','''+@ywusername+''','''+@yworgcode+''','''+@storetendcode+''', '+ cast((@storetotal-@zstotal) as varchar)+','+cast(@zstotal as varchar)+','''+ @prjcode +''')' exec(@sql) if @@error<>0 begin set @message='保存充值单失败' return (-1) end if exists(select * from t_vip_currpt where vipcode=@vipcode) update t_vip_currpt set storetotal=storetotal+@storetotal where vipcode=@vipcode else insert into t_vip_currpt(vipcode,storetotal,picktotal,fltotal,fljftotal) values (@vipcode,@storetotal,0,0,0) if @@error<>0 begin set @message='处理会员当前报表失败' return (-1) end set @sql='insert into '+@vipbk+' (bookdate,booktime,bizdate,vipcode,billno,memotxt,username,ywname,tendtotal,ctotal,sumtendtotal,overtotal) select convert(varchar(10),getdate(),120),convert(varchar(10),getdate(),108),bizdate,vipcode,billno, ''充值'',zdrname,zdrname,0.00,storetotal,isnull((select sumtendtotal from t_vip where vipcode=h.vipcode),0.00), isnull((select sumstoretotal-sumpaytotal from t_vip where vipcode=h.vipcode),0.00)+storetotal from '+@vipstorename+' h where billno='''+@billno+''' and vipcode='''+@vipcode+'''' exec(@sql) if @@error<>0 begin set @message='记录会员台账失败' return (-1) end update t_vip set sumstoretotal=sumstoretotal+@storetotal where vipcode=@vipcode if @@error<>0 begin set @message='处理t_vip表失败' return (-1) end update t_vip_pos set overtotal=overtotal+@storetotal,verifymark=dbo.p_vip_remark(@vipcode,overtotal+@storetotal), overcztotal=overcztotal+@storetotal-@zstotal,overzstotal=overzstotal+@zstotal where vipcode=@vipcode if @@error<>0 begin set @message='处理viptopos表失败' return (-1) end if @cardtype='1' and @iswriteic='0' begin set @sql='insert into t_vipstore(billno,vipcode,bizdate,billtype,rzdate,zdrname,storetotal,lockflag,remark) select billno,vipcode,bizdate,''0'' as billtype,rzdate,zdrname,storetotal,''0'' as lockflag,'''' as remark from '+@vipstorename+' where billno='''+@billno+''' and vipcode='''+@vipcode+'''' exec(@sql) if @@error<>0 begin set @message='记录ic卡补登数据失败' return (-1) end end if @cardtype='1' and @iswriteic='1' begin insert into t_viplog_icrw (bookdate,booktime,vipcode,memotxt,usercode,username,fstotal) values (convert(varchar(10),getdate(),120),convert(varchar(10),getdate(),108),@vipcode,'充值',@usercode,@username,@storetotal) if @@error<>0 begin set @message='记录ic卡日志失败' return (-1) end end set @message = '' return (1) end go