Exercise 2.1 Joint and serial control insertions
This commit is contained in:
parent
d509f430bf
commit
0f0cde2772
69
project1/c.sql
Normal file
69
project1/c.sql
Normal file
@ -0,0 +1,69 @@
|
|||||||
|
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);
|
||||||
|
-------------------------------------
|
||||||
|
-- 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;
|
||||||
Loading…
x
Reference in New Issue
Block a user