diff options
Diffstat (limited to 'src/exchangedb/0002-policy_fulfillments.sql')
-rw-r--r-- | src/exchangedb/0002-policy_fulfillments.sql | 100 |
1 files changed, 83 insertions, 17 deletions
diff --git a/src/exchangedb/0002-policy_fulfillments.sql b/src/exchangedb/0002-policy_fulfillments.sql index 28dd619e0..c00947019 100644 --- a/src/exchangedb/0002-policy_fulfillments.sql +++ b/src/exchangedb/0002-policy_fulfillments.sql @@ -14,22 +14,88 @@ -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/> -- --- FIXME-Oec: this table should be sharded! +-- @author: Özgür Kesim -CREATE TABLE policy_fulfillments - (fulfillment_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE PRIMARY KEY - ,fulfillment_timestamp INT8 NOT NULL - ,fulfillment_proof TEXT - ,h_fulfillment_proof BYTEA NOT NULL CHECK(LENGTH(h_fulfillment_proof) = 64) UNIQUE - ,policy_hash_codes BYTEA NOT NULL CHECK(0 = MOD(LENGTH(policy_hash_codes), 16)) +CREATE FUNCTION create_table_policy_fulfillments( + IN partition_suffix TEXT DEFAULT NULL +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + table_name TEXT DEFAULT 'policy_fulfillments'; +BEGIN + PERFORM create_partitioned_table( + 'CREATE TABLE %I ' + '(h_fulfillment_proof gnunet_hashcode PRIMARY KEY' + ',fulfillment_id BIGINT GENERATED BY DEFAULT AS IDENTITY' + ',fulfillment_timestamp INT8 NOT NULL' + ',fulfillment_proof TEXT' + ',policy_hash_codes gnunet_hashcode[] NOT NULL' + ') %s ;' + ,table_name + ,'PARTITION BY HASH (h_fulfillment_proof)' + ,partition_suffix ); -COMMENT ON TABLE policy_fulfillments - IS 'Proofs of fulfillment of policies that were set in deposits'; -COMMENT ON COLUMN policy_fulfillments.fulfillment_timestamp - IS 'Timestamp of the arrival of a proof of fulfillment'; -COMMENT ON COLUMN policy_fulfillments.fulfillment_proof - IS 'JSON object with a proof of the fulfillment of a policy. Supported details depend on the policy extensions supported by the exchange.'; -COMMENT ON COLUMN policy_fulfillments.h_fulfillment_proof - IS 'Hash of the fulfillment_proof'; -COMMENT ON COLUMN policy_fulfillments.policy_hash_codes - IS 'Concatenation of the policy_hash_code of all policy_details that are fulfilled by this proof'; + PERFORM comment_partitioned_table( + 'Proofs of fulfillment of policies that were set in deposits' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Timestamp of the arrival of a proof of fulfillment' + ,'fulfillment_timestamp' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'JSON object with a proof of the fulfillment of a policy. Supported details depend on the policy extensions supported by the exchange.' + ,'fulfillment_proof' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Hash of the fulfillment_proof' + ,'h_fulfillment_proof' + ,table_name + ,partition_suffix + ); + PERFORM comment_partitioned_column( + 'Array of the policy_hash_code''s of all policy_details that are fulfilled by this proof' + ,'policy_hash_codes' + ,table_name + ,partition_suffix + ); +END +$$; + +COMMENT ON FUNCTION create_table_policy_fulfillments + IS 'Creates the policy_fulfillments table'; + +CREATE FUNCTION constrain_table_policy_fulfillments( + IN partition_suffix TEXT +) +RETURNS VOID +LANGUAGE plpgsql +AS $$ +DECLARE + partition_name TEXT; +BEGIN + partition_name = concat_ws('_', 'policy_fulfillments', partition_suffix); + + EXECUTE FORMAT ( + 'ALTER TABLE ' || partition_name || + ' ADD CONSTRAINT ' || partition_name || '_serial_id ' + ' UNIQUE (h_fulfillment_proof, fulfillment_id)' + ); +END +$$; +INSERT INTO exchange_tables + (name + ,version + ,action + ,partitioned + ,by_range) +VALUES + ('policy_fulfillments', 'exchange-0002', 'create', TRUE ,FALSE), + ('policy_fulfillments', 'exchange-0002', 'constrain', TRUE ,FALSE); |