cleaner sql

This commit is contained in:
Marco Boss 2022-02-28 22:32:59 +01:00
parent 23bc09fe3c
commit 0efc7fd524
No known key found for this signature in database
GPG Key ID: 89A3EC33C625C3DF

View File

@ -97,34 +97,47 @@ CREATE INDEX IF NOT EXISTS wire_targets_serial_id_index
);
CREATE OR REPLACE FUNCTION create_table_reserves(
IN shard_suffix VARCHAR DEFAULT ''
CREATE OR REPLACE FUNCTION create_partitioned_table(
IN table_definition VARCHAR
,IN table_name VARCHAR
,IN main_table_partition_str VARCHAR
,IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'reserves'
ELSE
'reserves_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (reserve_pub);'
ELSE
';'
END;
IF shard_suffix IS NOT NULL THEN
table_name=table_name || '_' || shard_suffix;
main_table_partition_str = '';
END IF;
EXECUTE FORMAT(
table_definition,
table_name,
main_table_partition_str
);
END
$$;
COMMENT ON FUNCTION create_partitioned_table
IS 'Create a table which may be partitioned. If shard_suffix is null, it is assumed
that the table is a main table. Which means that it will be partitioned by
main_table_partition_str. If it is not null a table named `table_name_shard_suffix`
(not partitioned) will be created. The table must include `%I` as placeholder for
the table name, and `%s ;` as placeholder for the partitioning method';
CREATE OR REPLACE FUNCTION create_table_reserves(
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
',reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)'
@ -132,9 +145,10 @@ BEGIN
',current_balance_frac INT4 NOT NULL'
',expiration_date INT8 NOT NULL'
',gc_date INT8 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'reserves'
,'PARTITION BY HASH (reserve_pub)'
,shard_suffix
);
END
@ -179,33 +193,14 @@ COMMENT ON INDEX reserves_by_gc_date_index
CREATE OR REPLACE FUNCTION create_table_reserves_in(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'reserves_in'
ELSE
'reserves_in_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (reserve_pub);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(reserve_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',reserve_pub BYTEA PRIMARY KEY REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
@ -215,9 +210,10 @@ BEGIN
',wire_source_serial_id INT8 NOT NULL' -- REFERENCES wire_targets (wire_target_serial_id)'
',exchange_account_section TEXT NOT NULL'
',execution_date INT8 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'reserves_in'
,'PARTITION BY HASH (reserve_pub)'
,shard_suffix
);
END
@ -257,33 +253,14 @@ CREATE INDEX IF NOT EXISTS reserves_in_by_exchange_account_reserve_in_serial_id_
CREATE OR REPLACE FUNCTION create_table_reserves_close(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'reserves_close'
ELSE
'reserves_close_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (reserve_pub);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(close_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE / PRIMARY KEY'
',reserve_pub BYTEA NOT NULL REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
@ -294,9 +271,10 @@ BEGIN
',amount_frac INT4 NOT NULL'
',closing_fee_val INT8 NOT NULL'
',closing_fee_frac INT4 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'reserves_close'
,'PARTITION BY HASH (reserve_pub)'
,shard_suffix
);
END
@ -325,33 +303,14 @@ CREATE INDEX IF NOT EXISTS reserves_close_by_reserve_pub_index
CREATE OR REPLACE FUNCTION create_table_reserves_out(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'reserves_out'
ELSE
'reserves_out_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (h_blind_ev);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(reserve_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64) UNIQUE'
@ -362,9 +321,10 @@ BEGIN
',execution_date INT8 NOT NULL'
',amount_with_fee_val INT8 NOT NULL'
',amount_with_fee_frac INT4 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'reserves_out'
,'PARTITION BY HASH (h_blind_ev)'
,shard_suffix
);
END
@ -478,33 +438,14 @@ COMMENT ON COLUMN extensions.config
CREATE OR REPLACE FUNCTION create_table_known_coins(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'known_coins'
ELSE
'known_coins_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (coin_pub);' -- FIXME: or include denominations_serial? or multi-level partitioning?
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(known_coin_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',denominations_serial INT8 NOT NULL REFERENCES denominations (denominations_serial) ON DELETE CASCADE'
@ -513,9 +454,10 @@ BEGIN
',denom_sig BYTEA NOT NULL'
',remaining_val INT8 NOT NULL'
',remaining_frac INT4 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'known_coins'
,'PARTITION BY HASH (coin_pub)' -- FIXME: or include denominations_serial? or multi-level partitioning?;
,shard_suffix
);
END
@ -549,33 +491,14 @@ CREATE INDEX IF NOT EXISTS known_coins_by_known_coin_id_index
CREATE OR REPLACE FUNCTION create_table_refresh_commitments(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'refresh_commitments'
ELSE
'refresh_commitments_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (rc);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(melt_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',rc BYTEA PRIMARY KEY CHECK (LENGTH(rc)=64)'
@ -585,9 +508,10 @@ BEGIN
',amount_with_fee_val INT8 NOT NULL'
',amount_with_fee_frac INT4 NOT NULL'
',noreveal_index INT4 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'refresh_commitments'
,'PARTITION BY HASH (rc)'
,shard_suffix
);
END
@ -622,33 +546,14 @@ CREATE INDEX IF NOT EXISTS refresh_commitments_by_old_coin_pub_index
CREATE OR REPLACE FUNCTION create_table_refresh_revealed_coins(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'refresh_revealed_coins'
ELSE
'refresh_revealed_coins_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (melt_serial_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(rrc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',melt_serial_id INT8 NOT NULL' -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE'
@ -659,10 +564,11 @@ BEGIN
',h_coin_ev BYTEA NOT NULL CHECK(LENGTH(h_coin_ev)=64)' -- UNIQUE'
',ev_sig BYTEA NOT NULL'
',ewv BYTEA NOT NULL'
-- ,PRIMARY KEY (melt_serial_id, freshcoin_index) -- done per shard
') %s'
,table_name
,partition_str
-- ,PRIMARY KEY (melt_serial_id, freshcoin_index) -- done per shard
') %s ;'
,'refresh_revealed_coins'
,'PARTITION BY HASH (melt_serial_id)'
,shard_suffix
);
END
@ -705,41 +611,23 @@ CREATE INDEX IF NOT EXISTS refresh_revealed_coins_by_melt_serial_id_index
(melt_serial_id);
CREATE OR REPLACE FUNCTION create_table_refresh_transfer_keys(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'refresh_transfer_keys'
ELSE
'refresh_transfer_keys_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (melt_serial_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(rtc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',melt_serial_id INT8 PRIMARY KEY' -- REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE'
',transfer_pub BYTEA NOT NULL CHECK(LENGTH(transfer_pub)=32)'
',transfer_privs BYTEA NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'refresh_transfer_keys'
,'PARTITION BY HASH (melt_serial_id)'
,shard_suffix
);
END
@ -780,33 +668,14 @@ COMMENT ON COLUMN extension_details.extension_options
CREATE OR REPLACE FUNCTION create_table_deposits(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'deposits'
ELSE
'deposits_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (shard);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- PRIMARY KEY'
',shard INT8 NOT NULL'
@ -827,9 +696,10 @@ BEGIN
',extension_blocked BOOLEAN NOT NULL DEFAULT FALSE'
',extension_details_serial_id INT8 REFERENCES extension_details (extension_details_serial_id) ON DELETE CASCADE'
',UNIQUE (shard, known_coin_id, merchant_pub, h_contract_terms)'
') %s'
,table_name
,partition_str
') %s ;'
,'deposits'
,'PARTITION BY HASH (shard)'
,shard_suffix
);
END
@ -892,33 +762,14 @@ COMMENT ON INDEX deposits_for_iterate_matching_index
CREATE OR REPLACE FUNCTION create_table_refunds(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'refunds'
ELSE
'refunds_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (deposit_serial_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',deposit_serial_id INT8 NOT NULL' -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE'
@ -927,9 +778,10 @@ BEGIN
',amount_with_fee_val INT8 NOT NULL'
',amount_with_fee_frac INT4 NOT NULL'
-- ,PRIMARY KEY (deposit_serial_id, rtransaction_id) -- done per shard!
') %s'
,table_name
,partition_str
') %s ;'
,'refunds'
,'PARTITION BY HASH (deposit_serial_id)'
,shard_suffix
);
END
@ -959,33 +811,14 @@ CREATE INDEX IF NOT EXISTS refunds_by_refund_serial_id_index
CREATE OR REPLACE FUNCTION create_table_wire_out(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'wire_out'
ELSE
'wire_out_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (wtid_raw);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- PRIMARY KEY'
',execution_date INT8 NOT NULL'
@ -994,9 +827,10 @@ BEGIN
',exchange_account_section TEXT NOT NULL'
',amount_val INT8 NOT NULL'
',amount_frac INT4 NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'wire_out'
,'PARTITION BY HASH (wtid_raw)'
,shard_suffix
);
END
@ -1027,40 +861,22 @@ CREATE INDEX IF NOT EXISTS wire_out_by_wire_target_serial_id_index
CREATE OR REPLACE FUNCTION create_table_aggregation_tracking(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'aggregation_tracking'
ELSE
'aggregation_tracking_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (deposit_serial_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(aggregation_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',deposit_serial_id INT8 PRIMARY KEY' -- REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE'
',wtid_raw BYTEA NOT NULL CONSTRAINT wire_out_ref REFERENCES wire_out(wtid_raw) ON DELETE CASCADE DEFERRABLE'
') %s'
,table_name
,partition_str
') %s ;'
,'aggregation_tracking'
,'PARTITION BY HASH (deposit_serial_id)'
,shard_suffix
);
END
@ -1113,33 +929,14 @@ CREATE INDEX IF NOT EXISTS wire_fee_by_end_date_index
CREATE OR REPLACE FUNCTION create_table_recoup(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'recoup'
ELSE
'recoup_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (known_coin_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(recoup_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id)'
@ -1149,9 +946,10 @@ BEGIN
',amount_frac INT4 NOT NULL'
',recoup_timestamp INT8 NOT NULL'
',reserve_out_serial_id INT8 NOT NULL' -- REFERENCES reserves_out (reserve_out_serial_id) ON DELETE CASCADE'
') %s'
,table_name
,partition_str
') %s ;'
,'recoup'
,'PARTITION BY HASH (known_coin_id);'
,shard_suffix
);
END
@ -1189,33 +987,14 @@ CREATE INDEX IF NOT EXISTS recoup_by_known_coin_id_index
CREATE OR REPLACE FUNCTION create_table_recoup_refresh(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'recoup_refresh'
ELSE
'recoup_refresh_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (known_coin_id);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(recoup_refresh_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id)'
@ -1225,9 +1004,10 @@ BEGIN
',amount_frac INT4 NOT NULL'
',recoup_timestamp INT8 NOT NULL'
',rrc_serial INT8 NOT NULL' -- REFERENCES refresh_revealed_coins (rrc_serial) ON DELETE CASCADE -- UNIQUE'
') %s'
,table_name
,partition_str
') %s ;'
,'recoup_refresh'
,'PARTITION BY HASH (known_coin_id)'
,shard_suffix
);
END
@ -1263,42 +1043,24 @@ CREATE INDEX IF NOT EXISTS recoup_refresh_by_known_coin_id_index
CREATE OR REPLACE FUNCTION create_table_prewire(
IN shard_suffix VARCHAR DEFAULT ''
IN shard_suffix VARCHAR DEFAULT NULL
)
RETURNS VOID
LANGUAGE plpgsql
AS $$
DECLARE
table_name VARCHAR;
partition_str VARCHAR;
BEGIN
table_name = CASE
shard_suffix
WHEN '' THEN
'prewire'
ELSE
'prewire_' || shard_suffix
END;
partition_str = CASE
shard_suffix
WHEN '' THEN
'PARTITION BY HASH (prewire_uuid);'
ELSE
';'
END;
EXECUTE FORMAT(
PERFORM create_partitioned_table(
'CREATE TABLE IF NOT EXISTS %I'
'(prewire_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY'
',wire_method TEXT NOT NULL'
',finished BOOLEAN NOT NULL DEFAULT false'
',failed BOOLEAN NOT NULL DEFAULT false'
',buf BYTEA NOT NULL'
') %s'
,table_name
,partition_str
') %s ;'
,'prewire'
,'PARTITION BY HASH (prewire_uuid)'
,shard_suffix
);
END