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 COMMENT ON TABLE denomination_revocations
IS 'remembering which denomination keys have been revoked'; 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/> -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
-- --
CREATE OR REPLACE FUNCTION create_table_denominations() CREATE TABLE denominations
RETURNS VOID
LANGUAGE plpgsql
AS $$
BEGIN
CREATE TABLE IF NOT EXISTS denominations
(denominations_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE (denominations_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
,denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64) ,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!) ,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 COMMENT ON COLUMN denominations.denominations_serial
IS 'needed for exchange-auditor replication logic'; 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 ON denominations
(expire_legal); (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 ,partition_suffix
); );
PERFORM comment_partitioned_table( 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 ,table_name
,partition_suffix ,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 IN shard_suffix VARCHAR DEFAULT NULL
) )
RETURNS VOID RETURNS VOID
@ -64,7 +64,7 @@ BEGIN
END $$; END $$;
CREATE OR foreign_table_history_requests() CREATE FUNCTION foreign_table_history_requests()
RETURNS VOID RETURNS VOID
LANGUAGE plpgsql LANGUAGE plpgsql
AS $$ AS $$

View File

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

View File

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

View File

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

View File

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

View File

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

View File

@ -14,20 +14,11 @@
-- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/> -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
-- --
-- Everything in one big transaction
BEGIN; BEGIN;
-- Check patch versioning is in place.
SELECT _v.register_patch('exchange-0003', NULL, NULL); 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; SET search_path TO exchange;
#include "0003-purse_actions.sql" #include "0003-purse_actions.sql"
#include "0003-purse_deletion.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/> -- TALER; see the file COPYING. If not, see <http://www.gnu.org/licenses/>
-- --
-- Everything in one big transaction
BEGIN; BEGIN;
SET search_path TO exchange; SET search_path TO exchange;
---------------------------------------------------------------------------
-- Stored procedures
---------------------------------------------------------------------------
CREATE OR REPLACE FUNCTION exchange_do_withdraw( CREATE OR REPLACE FUNCTION exchange_do_withdraw(
IN cs_nonce BYTEA, IN cs_nonce BYTEA,