CrypthonicsException d94fe16b96 Ex C error fixes
2021-11-28 14:43:29 +03:00

175 lines
4.8 KiB
SQL

DROP TABLE IF EXISTS addressRelations;
CREATE TABLE addressRelations (addr1 int, addr2 int);
CREATE TEMPORARY TABLE tempRelations (addr1 int, addr2 int);
-------------------------------------
-- Tx that has more than one input
CREATE OR REPLACE VIEW joint_control_transactions
AS SELECT tx_id
FROM inputs
GROUP BY tx_id
HAVING count(*)>1;
-------------------------------------
-- Tx that pass serial control check
CREATE OR REPLACE VIEW serial_control_transactions
AS SELECT tx_id
FROM inputs
JOIN outputs
USING (tx_id)
GROUP BY tx_id
HAVING count(*)=1;
-------------------------------------
--insert joint control results (contains symmetric and reflexive results)
INSERT INTO tempRelations
SELECT inputs.sig_id, joint_tx_with_addr.sig_id
FROM inputs
RIGHT OUTER JOIN (
SELECT tx_id, sig_id
FROM joint_control_transactions
JOIN inputs
USING (tx_id)
)
AS joint_tx_with_addr
USING (tx_id);
-------------------------------------
--insert serial control results
INSERT INTO tempRelations
SELECT sig_id, pk_id
FROM inputs
JOIN outputs
USING (tx_id)
WHERE tx_id IN (SELECT tx_id FROM serial_control_transactions) AND sig_id != 0;
-------------------------------------
-- clean up reflexivity
DELETE
FROM tempRelations
WHERE addr1 = addr2;
-------------------------------------
-- Temporary table for storing symmetrical rows
CREATE TEMPORARY TABLE temp_symmetry (addr1 int, addr2 int);
-- find symmetrical rows
INSERT INTO temp_symmetry
SELECT tmp1.addr1, tmp1.addr2
FROM tempRelations tmp1
INNER JOIN tempRelations tmp2
ON tmp1.addr1 = tmp2.addr2
AND tmp1.addr2 = tmp2.addr1
AND tmp1.addr1 > tmp1.addr2;
-- clean up symmetrical rows
DELETE
FROM tempRelations
WHERE EXISTS (SELECT * FROM temp_symmetry WHERE tempRelations.addr1 = temp_symmetry.addr1 AND tempRelations.addr2 = temp_symmetry.addr2);
INSERT INTO addressRelations
SELECT addr1, addr2
FROM tempRelations;
DROP TABLE IF EXISTS temp_symmetry;
DROP TABLE IF EXISTS tempRelations;
-- exercise c (2)
DROP TABLE IF EXISTS temp_clusters;
CREATE TEMPORARY TABLE temp_clusters (id int, address int);
INSERT INTO temp_clusters
SELECT id, address
FROM clusterAddresses();
DROP TABLE IF EXISTS max_value_by_entity;
DROP TABLE IF EXISTS min_addr_of_max_entity;
DROP TABLE IF EXISTS max_tx_to_max_entity;
CREATE TABLE max_value_by_entity (value bigint);
CREATE TABLE min_addr_of_max_entity(addr int);
CREATE TABLE max_tx_to_max_entity(tx_id int);
---- table for having utxos with tx_id, values, and addresses
DROP TABLE IF EXISTS utxos_with_values;
CREATE TEMPORARY TABLE utxos_with_values (output_id int, value bigint, address int, tx_id int);
INSERT INTO utxos_with_values
SELECT utxos.output_id, utxos.value, pk_id as address, tx_id
FROM utxos
INNER JOIN outputs
USING (output_id);
------------ Table for sum values of all addresses per id--------
DROP TABLE IF EXISTS temp_sum_values;
CREATE TEMPORARY TABLE temp_sum_values (id int, sum_values bigint);
INSERT INTO temp_sum_values
SELECT id, SUM(value) as sum_values
FROM temp_clusters
INNER JOIN utxos_with_values
USING (address)
GROUP BY id;
----- Exercise 3 A
INSERT INTO max_value_by_entity
SELECT MAX(sum_values)
FROM temp_sum_values;
------ Table for putting max entity with its id, address and utxo values of these addresses
DROP TABLE IF EXISTS temp_max_entity;
CREATE TEMPORARY TABLE temp_max_entity (id int, address int, utxo_value bigint);
INSERT INTO temp_max_entity
SELECT id, address, value
FROM utxos_with_values as u
INNER JOIN (
SELECT id, address
FROM temp_clusters as tc
INNER JOIN (
SELECT id
FROM temp_sum_values as t
INNER JOIN max_value_by_entity as m
ON t.sum_values = m.value
) as j
USING (id)
) as c
USING (address);
--- table for having max entity with all the corresponding addresses
DROP TABLE IF EXISTS max_entity_all_addresses;
CREATE TEMPORARY TABLE max_entity_all_addresses (id int, address int);
INSERT INTO max_entity_all_addresses
SELECT id, address
FROM temp_clusters
WHERE id
IN (
SELECT id
FROM temp_max_entity
);
--- Exercise 3 B
INSERT INTO min_addr_of_max_entity
SELECT MIN(address)
FROM max_entity_all_addresses;
--- Table for inserting the value of max tx to the entity
DROP TABLE IF EXISTS max_tx_value_to_max_entity;
CREATE TEMPORARY TABLE max_tx_value_to_max_entity (value bigint);
WITH max_entity_join_outputs as (SELECT *
FROM max_entity_all_addresses as m
INNER JOIN outputs
ON outputs.pk_id = m.address)
INSERT INTO max_tx_value_to_max_entity
SELECT MAX(value)
FROM max_entity_join_outputs;
--- Exercise 3 C
WITH max_entity_join_outputs as (SELECT *
FROM max_entity_all_addresses as m
INNER JOIN outputs
ON outputs.pk_id = m.address)
INSERT INTO max_tx_to_max_entity
SELECT tx_id
FROM max_entity_join_outputs as m
WHERE value IN (SELECT value FROM max_tx_value_to_max_entity);