more work on SQL refactoring
This commit is contained in:
parent
4f75bcdca3
commit
85ce53a49b
@ -14,7 +14,7 @@
|
||||
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION create_table_purse_merges(
|
||||
CREATE FUNCTION create_table_purse_merges(
|
||||
IN shard_suffix VARCHAR DEFAULT NULL
|
||||
)
|
||||
RETURNS VOID
|
||||
@ -23,27 +23,72 @@ AS $$
|
||||
DECLARE
|
||||
table_name VARCHAR DEFAULT 'purse_merges';
|
||||
BEGIN
|
||||
|
||||
PERFORM create_partitioned_table(
|
||||
'CREATE TABLE IF NOT EXISTS %I '
|
||||
'(purse_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY '-- UNIQUE
|
||||
',partner_serial_id INT8' -- REFERENCES partners(partner_serial_id) ON DELETE CASCADE
|
||||
',reserve_pub BYTEA NOT NULL CHECK(length(reserve_pub)=32)'--REFERENCES reserves (reserve_pub) ON DELETE CASCADE
|
||||
',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)' --REFERENCES purse_requests (purse_pub) ON DELETE CASCADE
|
||||
',merge_sig BYTEA NOT NULL CHECK (LENGTH(merge_sig)=64)'
|
||||
',merge_timestamp INT8 NOT NULL'
|
||||
',PRIMARY KEY (purse_pub)'
|
||||
'CREATE TABLE %I '
|
||||
'(purse_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
|
||||
',partner_serial_id INT8'
|
||||
',reserve_pub BYTEA NOT NULL CHECK(length(reserve_pub)=32)'
|
||||
',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
|
||||
',merge_sig BYTEA NOT NULL CHECK (LENGTH(merge_sig)=64)'
|
||||
',merge_timestamp INT8 NOT NULL'
|
||||
',PRIMARY KEY (purse_pub)'
|
||||
') %s ;'
|
||||
,table_name
|
||||
,'PARTITION BY HASH (purse_pub)'
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_table(
|
||||
'Merge requests where a purse-owner requested merging the purse into the account'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_column(
|
||||
'identifies the partner exchange, NULL in case the target reserve lives at this exchange'
|
||||
,'partner_serial_id'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_column(
|
||||
'public key of the target reserve'
|
||||
,'reserve_pub'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_column(
|
||||
'public key of the purse'
|
||||
,'purse_pub'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_column(
|
||||
'signature by the purse private key affirming the merge, of type TALER_SIGNATURE_WALLET_PURSE_MERGE'
|
||||
,'merge_sig'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
PERFORM comment_partitioned_column(
|
||||
'when was the merge message signed'
|
||||
,'merge_timestamp'
|
||||
,table_name
|
||||
,shard_suffix
|
||||
);
|
||||
END
|
||||
$$;
|
||||
|
||||
|
||||
CREATE FUNCTION constrain_table_purse_merges(
|
||||
IN partition_suffix VARCHAR
|
||||
)
|
||||
RETURNS VOID
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
table_name VARCHAR DEFAULT 'purse_merges';
|
||||
BEGIN
|
||||
table_name = concat_ws('_', table_name, shard_suffix);
|
||||
|
||||
-- FIXME: change to materialized index by reserve_pub!
|
||||
EXECUTE FORMAT (
|
||||
'CREATE INDEX IF NOT EXISTS ' || table_name || '_reserve_pub '
|
||||
'CREATE INDEX ' || table_name || '_reserve_pub '
|
||||
'ON ' || table_name || ' '
|
||||
'(reserve_pub);'
|
||||
);
|
||||
@ -51,21 +96,30 @@ BEGIN
|
||||
'COMMENT ON INDEX ' || table_name || '_reserve_pub '
|
||||
'IS ' || quote_literal('needed in reserve history computation') || ';'
|
||||
);
|
||||
|
||||
EXECUTE FORMAT (
|
||||
'ALTER TABLE ' || table_name ||
|
||||
' ADD CONSTRAINT ' || table_name || '_purse_merge_request_serial_id_key'
|
||||
' UNIQUE (purse_merge_request_serial_id) '
|
||||
);
|
||||
END
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION add_constraints_to_purse_merges_partition(
|
||||
IN partition_suffix VARCHAR
|
||||
)
|
||||
|
||||
CREATE FUNCTION foreign_table_purse_merges()
|
||||
RETURNS VOID
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
table_name VARCHAR DEFAULT 'purse_merges';
|
||||
BEGIN
|
||||
EXECUTE FORMAT (
|
||||
'ALTER TABLE purse_merges_' || partition_suffix || ' '
|
||||
'ADD CONSTRAINT purse_merges_' || partition_suffix || '_purse_merge_request_serial_id_key '
|
||||
'UNIQUE (purse_merge_request_serial_id) '
|
||||
'ALTER TABLE ' || table_name ||
|
||||
' ADD CONSTRAINT ' || table_name || '_foreign_partner_serial_id'
|
||||
' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
|
||||
',ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
|
||||
' REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
|
||||
',ADD CONSTRAINT ' || table_name || '_foreign_purse_pub'
|
||||
' REFERENCES purse_requests (purse_pub) ON DELETE CASCADE'
|
||||
);
|
||||
END
|
||||
$$;
|
||||
@ -82,4 +136,14 @@ INSERT INTO exchange_tables
|
||||
,'exchange-0002'
|
||||
,'create'
|
||||
,TRUE
|
||||
,FALSE),
|
||||
('purse_merges'
|
||||
,'exchange-0002'
|
||||
,'constrain'
|
||||
,TRUE
|
||||
,FALSE),
|
||||
('purse_merges'
|
||||
,'exchange-0002'
|
||||
,'foreign'
|
||||
,TRUE
|
||||
,FALSE);
|
||||
|
@ -14,26 +14,6 @@
|
||||
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
|
||||
--
|
||||
|
||||
-- ------------------------------ purse_merges ----------------------------------------
|
||||
|
||||
SELECT create_table_purse_merges();
|
||||
|
||||
COMMENT ON TABLE purse_merges
|
||||
IS 'Merge requests where a purse-owner requested merging the purse into the account';
|
||||
COMMENT ON COLUMN purse_merges.partner_serial_id
|
||||
IS 'identifies the partner exchange, NULL in case the target reserve lives at this exchange';
|
||||
COMMENT ON COLUMN purse_merges.reserve_pub
|
||||
IS 'public key of the target reserve';
|
||||
COMMENT ON COLUMN purse_merges.purse_pub
|
||||
IS 'public key of the purse';
|
||||
COMMENT ON COLUMN purse_merges.merge_sig
|
||||
IS 'signature by the purse private key affirming the merge, of type TALER_SIGNATURE_WALLET_PURSE_MERGE';
|
||||
COMMENT ON COLUMN purse_merges.merge_timestamp
|
||||
IS 'when was the merge message signed';
|
||||
|
||||
SELECT add_constraints_to_purse_merges_partition('default');
|
||||
|
||||
|
||||
-- ------------------------------ account_merges ----------------------------------------
|
||||
|
||||
SELECT create_table_account_merges();
|
||||
|
Loading…
Reference in New Issue
Block a user