224 lines
6.2 KiB
SQL
224 lines
6.2 KiB
SQL
DROP TABLE IF EXISTS temporary_table;
|
|
CREATE TEMPORARY TABLE temporary_table (block_id int);
|
|
|
|
-- Contains all blocks and their coinbase transactions
|
|
CREATE OR REPLACE VIEW coinbase_transactions
|
|
AS SELECT block_id, tx_id
|
|
FROM (
|
|
SELECT tx_id
|
|
FROM inputs
|
|
GROUP BY tx_id
|
|
HAVING COUNT(input_id) = 1
|
|
AND SUM(sig_id) = 0
|
|
) AS one_input_transactions
|
|
NATURAL JOIN transactions
|
|
INTERSECT
|
|
SELECT block_id, MIN(tx_id) AS tx_id
|
|
FROM transactions
|
|
GROUP BY block_id;
|
|
|
|
-- Contains all blocks and their non-coinbase transactions
|
|
CREATE OR REPLACE VIEW non_coinbase_transactions
|
|
AS SELECT block_id, tx_id
|
|
FROM transactions
|
|
EXCEPT
|
|
SELECT block_id, tx_id
|
|
FROM coinbase_transactions;
|
|
|
|
-------- Block validation #6 --------
|
|
|
|
INSERT INTO temporary_table
|
|
SELECT block_id FROM (
|
|
-- All first transactions of each block
|
|
SELECT MIN(tx_id) AS tx_id, block_id
|
|
FROM transactions
|
|
GROUP BY block_id
|
|
) AS first_transactions
|
|
WHERE tx_id NOT IN (
|
|
SELECT tx_id
|
|
FROM coinbase_transactions
|
|
);
|
|
|
|
-------- Block validation #7.2 --------
|
|
|
|
-- Get all blocks which have transactions with no inputs
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM transactions
|
|
NATURAL JOIN inputs
|
|
GROUP BY tx_id
|
|
HAVING COUNT(input_id) = 0;
|
|
|
|
-- Get all blocks which have transactions with no outputs
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM transactions
|
|
NATURAL JOIN outputs
|
|
GROUP BY tx_id
|
|
HAVING COUNT(output_id) = 0;
|
|
|
|
-------- Block validation #7.4 --------
|
|
|
|
-- Get all blocks which have transactions with invalid output values
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM transactions
|
|
NATURAL JOIN outputs
|
|
WHERE value < 0 OR value > 2100000000000000;
|
|
|
|
-- Get all blocks which have transactions with invalid total output values
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM transactions
|
|
NATURAL JOIN outputs
|
|
GROUP BY tx_id
|
|
HAVING COUNT(output_id) = 0 OR SUM(value) < 0 OR SUM(value) > 2100000000000000;
|
|
|
|
-------- Block validation #16.1 --------
|
|
|
|
-- Contains all non-coinbase inputs
|
|
CREATE OR REPLACE VIEW non_coinbase_inputs AS (
|
|
SELECT *
|
|
FROM non_coinbase_transactions
|
|
NATURAL JOIN inputs
|
|
);
|
|
|
|
-- #16.1.1 Get all blocks which have transactions where inputs do not have
|
|
-- corresponding outputs
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM non_coinbase_inputs
|
|
LEFT OUTER JOIN outputs USING(output_id)
|
|
WHERE value IS NULL OR non_coinbase_inputs.tx_id <= outputs.tx_id;
|
|
|
|
-- #16.1.4 Get blocks where sig_id of inputs does not match pk_id of matching
|
|
-- outputs
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM non_coinbase_inputs
|
|
JOIN outputs USING(output_id)
|
|
WHERE sig_id <> pk_id;
|
|
|
|
-- #16.1.5 Get blocks with inputs that have outputs which have already been
|
|
-- spent (double-spending)
|
|
|
|
-- First, get outputs that have been doubly spent
|
|
CREATE OR REPLACE VIEW outputs_doubly_spent AS (
|
|
SELECT output_id
|
|
FROM non_coinbase_inputs
|
|
JOIN outputs USING(output_id)
|
|
GROUP BY output_id
|
|
HAVING COUNT(input_id) > 1
|
|
);
|
|
-- Second, get corresponding input_id where the output was first spent
|
|
CREATE OR REPLACE VIEW inputs_first_spent AS (
|
|
SELECT MIN(input_id) AS input_id, output_id
|
|
FROM outputs_doubly_spent
|
|
JOIN non_coinbase_inputs USING(output_id)
|
|
GROUP BY output_id
|
|
);
|
|
-- Third, combine to get invalid blocks
|
|
INSERT INTO temporary_table
|
|
SELECT block_id
|
|
FROM outputs_doubly_spent
|
|
JOIN non_coinbase_inputs USING(output_id)
|
|
WHERE input_id NOT IN (
|
|
SELECT input_id
|
|
FROM inputs_first_spent
|
|
);
|
|
|
|
-- #16.1.6 Get all blocks where input value or sum is outside of legal money
|
|
-- range (value < 0 OR value > 2100000000000000)
|
|
CREATE OR REPLACE VIEW input_sums AS (
|
|
SELECT block_id, tx_id, input_sum
|
|
FROM transactions
|
|
JOIN (
|
|
SELECT non_coinbase_inputs.tx_id AS tx_id, SUM(value) AS input_sum
|
|
FROM non_coinbase_inputs JOIN outputs USING(output_id)
|
|
GROUP BY non_coinbase_inputs.tx_id
|
|
) AS inputs USING(tx_id)
|
|
);
|
|
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM non_coinbase_inputs
|
|
JOIN outputs USING(output_id)
|
|
WHERE value < 0 OR value > 2100000000000000;
|
|
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM input_sums
|
|
WHERE input_sum < 0 OR input_sum > 2100000000000000;
|
|
|
|
-- #16.1.7 Get all blocks where the sum of input values < sum of output values
|
|
CREATE OR REPLACE VIEW output_sums AS (
|
|
SELECT block_id, tx_id, output_sum
|
|
FROM transactions
|
|
JOIN (
|
|
SELECT tx_id, SUM(value) AS output_sum
|
|
FROM non_coinbase_transactions
|
|
JOIN outputs USING(tx_id)
|
|
GROUP BY tx_id
|
|
) AS outputs USING(tx_id)
|
|
);
|
|
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT input_sums.block_id
|
|
FROM input_sums
|
|
NATURAL JOIN output_sums
|
|
WHERE input_sums.input_sum < output_sums.output_sum;
|
|
|
|
-------- Block validation #16.2 --------
|
|
|
|
-- Get the coinbase value for each block
|
|
CREATE OR REPLACE VIEW coinbase_value_per_block AS (
|
|
SELECT block_id, SUM(value) AS coinbase_value
|
|
FROM coinbase_transactions
|
|
JOIN outputs USING(tx_id)
|
|
GROUP BY block_id
|
|
);
|
|
|
|
-- Get the sum of all inputs per block
|
|
CREATE OR REPLACE VIEW sum_inputs_per_block AS (
|
|
SELECT block_id, SUM(value) AS total_inputs
|
|
FROM transactions
|
|
NATURAL JOIN inputs
|
|
JOIN outputs USING(output_id)
|
|
WHERE inputs.tx_id NOT IN (
|
|
SELECT tx_id
|
|
FROM coinbase_transactions
|
|
)
|
|
GROUP BY block_id
|
|
);
|
|
|
|
-- Get the sum of all outputs per block
|
|
CREATE OR REPLACE VIEW sum_outputs_per_block AS (
|
|
SELECT block_id, SUM(value) AS total_outputs
|
|
FROM transactions
|
|
NATURAL JOIN outputs
|
|
WHERE tx_id NOT IN (
|
|
SELECT tx_id
|
|
FROM coinbase_transactions
|
|
)
|
|
GROUP BY block_id
|
|
);
|
|
|
|
-- Get all blocks where the coinbase value is bigger than the sum of block
|
|
-- creation fee and transaction fees
|
|
INSERT INTO temporary_table
|
|
SELECT DISTINCT block_id
|
|
FROM coinbase_value_per_block
|
|
JOIN sum_inputs_per_block USING(block_id)
|
|
JOIN sum_outputs_per_block USING(block_id)
|
|
WHERE coinbase_value_per_block.coinbase_value > (5000000000 + sum_inputs_per_block.total_inputs - sum_outputs_per_block.total_outputs);
|
|
|
|
-- Start with a clean final table
|
|
DROP TABLE IF EXISTS invalid_blocks;
|
|
CREATE TABLE invalid_blocks (block_id int);
|
|
|
|
-- Remove duplicates from temporary_table and insert remaining into final
|
|
-- invalid_blocks table
|
|
INSERT INTO invalid_blocks
|
|
SELECT DISTINCT block_id
|
|
FROM temporary_table;
|