more sql refactoring

This commit is contained in:
Christian Grothoff 2022-11-27 18:40:44 +01:00
parent bbf3e6fe03
commit f2ba02aab2
No known key found for this signature in database
GPG Key ID: 939E6BE1E29FC3CC
12 changed files with 185 additions and 257 deletions

View File

@ -21,17 +21,3 @@ CREATE TABLE IF NOT EXISTS denomination_revocations
);
COMMENT ON TABLE denomination_revocations
IS 'remembering which denomination keys have been revoked';
INSERT INTO exchange_tables
(name
,version
,action
,partitioned
,by_range)
VALUES
('denomination_revocations'
,'exchange-0002'
,'create'
,FALSE
,FALSE);

View File

@ -14,13 +14,7 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
CREATE OR REPLACE FUNCTION create_table_denominations()
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
CREATE TABLE IF NOT EXISTS denominations
CREATE TABLE denominations
(denominations_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
,denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64)
,denom_type INT4 NOT NULL DEFAULT (1) -- 1 == RSA (for now, remove default later!)
@ -51,22 +45,6 @@ COMMENT ON COLUMN denominations.age_mask
COMMENT ON COLUMN denominations.denominations_serial
IS 'needed for exchange-auditor replication logic';
CREATE INDEX IF NOT EXISTS denominations_by_expire_legal_index
CREATE INDEX denominations_by_expire_legal_index
ON denominations
(expire_legal);
END
$$;
INSERT INTO exchange_tables
(name
,version
,action
,partitioned
,by_range)
VALUES
('denominations'
,'exchange-0002'
,'create'
,FALSE
,FALSE);

View File

@ -49,7 +49,7 @@ BEGIN
,partition_suffix
);
PERFORM comment_partitioned_table(
'Deposits we have received and for which we need to make (aggregate) wire transfers (and manage refunds).';
'Deposits we have received and for which we need to make (aggregate) wire transfers (and manage refunds).'
,table_name
,partition_suffix
);

View File

