Commit 6862cdde authored by Kalinka's avatar Kalinka

Update SQL Stuff. Moved Boomcoin and Burstcoin into special files, as there are differences

parent 794e510a
<?xml version="1.0" encoding="UTF-8"?>
<project version="4">
<component name="SqlDialectMappings">
<file url="file://$PROJECT_DIR$/SQL/init_booncoin.sql" dialect="MySQL" />
<file url="file://$PROJECT_DIR$/SQL/init_burstcoin.sql" dialect="MySQL" />
<file url="file://$PROJECT_DIR$/wallet_additions.sql" dialect="MariaDB" />
</component>
</project>
\ No newline at end of file
/*
Functions
*/
DROP FUNCTION IF EXISTS getRewardByHeight;
DELIMITER $$
CREATE FUNCTION getRewardByHeight(in_height bigint(20))
RETURNS INT(5) DETERMINISTIC
BEGIN
DECLARE counter, ratio, reward BIGINT(20);
SET counter = (525000 - 55500);
SET reward = 20000000000;
SELECT b.ratio INTO ratio FROM block b WHERE b.height = in_height;
IF in_height = 0 OR in_height > 20180768 THEN SET reward = 0;
ELSEIF in_height >= 18622075 THEN SET reward = 1;
ELSE
WHILE in_height > counter DO
SET counter = counter + 525000;
SET reward = reward / 2;
END WHILE;
END IF;
RETURN reward * ratio / 100 / 100000000;
END$$
DELIMITER ;
DROP FUNCTION IF EXISTS getTransactionType;
DELIMITER $$
CREATE FUNCTION getTransactionType(type tinyint(4), subtype tinyint(4))
RETURNS char(100) DETERMINISTIC
BEGIN
-- Transaction Types: https://github.com/burst-apps-team/burstcoin/blob/develop/src/brs/TransactionType.java#L34
IF type = 0 THEN
IF subtype = 0 THEN RETURN 'Ordinary Payment';
ELSEIF subtype = 1 THEN RETURN 'MultiOut Payment';
ELSEIF subtype = 2 THEN RETURN 'MultiOut-Same Payment';
END IF;
ELSEIF type = 1 THEN
IF subtype = 0 THEN RETURN 'Arbritrary Message';
ELSEIF subtype = 1 THEN RETURN 'Alias Assignment';
ELSEIF subtype = 5 THEN RETURN 'Account Info';
ELSEIF subtype = 6 THEN RETURN 'Alias Sell';
ELSEIF subtype = 7 THEN RETURN 'Alias Buy';
END IF;
ELSEIF type = 2 THEN
IF subtype = 0 THEN RETURN 'Asset Issued';
ELSEIF subtype = 1 THEN RETURN 'Asset Transfer';
ELSEIF subtype = 2 THEN RETURN 'Ask Order Placement';
ELSEIF subtype = 3 THEN RETURN 'Bid Order Placement';
ELSEIF subtype = 4 THEN RETURN 'Ask Order Cancellation';
ELSEIF subtype = 5 THEN RETURN 'Bid Order Cancellation';
END IF;
ELSEIF type = 3 THEN
IF subtype = 0 THEN RETURN 'Marketplace Listing';
ELSEIF subtype = 1 THEN RETURN 'Marketplace Delisting';
ELSEIF subtype = 2 THEN RETURN 'Marketplace Price Change';
ELSEIF subtype = 3 THEN RETURN 'Marketplace Quantity Change';
ELSEIF subtype = 4 THEN RETURN 'Marketplace Purchase';
ELSEIF subtype = 5 THEN RETURN 'Marketplace Delivery';
ELSEIF subtype = 6 THEN RETURN 'Marketplace Feedback';
ELSEIF subtype = 7 THEN RETURN 'Marketplace Refund';
END IF;
ELSEIF type = 4 THEN
IF subtype = 0 THEN RETURN 'Effective Balance Leasing';
END IF;
ELSEIF type = 10 THEN
IF subtype = 0 THEN RETURN 'Create Pledge';
ELSEIF subtype = 1 THEN RETURN 'Cancel Pledge';
END IF;
ELSEIF type = 20 THEN
IF subtype = 0 THEN RETURN 'Reward Recipient';
END IF;
ELSEIF type = 21 THEN
IF subtype = 0 THEN RETURN 'Escrow Creation';
ELSEIF subtype = 1 THEN RETURN 'Escrow Signing';
ELSEIF subtype = 2 THEN RETURN 'Escrow Result';
ELSEIF subtype = 3 THEN RETURN 'Subscription Subscribe';
ELSEIF subtype = 4 THEN RETURN 'Subscription Cancel';
ELSEIF subtype = 5 THEN RETURN 'Subscription Payment';
END IF;
ELSEIF type = 22 THEN
IF subtype = 0 THEN RETURN 'AT Creation';
ELSEIF subtype = 1 THEN RETURN 'AT Payment';
END IF;
ELSE
RETURN 'unkown transaction type';
END IF;
END $$
DELIMITER ;
/*
Procedures
*/
DROP PROCEDURE IF EXISTS fill_recipient_id_block_info;
DELIMITER $$
CREATE PROCEDURE fill_recipient_id_block_info(in_height bigint(20))
BEGIN
UPDATE block_info bi
SET bi.recipient_id = (
SELECT CASE WHEN t.recipient_id IS NOT NULL THEN t.recipient_id ELSE b.generator_id END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = in_height
ORDER BY t.height DESC
LIMIT 1)
WHERE bi.height = in_height;
END$$
DELIMITER ;
DROP PROCEDURE IF EXISTS cache_all;
DELIMITER $$
CREATE PROCEDURE cache_all()
BEGIN
DROP TABLE IF EXISTS `ec_account`;
CREATE TABLE `ec_account` ( `id` BIGINT(20) NOT NULL , `name` VARCHAR(100) NOT NULL, INDEX `idx` (`id`)) ENGINE = MEMORY;
INSERT INTO ec_account (id, name) SELECT id,name FROM `account` WHERE latest = 1 AND name IS NOT NULL;
END$$
DELIMITER ;
/*
Trigger
*/
DROP TRIGGER IF EXISTS add_block_info;
DELIMITER $$
CREATE TRIGGER `add_block_info` AFTER INSERT ON `block`
FOR EACH ROW BEGIN
IF (SELECT bi.height FROM block_info bi WHERE bi.height = NEW.height) IS NOT NULL
THEN
DELETE FROM block_info WHERE height = NEW.height;
END IF;
INSERT INTO block_info (height, generator_id, recipient_id)
SELECT b.height as height, b.generator_id AS generator_id,
CASE
WHEN t.recipient_id IS NOT NULL THEN CAST(t.recipient_id AS UNSIGNED)
ELSE CAST(b.generator_id AS UNSIGNED)
END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = NEW.height
ORDER BY t.height DESC
LIMIT 1;
END$$
DELIMITER ;
DROP TRIGGER IF EXISTS update_tx_count;
DELIMITER $$
CREATE TRIGGER `update_tx_count` AFTER INSERT ON `transaction`
FOR EACH ROW BEGIN
UPDATE block_info bi SET tx_count = tx_count + 1 WHERE bi.height = NEW.height;
END$$
DELIMITER ;
/*
Tables
*/
-- DROP TABLE IF EXISTS block_info;
CREATE TABLE `block_info` (
`height` bigint(20) NOT NULL,
`generator_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`tx_count` int(10) NOT NULL DEFAULT '0',
INDEX `idx` (`height`,`generator_id`,`recipient_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mo;
CREATE TABLE `mo` (
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`amount` bigint(20) NOT NULL,
INDEX `idx` (`recipient_id`, `db_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mos;
CREATE TABLE `mos` (
`db_id` bigint(20) NOT NULL,
`recipient_count` int(4) NOT NULL,
INDEX `idx` (`db_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mosr;
CREATE TABLE `mosr` (
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
INDEX `idx` (`db_id`,`recipient_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mo;
CREATE TABLE `ec_account` (
`id` BIGINT(20) NOT NULL ,
`name` VARCHAR(100) NOT NULL,
INDEX `idx` (`id`)
) ENGINE = MEMORY;
/*
Fill Tables with stuff
*/
INSERT INTO block_info (tx_count, height, generator_id)
SELECT count(t.db_id) as tx_count, t.height, (SELECT b.generator_id FROM block b WHERE b.height = t.height) as generator_id
FROM `transaction` t
WHERE t.height NOT IN (SELECT bi.height FROM block_info bi)
GROUP BY t.height;
INSERT INTO block_info (tx_count, height, generator_id)
SELECT 0 as tx_count, b.height, b.generator_id
FROM `block` b
WHERE b.height NOT IN (SELECT bi.height FROM block_info bi);
-- run "php bin/console explorer:import:blockinfo" afterwards
CREATE TABLE `block_info` (
`height` bigint(20) NOT NULL,
`generator_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`tx_count` int(10) NOT NULL DEFAULT '0'
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
ALTER TABLE `block_info`
ADD KEY `idx` (`height`,`generator_id`,`recipient_id`);
/*
Functions
*/
DELIMITER $$
CREATE TRIGGER `add_block_info` AFTER INSERT ON `block`
FOR EACH ROW BEGIN
IF (SELECT bi.height FROM block_info bi WHERE bi.height = NEW.height) IS NOT NULL
THEN
DELETE FROM block_info WHERE height = NEW.height;
END IF;
INSERT INTO block_info (height, generator_id, recipient_id)
SELECT b.height as height, b.generator_id AS generator_id,
CASE
WHEN t.recipient_id IS NOT NULL THEN CAST(t.recipient_id AS UNSIGNED)
ELSE CAST(b.generator_id AS UNSIGNED)
END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = NEW.height
ORDER BY t.height DESC
LIMIT 1;
END$$
DELIMITER ;
DELIMITER $$
CREATE TRIGGER `update_tx_count` AFTER INSERT ON `transaction`
FOR EACH ROW BEGIN
UPDATE block_info bi SET tx_count = tx_count + 1 WHERE bi.height = NEW.height;
END$$
DELIMITER ;
-- Fill in
INSERT INTO block_info (tx_count, height, generator_id)
SELECT count(t.db_id) as tx_count, t.height, (SELECT b.generator_id FROM block b WHERE b.height = t.height) as generator_id
FROM `transaction` t
WHERE t.height NOT IN (SELECT bi.height FROM block_info bi)
GROUP BY t.height;
INSERT INTO block_info (tx_count, height, generator_id)
SELECT 0 as tx_count, b.height, b.generator_id
FROM `block` b
WHERE b.height NOT IN (SELECT bi.height FROM block_info bi);
DELIMITER $$
CREATE PROCEDURE fill_recipient_id_block_info(in_height bigint(20))
BEGIN
UPDATE block_info bi
SET bi.recipient_id = (
SELECT CASE WHEN t.recipient_id IS NOT NULL THEN t.recipient_id ELSE b.generator_id END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = in_height
ORDER BY t.height DESC
LIMIT 1)
WHERE bi.height = in_height;
END$$
DELIMITER ;
-- run "php bin/console explorer:import:blockinfo" afterwards
-- Burstcoin
DROP FUNCTION IF EXISTS getRewardByHeight;
DELIMITER $$
CREATE FUNCTION getRewardByHeight(in_height bigint(20))
RETURNS INT(5) DETERMINISTIC
RETURNS INT(5) DETERMINISTIC
BEGIN
RETURN FLOOR(POW(0.95,FLOOR(in_height/10800))*10000);
RETURN FLOOR(POW(0.95,FLOOR(in_height/10800))*10000);
END$$
-- Booncoin
DELIMITER $$
CREATE FUNCTION getRewardByHeight(in_height bigint(20))
RETURNS BIGINT(20) DETERMINISTIC
BEGIN
DECLARE counter, ratio, reward BIGINT(20);
SET counter = (525000 - 55500);
SET reward = 20000000000;
SELECT b.ratio INTO ratio FROM block b WHERE b.height = in_height;
IF in_height = 0 OR in_height > 20180768 THEN SET reward = 0;
ELSEIF in_height >= 18622075 THEN SET reward = 1;
ELSE
WHILE in_height > counter DO
SET counter = counter + 525000;
SET reward = reward / 2;
END WHILE;
END IF;
RETURN reward * ratio / 100;
END$$
DELIMITER ;
DELIMITER $$
CREATE PROCEDURE cache_all()
BEGIN
DROP TABLE IF EXISTS `ec_account`;
CREATE TABLE `ec_account` ( `id` BIGINT(20) NOT NULL , `name` VARCHAR(100) NOT NULL, INDEX `idx` (`id`)) ENGINE = MEMORY;
INSERT INTO ec_account (id, name) SELECT id,name FROM `account` WHERE latest = 1 AND name IS NOT NULL;
END$$
DELIMITER ;
DROP FUNCTION IF EXISTS getTransactionType;
DELIMITER $$
CREATE FUNCTION getTransactionType(type tinyint(4), subtype tinyint(4))
RETURNS char(100) DETERMINISTIC
RETURNS char(100) DETERMINISTIC
BEGIN
-- Transaction Types: https://github.com/burst-apps-team/burstcoin/blob/develop/src/brs/TransactionType.java#L34
IF type = 0 THEN
......@@ -166,30 +70,132 @@ BEGIN
END $$
DELIMITER ;
/*
Procedures
*/
DROP PROCEDURE IF EXISTS fill_recipient_id_block_info;
DELIMITER $$
CREATE PROCEDURE fill_recipient_id_block_info(in_height bigint(20))
BEGIN
UPDATE block_info bi
SET bi.recipient_id = (
SELECT CASE WHEN t.recipient_id IS NOT NULL THEN t.recipient_id ELSE b.generator_id END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = in_height
ORDER BY t.height DESC
LIMIT 1)
WHERE bi.height = in_height;
END$$
DELIMITER ;
DROP PROCEDURE IF EXISTS cache_all;
DELIMITER $$
CREATE PROCEDURE cache_all()
BEGIN
DROP TABLE IF EXISTS `ec_account`;
CREATE TABLE `ec_account` ( `id` BIGINT(20) NOT NULL , `name` VARCHAR(100) NOT NULL, INDEX `idx` (`id`)) ENGINE = MEMORY;
INSERT INTO ec_account (id, name) SELECT id,name FROM `account` WHERE latest = 1 AND name IS NOT NULL;
END$$
DELIMITER ;
/*
Trigger
*/
DROP TRIGGER IF EXISTS add_block_info;
DELIMITER $$
CREATE TRIGGER `add_block_info` AFTER INSERT ON `block`
FOR EACH ROW BEGIN
IF (SELECT bi.height FROM block_info bi WHERE bi.height = NEW.height) IS NOT NULL
THEN
DELETE FROM block_info WHERE height = NEW.height;
END IF;
INSERT INTO block_info (height, generator_id, recipient_id)
SELECT b.height as height, b.generator_id AS generator_id,
CASE
WHEN t.recipient_id IS NOT NULL THEN CAST(t.recipient_id AS UNSIGNED)
ELSE CAST(b.generator_id AS UNSIGNED)
END AS recipient_id
FROM block b
LEFT JOIN transaction t ON (t.type = 20 AND t.height <= b.height -3 AND t.sender_id = b.generator_id )
WHERE b.height = NEW.height
ORDER BY t.height DESC
LIMIT 1;
END$$
DELIMITER ;
DROP TRIGGER IF EXISTS update_tx_count;
DELIMITER $$
CREATE TRIGGER `update_tx_count` AFTER INSERT ON `transaction`
FOR EACH ROW BEGIN
UPDATE block_info bi SET tx_count = tx_count + 1 WHERE bi.height = NEW.height;
END$$
DELIMITER ;
/*
Tables
*/
-- DROP TABLE IF EXISTS block_info;
CREATE TABLE `block_info` (
`height` bigint(20) NOT NULL,
`generator_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`tx_count` int(10) NOT NULL DEFAULT '0',
INDEX `idx` (`height`,`generator_id`,`recipient_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mo;
CREATE TABLE `mo` (
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`amount` bigint(20) NOT NULL
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
`amount` bigint(20) NOT NULL,
INDEX `idx` (`recipient_id`, `db_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mos;
CREATE TABLE `mos` (
`db_id` bigint(20) NOT NULL,
`recipient_count` int(4) NOT NULL
`db_id` bigint(20) NOT NULL,
`recipient_count` int(4) NOT NULL,
INDEX `idx` (`db_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
-- DROP TABLE IF EXISTS mosr;
CREATE TABLE `mosr` (
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL
`db_id` bigint(20) NOT NULL,
`recipient_id` bigint(20) NOT NULL,
INDEX `idx` (`db_id`,`recipient_id`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
CREATE TABLE `ec_account` ( `id` BIGINT(20) NOT NULL , `name` VARCHAR(100) NOT NULL, INDEX `idx` (`id`)) ENGINE = MEMORY;
-- DROP TABLE IF EXISTS mo;
CREATE TABLE `ec_account` (
`id` BIGINT(20) NOT NULL ,
`name` VARCHAR(100) NOT NULL,
INDEX `idx` (`id`)
) ENGINE = MEMORY;
ALTER TABLE `mo`
ADD KEY `idx` (`recipient_id`,`db_id`);
/*
Fill Tables with stuff
*/
INSERT INTO block_info (tx_count, height, generator_id)
SELECT count(t.db_id) as tx_count, t.height, (SELECT b.generator_id FROM block b WHERE b.height = t.height) as generator_id
FROM `transaction` t
WHERE t.height NOT IN (SELECT bi.height FROM block_info bi)
GROUP BY t.height;
INSERT INTO block_info (tx_count, height, generator_id)
SELECT 0 as tx_count, b.height, b.generator_id
FROM `block` b
WHERE b.height NOT IN (SELECT bi.height FROM block_info bi);
ALTER TABLE `mos`
ADD KEY `idx` (`db_id`);
ALTER TABLE `mosr`
ADD KEY `idx` (`db_id`,`recipient_id`);
-- run "php bin/console explorer:import:blockinfo" afterwards
-- New
-- Test: SELECT getBLC(100), getBLC(450), getBLC(451), getBLC(99999), getBLC(100000), getBLC(100001), getBLC(200000), getBLC(200001), getBLC(300000), getBLC(300001), getBLC(13900000)
DELIMITER $$
CREATE FUNCTION getBLC(in_height BIGINT(20))
RETURNS INT(5) DETERMINISTIC
BEGIN
DECLARE decay DOUBLE;
DECLARE blockEra, initialReward INT;
SET decay = 0.95273;
SET blockEra = 100000;
SET initialReward = 10000;
IF in_height < 451 THEN RETURN 0;
ELSE RETURN FLOOR(POW(decay, (FLOOR(in_height) / blockEra)) * initialReward);
END IF;
END$$
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment