242 lines
8.6 KiB
SQL
Executable File
242 lines
8.6 KiB
SQL
Executable File
/*
|
|
Navicat Premium Data Transfer
|
|
|
|
Source Server : 127.0.0.1
|
|
Source Server Type : MySQL
|
|
Source Server Version : 50739
|
|
Source Host : 127.0.0.1:3306
|
|
Source Schema : mir_amdb
|
|
|
|
Target Server Type : MySQL
|
|
Target Server Version : 50739
|
|
File Encoding : 65001
|
|
|
|
Date: 11/10/2022 21:31:38
|
|
*/
|
|
|
|
SET NAMES utf8mb4;
|
|
SET FOREIGN_KEY_CHECKS = 0;
|
|
|
|
-- ----------------------------
|
|
-- Table structure for am
|
|
-- ----------------------------
|
|
DROP TABLE IF EXISTS `am`;
|
|
CREATE TABLE `am` (
|
|
`userid` int(10) UNSIGNED NOT NULL,
|
|
`actorid` int(10) UNSIGNED NOT NULL,
|
|
`account` varchar(64) CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL DEFAULT '',
|
|
`amount` double NOT NULL DEFAULT 0,
|
|
`updatetime` datetime(0) NOT NULL,
|
|
INDEX `userid`(`userid`) USING BTREE,
|
|
INDEX `actorid`(`actorid`) USING BTREE
|
|
) ENGINE = MyISAM CHARACTER SET = utf8 COLLATE = utf8_general_ci ROW_FORMAT = DYNAMIC;
|
|
|
|
-- ----------------------------
|
|
-- Records of am
|
|
-- ----------------------------
|
|
|
|
-- ----------------------------
|
|
-- Table structure for amorder
|
|
-- ----------------------------
|
|
DROP TABLE IF EXISTS `amorder`;
|
|
CREATE TABLE `amorder` (
|
|
`userid` int(10) UNSIGNED NOT NULL DEFAULT 0,
|
|
`consume` int(10) NOT NULL DEFAULT 0,
|
|
`remain` int(10) NOT NULL DEFAULT 0,
|
|
`srvid` int(10) NOT NULL DEFAULT 0,
|
|
`actorid` int(10) UNSIGNED NULL DEFAULT 0,
|
|
`charname` varchar(32) CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL DEFAULT '',
|
|
`comment` varchar(32) CHARACTER SET utf8 COLLATE utf8_general_ci NOT NULL DEFAULT '',
|
|
`recdate` datetime(0) NOT NULL,
|
|
INDEX `userid`(`userid`) USING BTREE
|
|
) ENGINE = MyISAM CHARACTER SET = utf8 COLLATE = utf8_general_ci ROW_FORMAT = DYNAMIC;
|
|
|
|
-- ----------------------------
|
|
-- Records of amorder
|
|
-- ----------------------------
|
|
|
|
-- ----------------------------
|
|
-- Table structure for payorder
|
|
-- ----------------------------
|
|
DROP TABLE IF EXISTS `payorder`;
|
|
CREATE TABLE `payorder` (
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`orderid` varchar(32) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`account` varchar(60) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`actorid` int(10) UNSIGNED NULL DEFAULT 0,
|
|
`actorname` varchar(64) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`money` decimal(10, 0) NULL DEFAULT NULL,
|
|
`level` int(11) NULL DEFAULT 0,
|
|
`serverid` int(10) NOT NULL DEFAULT 0,
|
|
`orderdate` datetime(0) NULL DEFAULT NULL,
|
|
`state` tinyint(4) NULL DEFAULT NULL,
|
|
`yunying` varchar(10) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`channel` varchar(32) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`paygift` varchar(20) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`rmb` float NULL DEFAULT NULL,
|
|
`paygift2` varchar(20) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
`type` int(11) NOT NULL DEFAULT 1,
|
|
`paygift3` varchar(20) CHARACTER SET utf8 COLLATE utf8_general_ci NULL DEFAULT NULL,
|
|
PRIMARY KEY (`id`) USING BTREE,
|
|
INDEX `orderid`(`orderid`) USING BTREE,
|
|
INDEX `index_orderdate`(`orderdate`) USING BTREE
|
|
) ENGINE = MyISAM AUTO_INCREMENT = 1 CHARACTER SET = utf8 COLLATE = utf8_general_ci ROW_FORMAT = DYNAMIC;
|
|
|
|
-- ----------------------------
|
|
-- Records of payorder
|
|
-- ----------------------------
|
|
|
|
-- ----------------------------
|
|
-- Procedure structure for Consume
|
|
-- ----------------------------
|
|
DROP PROCEDURE IF EXISTS `Consume`;
|
|
delimiter ;;
|
|
CREATE PROCEDURE `Consume`(IN nUserId int unsigned, IN nConsume INT,IN nActorId INT unsigned , IN sActorName VARCHAR(32),
|
|
IN nServerId INT, IN nLevel INT)
|
|
BEGIN
|
|
declare nAmount INT default 0;
|
|
declare sAccount VARCHAR(64);
|
|
declare nAmountActorId INT unsigned default 0;
|
|
select `amount`,`account`,`actorid` into nAmount, sAccount,nAmountActorId from am where (`userid` = nUserId and `actorid`= nActorId) or (`userid` = nUserId and `actorid`=0) limit 1;
|
|
|
|
if nConsume > 0 and nAmount >= nConsume then
|
|
update am set `amount` = `amount` - nConsume where `userid` = nUserId and `amount` >= nConsume and `actorid`= nAmountActorId limit 1;
|
|
set nAmount = nAmount - nConsume;
|
|
insert into amorder values (nUserId, nConsume, nAmount, nServerId, nActorId, sActorName, "g2xhCAV-peek", now());
|
|
|
|
if nAmountActorId = 0 then
|
|
update payorder set `actorid` = nActorId, `actorname` = sActorName,`level` = nLevel where `account`= sAccount and `actorid`= nAmountActorId;
|
|
end if;
|
|
select 0, nAmount;
|
|
else
|
|
select -1, nAmount;
|
|
end if;
|
|
END
|
|
;;
|
|
delimiter ;
|
|
|
|
-- ----------------------------
|
|
-- Procedure structure for HistoryPay
|
|
-- ----------------------------
|
|
DROP PROCEDURE IF EXISTS `HistoryPay`;
|
|
delimiter ;;
|
|
CREATE PROCEDURE `HistoryPay`()
|
|
BEGIN
|
|
declare nY INT default 0;
|
|
declare sM varchar(2);
|
|
declare sMinDate varchar(20);
|
|
declare sMaxDate varchar(20);
|
|
select nYear,sMonth into nY,sM from (select distinct year(orderdate) as nYear,DATE_FORMAT(orderdate,'%m') as sMonth from payorder ) tmp where CONCAT(nYear,'-',sMonth)<>CONCAT(year(NOW()),'-',DATE_FORMAT(NOW(),'%m')) limit 1;
|
|
if sM is not null then
|
|
set @sqlstr=CONCAT("
|
|
CREATE TABLE IF NOT EXISTS payorder_",nY,sM,"
|
|
(
|
|
`id` int(11) NOT NULL AUTO_INCREMENT,
|
|
`orderid` varchar(32) DEFAULT NULL,
|
|
`account` varchar(60) DEFAULT NULL,
|
|
`money` decimal(10,0) DEFAULT NULL,
|
|
`serverid` int(10) NOT NULL DEFAULT 0,
|
|
`orderdate` datetime DEFAULT NULL,
|
|
`state` tinyint(4) DEFAULT NULL,
|
|
`yunying` varchar(10) DEFAULT NULL,
|
|
`paygift` varchar(20) DEFAULT NULL,
|
|
`rmb` float DEFAULT NULL,
|
|
`paygift2` varchar(20) DEFAULT NULL,
|
|
`type` int(11) NOT NULL DEFAULT '1',
|
|
`paygift3` varchar(20) DEFAULT NULL,
|
|
PRIMARY KEY (`id`),
|
|
KEY `orderid` (`orderid`)
|
|
) ENGINE=MyISAM DEFAULT CHARSET=UTF8");
|
|
prepare stmt from @sqlstr;
|
|
execute stmt;
|
|
set sMinDate = CONCAT(nY,"-",sM,"-01 00:00:00");
|
|
set @sDate = CONCAT(nY,"-",sM,"-01 23:59:59");
|
|
set sMaxDate = date_add(date_add(@sDate,interval 1 month),interval -1 day);
|
|
set @sqlstr = CONCAT("INSERT INTO payorder_",nY,sM," SELECT * FROM payorder WHERE orderdate>='",sMinDate,"' AND orderdate<='",sMaxDate,"'");
|
|
prepare stmt from @sqlstr;
|
|
execute stmt;
|
|
delete from payorder where orderdate>=sMinDate and orderdate<=sMaxDate;
|
|
end if;
|
|
END
|
|
;;
|
|
delimiter ;
|
|
|
|
-- ----------------------------
|
|
-- Procedure structure for QueryAmount
|
|
-- ----------------------------
|
|
DROP PROCEDURE IF EXISTS `QueryAmount`;
|
|
delimiter ;;
|
|
CREATE PROCEDURE `QueryAmount`(IN nUserId INT unsigned, IN nServerId INT, IN nActorId INT unsigned)
|
|
BEGIN
|
|
declare nAmount INT default 0;
|
|
declare nAmountActorId INT unsigned default 0;
|
|
select `amount`,`actorid` into nAmount,nAmountActorId from am where (`userid` = nUserId and `actorid`= nActorId) or (`userid` = nUserId and `actorid`=0) limit 1;
|
|
select nAmount,nAmountActorId;
|
|
END
|
|
;;
|
|
delimiter ;
|
|
|
|
-- ----------------------------
|
|
-- Procedure structure for UserPayment
|
|
-- ----------------------------
|
|
DROP PROCEDURE IF EXISTS `UserPayment`;
|
|
delimiter ;;
|
|
CREATE PROCEDURE `UserPayment`(IN sOPID VARCHAR(32), IN sAccount VARCHAR(64), IN nMoneyChg DOUBLE, IN nRawAmount DOUBLE,
|
|
IN sServer VARCHAR(32), IN sSPID VARCHAR(8), IN nOPType INT, IN nActorId INT unsigned, IN sActorName VARCHAR(64), IN nLevel INT, IN sChannel VARCHAR(64))
|
|
BEGIN
|
|
declare nOPIdx INT default 0;
|
|
declare nId INT unsigned default null;
|
|
declare Result INT DEFAULT 0;
|
|
declare sAcc VARCHAR(64) default null;
|
|
declare nRemain INT default 0;
|
|
|
|
|
|
select `id` into nOPIdx from payorder where `orderid` = sOPID limit 1;
|
|
if nOPIdx > 0 then
|
|
set Result = 3;
|
|
else
|
|
|
|
select `userid` into nId from am where `account` = sAccount and `actorid` = nActorId limit 1;
|
|
|
|
if nId is null then
|
|
select `userid`, `account` into nId, sAcc from mir_account.globaluser where `account` = sAccount limit 1;
|
|
|
|
if (nId is null) then
|
|
set Result = 1;
|
|
else
|
|
|
|
if nMoneyChg < 0 then
|
|
set Result = 2;
|
|
else
|
|
|
|
insert into am (`userid`, `account`, `actorid`,`amount`, `updatetime`) values (nId, sAcc, nActorId,nMoneyChg, now());
|
|
end if;
|
|
end if;
|
|
|
|
else
|
|
|
|
if nMoneyChg < 0 then
|
|
select `amount` into nRemain from am where `userid` = nId and `actorid` = nActorId limit 1;
|
|
if nRemain < -nMoneyChg then
|
|
set Result = 2;
|
|
end if;
|
|
end if;
|
|
|
|
if Result = 0 then
|
|
update am set `amount` = `amount` + nMoneyChg, `updatetime` = now() where `userid` = nId and `actorid`= nActorId limit 1;
|
|
end if;
|
|
end if;
|
|
|
|
|
|
if Result = 0 then
|
|
insert into payorder (`orderid`, `account`, `actorid`,`actorname`,`money`,`level`, `rmb`, `serverid`, `orderdate`, `state`, `yunying`, `type`,`channel`)
|
|
values (sOPID, sAccount, nActorId, sActorName,nMoneyChg, nLevel,nRawAmount, sServer, now(), 1, concat("_", sSPID), nOPType, sChannel);
|
|
end if;
|
|
end if;
|
|
select Result,nId;
|
|
END
|
|
;;
|
|
delimiter ;
|
|
|
|
SET FOREIGN_KEY_CHECKS = 1;
|