@ -15,7 +15,7 @@
--
CREATE OR create_table_history_requests(
CREATE FUNCTION create_table_history_requests(
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
@ -64,7 +64,7 @@ BEGIN
END $$;
CREATE OR foreign_table_history_requests()
CREATE FUNCTION foreign_table_history_requests()
RETURNS VOID
LANGUAGE plpgsql
AS $$

View File

@ -39,48 +39,48 @@ BEGIN
,'PARTITION BY HASH (melt_serial_id)'
,shard_suffix
);
PEFORM comment_partitioned_table(
PERFORM comment_partitioned_table(
'Revelations about the new coins that are to be created during a melting session.'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'needed for exchange-auditor replication logic'
,'rrc_serial'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'Identifies the refresh commitment (rc) of the melt operation.'
,'melt_serial_id'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'index of the fresh coin being created (one melt operation may result in multiple fresh coins)'
,'freshcoin_index'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'envelope of the new coin to be signed'
,'coin_ev'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'exchange contributed values in the creation of the fresh coin (see /csr)'
,'ewv'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'hash of the envelope of the new coin to be signed (for lookups)'
,'h_coin_ev'
,table_name
,shard_suffix
);
PEFORM comment_partitioned_column(
PERFORM comment_partitioned_column(
'exchange signature over the envelope'
,'ev_sig'
,table_name

View File

@ -15,7 +15,7 @@
--
CREATE FUNCTION create_table_wads_in(
IN shard_suffix VARCHAR DEFAULT NULL
IN partition_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
@ -35,36 +35,36 @@ BEGIN
') %s ;'
,table_name
,'PARTITION BY HASH (wad_id)'
,shard_suffix
,partition_suffix
);
PERFORM comment_partitioned_table(
'Incoming exchange-to-exchange wad wire transfers'
,table_name
,shard_suffix
,partition_suffix
);
PERFORM comment_partitioned_column(
'Unique identifier of the wad, part of the wire transfer subject'
,'wad_id'
,table_name
,shard_suffix
,partition_suffix
);
PERFORM comment_partitioned_column(
'Base URL of the originating URL, also part of the wire transfer subject'
,'origin_exchange_url'
,table_name
,shard_suffix
,partition_suffix
);
PERFORM comment_partitioned_column(
'Actual amount that was received by our exchange'
,'amount_val'
,table_name
,shard_suffix
,partition_suffix
);
PERFORM comment_partitioned_column(
'Time when the wad was received'
,'arrival_time'
,table_name
,shard_suffix
,partition_suffix
);
END $$;

View File

@ -14,7 +14,7 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
CREATE OR REPLACE FUNCTION create_table_wire_targets(
CREATE FUNCTION create_table_wire_targets(
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
@ -22,7 +22,7 @@ LANGUAGE plpgsql
AS $$
BEGIN
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'CREATE TABLE %I'
'(wire_target_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
',wire_target_h_payto BYTEA PRIMARY KEY CHECK (LENGTH(wire_target_h_payto)=32)'
',payto_uri VARCHAR NOT NULL'
@ -47,12 +47,10 @@ BEGIN
,'wire_target_h_payto'
,shard_suffix
);
END
$$;
END $$;
CREATE OR REPLACE FUNCTION constrain_table_wire_targets(
CREATE FUNCTION constrain_table_wire_targets(
IN partition_suffix VARCHAR
)
RETURNS void

View File

@ -19,6 +19,7 @@ BEGIN;
SELECT _v.unregister_patch('exchange-0001');
SELECT _v.unregister_patch('exchange-0002');
DROP SCHEMA exchange CASCADE;

View File

@ -14,9 +14,13 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
-- Everything in one big transaction
BEGIN;
SELECT _v.register_patch('exchange-0001', NULL, NULL);
CREATE SCHEMA exchange;
COMMENT ON SCHEMA exchange IS 'taler-exchange data';
SET search_path TO exchange;
---------------------------------------------------------------------------
@ -38,7 +42,7 @@ COMMENT ON COLUMN exchange_tables.name
COMMENT ON COLUMN exchange_tables.version
IS 'Version of the DB in which the given action happened';
COMMENT ON COLUMN exchange_tables.action
IS 'Action to take on the table (e.g. create, alter, constrain, foreign, or drop). Create, alter and drop are done for master and each partition; constrain is only for partitions or for master if there are no partitions; master only on master (takes no argument); foreign only on master if there are no partitions.';
IS 'Action to take on the table (e.g. create, constrain, foreign, or drop). Create is done for the master table and each partition; constrain is only for partitions or for master if there are no partitions; master only on master (takes no argument); foreign only on master if there are no partitions.';
COMMENT ON COLUMN exchange_tables.partitioned
IS 'TRUE if the table is partitioned';
COMMENT ON COLUMN exchange_tables.by_range
@ -48,51 +52,58 @@ COMMENT ON COLUMN exchange_tables.finished
CREATE FUNCTION create_partitioned_table(
IN table_definition VARCHAR
,IN table_name VARCHAR
,IN main_table_partition_str VARCHAR -- Used only when it is the main table - we do not partition shard tables
,IN shard_suffix VARCHAR DEFAULT NULL
IN table_definition VARCHAR -- SQL template for table creation
,IN table_name VARCHAR -- base name of the table
,IN main_table_partition_str VARCHAR -- declaration for how to partition the table
,IN partition_suffix VARCHAR DEFAULT NULL -- NULL: no partitioning, 0: yes partitioning, no sharding, >0: sharding
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
IF shard_suffix IS NOT NULL THEN
table_name=table_name || '_' || shard_suffix;
IF partition_suffix IS NULL
THEN
-- no partitioning, disable option
main_table_partition_str = '';
ELSE
IF partition_suffix > 0
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
END IF;
END IF;
EXECUTE FORMAT(
table_definition,
table_name,
main_table_partition_str
);
END
$$;
END $$;
COMMENT ON FUNCTION create_partitioned_table
IS 'Generic function to create a table that is partitioned.';
IS 'Generic function to create a table that is partitioned or sharded.';
CREATE FUNCTION comment_partitioned_table(
IN table_comment VARCHAR
,IN table_name VARCHAR
,IN shard_suffix VARCHAR DEFAULT NULL
,IN partition_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
IF shard_suffix IS NOT NULL THEN
table_name=table_name || '_' || shard_suffix;
main_table_partition_str = '';
IF ( (partition_suffix IS NOT NULL) AND
(partition_suffix > 0) )
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
END IF;
EXECUTE FORMAT(
COMMENT ON TABLE %s IS '%s'
'COMMENT ON TABLE %s IS %s'
,table_name
,table_comment
,quote_literal(table_comment)
);
END
$$;
END $$;
COMMENT ON FUNCTION comment_partitioned_table
IS 'Generic function to create a comment on table that is partitioned.';
@ -102,34 +113,37 @@ CREATE FUNCTION comment_partitioned_column(
IN table_comment VARCHAR
,IN column_name VARCHAR
,IN table_name VARCHAR
,IN shard_suffix VARCHAR DEFAULT NULL
,IN partition_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
IF shard_suffix IS NOT NULL THEN
table_name=table_name || '_' || shard_suffix;
main_table_partition_str = '';
IF ( (partition_suffix IS NOT NULL) AND
(partition_suffix > 0) )
THEN
-- sharding, add shard name
table_name=table_name || '_' || partition_suffix;
END IF;
EXECUTE FORMAT(
COMMENT ON COLUMN %s.%s IS '%s'
'COMMENT ON COLUMN %s.%s IS %s'
,table_name
,column_name
,table_comment
,quote_literal(table_comment)
);
END
$$;
END $$;
COMMENT ON FUNCTION comment_partitioned_column
IS 'Generic function to create a comment on column of a table that is partitioned.';
---------------------------------------------------------------------------
-- Main DB setup loop
---------------------------------------------------------------------------
CREATE FUNCTION create_tables(
num_partitions INTEGER
-- FIXME: not implemented like this, but likely good:
-- NULL: no partitions, add foreign constraints
-- 0: no partitions, no foreign constraints
-- 1: only 1 default partition
@ -139,100 +153,57 @@ CREATE FUNCTION create_tables(
LANGUAGE plpgsql
AS $$
DECLARE
-- FIXME: use only ONE cursor and then switch on action!
tc CURSOR FOR
SELECT table_serial_id
,name
,action
,partitioned
,by_range
FROM exchange_tables
WHERE NOT finished
AND partitioned
AND (action='create'
OR action='alter'
OR action='drop')
ORDER BY table_serial_id ASC;
DECLARE
ta CURSOR FOR
SELECT table_serial_id
,name
,action
,by_range
FROM exchange_tables
WHERE NOT finished
AND partitioned
AND action='constrain'
ORDER BY table_serial_id ASC;
DECLARE
tf CURSOR FOR
SELECT table_serial_id
,name
,action
,by_range
FROM exchange_tables
WHERE NOT finished
AND partitioned
AND action='foreign'
ORDER BY table_serial_id ASC;
DECLARE
tm CURSOR FOR
SELECT table_serial_id
,name
,action
,by_range
FROM exchange_tables
WHERE NOT finished
AND partitioned
AND action='master'
ORDER BY table_serial_id ASC;
BEGIN
-- run create/alter/drop actions
FOR rec IN tc
LOOP
-- First create the master table, either
-- completely unpartitioned, or with one
-- master and the 'default' partition
IF IS NULL num_partitions
CASE rec.action
-- "create" actions apply to master and partitions
WHEN "create"
THEN
-- No partitions at all.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
ELSE
-- One default partition only.
IF (rec.partitioned AND
(num_partitions IS NOT NULL))
THEN
-- Create master table with partitioning.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,0
);
IF NOT IS NULL num_partitions
IF (rec.by_range OR
(num_partitions = 0))
THEN
IF rec.by_range
THEN
-- range partitions (only create default)
-- Create default partition.
IF (rec.by_range)
THEN
-- Range partition
EXECUTE FORMAT(
'CREATE TABLE %s_default PARTITION OF %s DEFAULT'
'CREATE TABLE IF NOT EXISTS %s_default'
' PARTITION OF %s'
' FOR DEFAULT'
,rec.name
,rec.name
);
ELSE
-- hash partitions
IF 0=num_partitions
THEN
-- Create default partition.
-- Hash partition
EXECUTE FORMAT(
'CREATE TABLE IF NOT EXISTS %s_default PARTITION OF %s FOR VALUES WITH (MODULUS 1, REMAINDER 0)'
'CREATE TABLE IF NOT EXISTS %s_default'
' PARTITION OF %s'
' FOR VALUES WITH (MODULUS 1, REMAINDER 0)'
,rec.name
,rec.name
);
END IF
END IF;
ELSE
FOR i IN 1..num_partitions LOOP
-- Create num_partitions
EXECUTE FORMAT(
@ -246,69 +217,82 @@ BEGIN
);
END LOOP;
END IF;
END IF;
UPDATE exchange_tables
SET finished=TRUE
WHERE table_serial_id=rec.table_serial_id;
END LOOP; -- create/alter/drop actions
-- Run constrain actions
FOR rec IN ta
LOOP
IF IS NULL num_partitions
THEN
-- Constrain master
ELSE
-- Only create master table. No partitions.
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
END IF
IF 0=num_partitions
END IF;
-- Constrain action apply to master OR each partition
WHEN "constrain"
THEN
-- constrain default partition
ASSERT rec.partitioned, 'constrain action only applies to partitioned tables';
IF (num_partitions IS NULL)
THEN
-- Constrain master table
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,0
,NULL
);
END IF
ELSE
IF (num_partitions = 0)
THEN
-- Constrain default table
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,'default'
);
ELSE
-- Constrain each partition
FOR i IN 1..num_partitions LOOP
-- constrain each partition
EXECUTE FORMAT(
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,i::varchar
,i
);
END LOOP;
UPDATE exchange_tables
SET finished=TRUE
WHERE table_serial_id=rec.table_serial_id;
END LOOP;
-- run foreign actions
FOR rec IN tf
LOOP
IF IS NULL num_partitions
END IF;
END IF;
-- Foreign actions only apply if partitioning is off
WHEN "foreign"
THEN
-- Add foreign constraints
IF (num_partitions IS NULL)
THEN
-- Only create master table. No partitions.
EXECUTE FORMAT(
'PERFORM %s_table_%s ()'::text
'PERFORM %s_table_%s (%s)'::text
,rec.action
,rec.name
,NULL
);
END IF;
WHEN "master"
THEN
EXECUTE FORMAT(
'PERFORM %s_table_%s'::text
,rec.action
,rec.name
);
END IF
ELSE
ASSERT FALSE, 'unsupported action type: ' || rec.action;
END CASE; -- END CASE (rec.action)
-- Mark as finished
UPDATE exchange_tables
SET finished=TRUE
WHERE table_serial_id=rec.table_serial_id;
END LOOP;
END
$$;
END LOOP; -- create/alter/drop actions
END $$;
COMMENT ON FUNCTION create_tables
IS 'Creates all tables for the given number of partitions that need creating.';
IS 'Creates all tables for the given number of partitions that need creating. Does NOT support sharding.';
COMMIT;

View File

@ -14,14 +14,9 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
-- Everything in one big transaction
BEGIN;
-- Check patch versioning is in place.
SELECT _v.register_patch('exchange-0002', NULL, NULL);
-------------------- Schema ----------------------------
SET search_path TO exchange;
#include "0002-denominations.sql"

View File

@ -14,20 +14,11 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
-- Everything in one big transaction
BEGIN;
-- Check patch versioning is in place.
SELECT _v.register_patch('exchange-0003', NULL, NULL);
-------------------- Schema ----------------------------
CREATE SCHEMA exchange;
COMMENT ON SCHEMA exchange IS 'taler-exchange data';
SET search_path TO exchange;
#include "0003-purse_actions.sql"
#include "0003-purse_deletion.sql"

View File

@ -14,15 +14,10 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
--
-- Everything in one big transaction
BEGIN;
SET search_path TO exchange;
---------------------------------------------------------------------------
-- Stored procedures
---------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION exchange_do_withdraw(
IN cs_nonce BYTEA,