gnunet-svn
[Top][All Lists]
Advanced

[Date Prev][Date Next][Thread Prev][Thread Next][Date Index][Thread Index]

[taler-exchange] branch master updated (95149f34 -> 07b4b1aa)


From: gnunet
Subject: [taler-exchange] branch master updated (95149f34 -> 07b4b1aa)
Date: Sun, 27 Nov 2022 22:14:24 +0100

This is an automated email from the git hooks/post-receive script.

grothoff pushed a change to branch master
in repository exchange.

    from 95149f34 -draft for better sql
     new 746a8a0c -remove shard support
     new 9580dd19 intermediate step in major SQL refactoring (not done at all)
     new be2c11a1 more sql refactoring
     new a322770d more work on SQL refactoring
     new 4f75bcdc more work on SQL refactoring
     new 85ce53a4 more work on SQL refactoring
     new 2eff222c more work on SQL refactoring
     new bbf3e6fe more work on SQL refactoring
     new f2ba02aa more sql refactoring
     new cf2e37cd more work on SQL refactoring
     new c86c9220 -db tests pass again
     new 0a75bcad -cleanup
     new 68abe6d9 -constraint no longer holds
     new 1cdd999c -fix foreign key constraint issue
     new 07b4b1aa handle partner_serial_id being NULL

The 15 revisions listed above as "new" are entirely new to this
repository and will be described in separate emails.  The revisions
listed as "add" were already present in the repository and have only
been added to this reference.


Summary of changes:
 contrib/gana                                       |    2 +-
 src/exchange-tools/taler-exchange-dbinit.c         |   72 +-
 src/exchangedb/.gitignore                          |    5 +-
 src/exchangedb/0002-account_merges.sql             |  133 +
 src/exchangedb/0002-aggregation_tracking.sql       |  117 +
 src/exchangedb/0002-aggregation_transient.sql      |   72 +
 src/exchangedb/0002-auditor_denom_sigs.sql         |   32 +
 src/exchangedb/0002-auditors.sql                   |   35 +
 src/exchangedb/0002-close_requests.sql             |  143 +
 src/exchangedb/0002-contracts.sql                  |  109 +
 src/exchangedb/0002-cs_nonce_locks.sql             |   97 +
 ...01.sql.in => 0002-denomination_revocations.sql} |   24 +-
 src/exchangedb/0002-denominations.sql              |   50 +
 src/exchangedb/0002-deposits.sql                   |  427 +++
 src/exchangedb/0002-exchange_sign_keys.sql         |   36 +
 .../{exchange-0002.sql.in => 0002-extensions.sql}  |   25 +-
 src/exchangedb/0002-global_fee.sql                 |   40 +
 src/exchangedb/0002-history_requests.sql           |   99 +
 src/exchangedb/0002-known_coins.sql                |  137 +
 .../{exchange-0002.sql.in => 0002-kyc_alerts.sql}  |   25 +-
 src/exchangedb/0002-legitimization_processes.sql   |  129 +
 .../0002-legitimization_requirements.sql           |   97 +
 src/exchangedb/0002-partner_accounts.sql           |   33 +
 src/exchangedb/0002-partners.sql                   |   49 +
 src/exchangedb/0002-policy_details.sql             |   59 +
 src/exchangedb/0002-policy_fulfillments.sql        |   35 +
 src/exchangedb/0002-prewire.sql                    |  114 +
 src/exchangedb/0002-profit_drains.sql              |   43 +
 src/exchangedb/0002-purse_decision.sql             |   88 +
 src/exchangedb/0002-purse_deposits.sql             |  146 +
 src/exchangedb/0002-purse_merges.sql               |  152 +
 src/exchangedb/0002-purse_requests.sql             |  167 ++
 src/exchangedb/0002-recoup.sql                     |  248 ++
 src/exchangedb/0002-recoup_refresh.sql             |  151 +
 src/exchangedb/0002-refresh_commitments.sql        |  131 +
 src/exchangedb/0002-refresh_revealed_coins.sql     |  163 ++
 src/exchangedb/0002-refresh_transfer_keys.sql      |  127 +
 src/exchangedb/0002-refunds.sql                    |  127 +
 src/exchangedb/0002-reserves.sql                   |  148 +
 src/exchangedb/0002-reserves_close.sql             |  117 +
 src/exchangedb/0002-reserves_in.sql                |  123 +
 src/exchangedb/0002-reserves_open_deposits.sql     |  100 +
 src/exchangedb/0002-reserves_open_requests.sql     |  115 +
 src/exchangedb/0002-reserves_out.sql               |  240 ++
 src/exchangedb/0002-revolving_work_shards.sql      |   46 +
 ...ge-0002.sql.in => 0002-signkey_revocations.sql} |   21 +-
 src/exchangedb/0002-wad_in_entries.sql             |  188 ++
 src/exchangedb/0002-wad_out_entries.sql            |  188 ++
 src/exchangedb/0002-wads_in.sql                    |  108 +
 src/exchangedb/0002-wads_out.sql                   |  129 +
 src/exchangedb/0002-wire_accounts.sql              |   34 +
 .../{exchange-0002-part.sql => 0002-wire_fee.sql}  |   35 +-
 src/exchangedb/0002-wire_out.sql                   |  131 +
 src/exchangedb/0002-wire_targets.sql               |   89 +
 src/exchangedb/0002-work_shards.sql                |   46 +
 src/exchangedb/0003-purse_actions.sql              |   74 +
 src/exchangedb/0003-purse_deletion.sql             |   94 +
 src/exchangedb/Makefile.am                         |   45 +-
 src/exchangedb/common-0001.sql                     | 3035 --------------------
 src/exchangedb/common-0002.sql                     |  205 --
 src/exchangedb/drop.sql                            |    1 +
 src/exchangedb/exchange-0001-part.sql              | 1522 ----------
 src/exchangedb/exchange-0001.sql                   |  297 ++
 src/exchangedb/exchange-0002.sql.in                |   59 +-
 .../{shard-0002-part.sql => exchange-0003.sql.in}  |   20 +-
 .../perf_exchangedb_reserves_in_insert.c           |   46 +-
 src/exchangedb/pg_complete_shard.c                 |    9 +-
 src/exchangedb/pg_create_shard_tables.c            |   66 -
 src/exchangedb/pg_create_shard_tables.h            |   39 -
 src/exchangedb/pg_create_tables.c                  |   38 +-
 src/exchangedb/pg_create_tables.h                  |    9 +-
 src/exchangedb/pg_do_purse_deposit.c               |    4 +-
 src/exchangedb/pg_get_reserve_history.c            |    4 +-
 src/exchangedb/pg_insert_purse_request.c           |   62 +-
 src/exchangedb/pg_setup_foreign_servers.c          |  118 -
 src/exchangedb/pg_setup_foreign_servers.h          |   39 -
 src/exchangedb/pg_setup_partitions.c               |   73 -
 src/exchangedb/pg_setup_partitions.h               |   39 -
 src/exchangedb/plugin_exchangedb_postgres.c        |   28 +-
 src/exchangedb/procedures.sql                      |   11 +-
 src/exchangedb/shard-0001-part.sql                 |  134 -
 src/exchangedb/test_exchangedb.c                   |   10 +-
 src/exchangedb/test_exchangedb_by_j.c              |   58 +-
 src/include/taler_exchangedb_plugin.h              |   49 +-
 84 files changed, 6129 insertions(+), 5656 deletions(-)
 create mode 100644 src/exchangedb/0002-account_merges.sql
 create mode 100644 src/exchangedb/0002-aggregation_tracking.sql
 create mode 100644 src/exchangedb/0002-aggregation_transient.sql
 create mode 100644 src/exchangedb/0002-auditor_denom_sigs.sql
 create mode 100644 src/exchangedb/0002-auditors.sql
 create mode 100644 src/exchangedb/0002-close_requests.sql
 create mode 100644 src/exchangedb/0002-contracts.sql
 create mode 100644 src/exchangedb/0002-cs_nonce_locks.sql
 rename src/exchangedb/{exchange-0001.sql.in => 
0002-denomination_revocations.sql} (63%)
 create mode 100644 src/exchangedb/0002-denominations.sql
 create mode 100644 src/exchangedb/0002-deposits.sql
 create mode 100644 src/exchangedb/0002-exchange_sign_keys.sql
 copy src/exchangedb/{exchange-0002.sql.in => 0002-extensions.sql} (60%)
 create mode 100644 src/exchangedb/0002-global_fee.sql
 create mode 100644 src/exchangedb/0002-history_requests.sql
 create mode 100644 src/exchangedb/0002-known_coins.sql
 copy src/exchangedb/{exchange-0002.sql.in => 0002-kyc_alerts.sql} (56%)
 create mode 100644 src/exchangedb/0002-legitimization_processes.sql
 create mode 100644 src/exchangedb/0002-legitimization_requirements.sql
 create mode 100644 src/exchangedb/0002-partner_accounts.sql
 create mode 100644 src/exchangedb/0002-partners.sql
 create mode 100644 src/exchangedb/0002-policy_details.sql
 create mode 100644 src/exchangedb/0002-policy_fulfillments.sql
 create mode 100644 src/exchangedb/0002-prewire.sql
 create mode 100644 src/exchangedb/0002-profit_drains.sql
 create mode 100644 src/exchangedb/0002-purse_decision.sql
 create mode 100644 src/exchangedb/0002-purse_deposits.sql
 create mode 100644 src/exchangedb/0002-purse_merges.sql
 create mode 100644 src/exchangedb/0002-purse_requests.sql
 create mode 100644 src/exchangedb/0002-recoup.sql
 create mode 100644 src/exchangedb/0002-recoup_refresh.sql
 create mode 100644 src/exchangedb/0002-refresh_commitments.sql
 create mode 100644 src/exchangedb/0002-refresh_revealed_coins.sql
 create mode 100644 src/exchangedb/0002-refresh_transfer_keys.sql
 create mode 100644 src/exchangedb/0002-refunds.sql
 create mode 100644 src/exchangedb/0002-reserves.sql
 create mode 100644 src/exchangedb/0002-reserves_close.sql
 create mode 100644 src/exchangedb/0002-reserves_in.sql
 create mode 100644 src/exchangedb/0002-reserves_open_deposits.sql
 create mode 100644 src/exchangedb/0002-reserves_open_requests.sql
 create mode 100644 src/exchangedb/0002-reserves_out.sql
 create mode 100644 src/exchangedb/0002-revolving_work_shards.sql
 copy src/exchangedb/{exchange-0002.sql.in => 0002-signkey_revocations.sql} 
(65%)
 create mode 100644 src/exchangedb/0002-wad_in_entries.sql
 create mode 100644 src/exchangedb/0002-wad_out_entries.sql
 create mode 100644 src/exchangedb/0002-wads_in.sql
 create mode 100644 src/exchangedb/0002-wads_out.sql
 create mode 100644 src/exchangedb/0002-wire_accounts.sql
 rename src/exchangedb/{exchange-0002-part.sql => 0002-wire_fee.sql} (52%)
 create mode 100644 src/exchangedb/0002-wire_out.sql
 create mode 100644 src/exchangedb/0002-wire_targets.sql
 create mode 100644 src/exchangedb/0002-work_shards.sql
 create mode 100644 src/exchangedb/0003-purse_actions.sql
 create mode 100644 src/exchangedb/0003-purse_deletion.sql
 delete mode 100644 src/exchangedb/common-0001.sql
 delete mode 100644 src/exchangedb/common-0002.sql
 delete mode 100644 src/exchangedb/exchange-0001-part.sql
 create mode 100644 src/exchangedb/exchange-0001.sql
 rename src/exchangedb/{shard-0002-part.sql => exchange-0003.sql.in} (75%)
 delete mode 100644 src/exchangedb/pg_create_shard_tables.c
 delete mode 100644 src/exchangedb/pg_create_shard_tables.h
 delete mode 100644 src/exchangedb/pg_setup_foreign_servers.c
 delete mode 100644 src/exchangedb/pg_setup_foreign_servers.h
 delete mode 100644 src/exchangedb/pg_setup_partitions.c
 delete mode 100644 src/exchangedb/pg_setup_partitions.h
 delete mode 100644 src/exchangedb/shard-0001-part.sql

diff --git a/contrib/gana b/contrib/gana
index b971fd44..a4a6b9ba 160000
--- a/contrib/gana
+++ b/contrib/gana
@@ -1 +1 @@
-Subproject commit b971fd44ebf51a9c403dbbff144b43e73aa02c6c
+Subproject commit a4a6b9ba4b2634c56194d53e36344686d7052cef
diff --git a/src/exchange-tools/taler-exchange-dbinit.c 
b/src/exchange-tools/taler-exchange-dbinit.c
index 7dd5c015..af4f381f 100644
--- a/src/exchange-tools/taler-exchange-dbinit.c
+++ b/src/exchange-tools/taler-exchange-dbinit.c
@@ -49,21 +49,11 @@ static int gc_db;
  */
 static uint32_t num_partitions;
 
-/**
- * -F option: setup a sharded database, i.e. create foreign tables/server
- */
-static int shard_db;
-
 /**
  * -f option: force partitions to be created when there is only one
  */
 static int force_create_partitions;
 
-/**
- * -S option: setup a database on a shard server, creates tables with suffix 
shard_idx
- */
-static uint32_t shard_idx;
-
 /**
  * Main function that will be run.
  *
@@ -100,23 +90,10 @@ run (void *cls,
                   "Could not drop tables as requested. Either database was not 
yet initialized, or permission denied. Consult the logs. Will still try to 
create new tables.\n");
     }
   }
-  if (0 < shard_idx)
-  {
-    if (GNUNET_OK !=
-        plugin->create_shard_tables (plugin->cls,
-                                     shard_idx))
-    {
-      GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
-                  "Could not create shard database\n");
-      global_ret = EXIT_NOTINSTALLED;
-    }
-    /* We do not want to continue if we are on a shard */
-    TALER_EXCHANGEDB_plugin_unload (plugin);
-    plugin = NULL;
-    return;
-  }
   if (GNUNET_OK !=
-      plugin->create_tables (plugin->cls))
+      plugin->create_tables (plugin->cls,
+                             force_create_partitions || num_partitions > 0,
+                             num_partitions))
   {
     fprintf (stderr,
              "Failed to initialize database.\n");
@@ -125,38 +102,6 @@ run (void *cls,
     global_ret = EXIT_NOPERMISSION;
     return;
   }
-  if (1 <
-      num_partitions
-      || (
-        1 == num_partitions
-        && force_create_partitions))
-  {
-    enum GNUNET_GenericReturnValue r = GNUNET_OK;
-    if (shard_db)
-    {
-      r = plugin->setup_foreign_servers (plugin->cls,
-                                         num_partitions);
-    }
-    else
-    {
-      r = plugin->setup_partitions (plugin->cls,
-                                    num_partitions);
-    }
-    if (GNUNET_OK != r)
-    {
-      GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
-                  "Could not setup partitions. Dropping default ones again\n");
-      if (GNUNET_OK != plugin->drop_tables (plugin->cls))
-      {
-        GNUNET_log (GNUNET_ERROR_TYPE_ERROR,
-                    "Could not drop tables after failed partitioning, please 
delete the DB manually\n");
-      }
-      TALER_EXCHANGEDB_plugin_unload (plugin);
-      plugin = NULL;
-      global_ret = EXIT_NOTINSTALLED;
-      return;
-    }
-  }
   if (gc_db || clear_shards)
   {
     if (GNUNET_OK !=
@@ -220,17 +165,8 @@ main (int argc,
     GNUNET_GETOPT_option_uint ('P',
                                "partition",
                                "NUMBER",
-                               "Setup a partitioned database where each table 
which can be partitioned holds NUMBER partitions on a single DB node (NOTE: 
sharding add -F for sharding)",
+                               "Setup a partitioned database where each table 
which can be partitioned holds NUMBER partitions on a single DB node",
                                &num_partitions),
-    GNUNET_GETOPT_option_flag ('F',
-                               "foreign",
-                               "Setup a sharded database with foreign servers 
(shards) / tables rather than a partitioned one, must be called as DB 
superuser.",
-                               &shard_db),
-    GNUNET_GETOPT_option_uint ('S',
-                               "shard",
-                               "INDEX",
-                               "Setup a shard server, creates tables with 
INDEX as suffix",
-                               &shard_idx),
     GNUNET_GETOPT_option_flag ('f',
                                "force",
                                "Force partitions to be created if there is 
only one partition",
diff --git a/src/exchangedb/.gitignore b/src/exchangedb/.gitignore
index 540724b8..fcac98bc 100644
--- a/src/exchangedb/.gitignore
+++ b/src/exchangedb/.gitignore
@@ -5,10 +5,7 @@ test-exchangedb-postgres
 test-exchangedb-signkeys
 test-perf-taler-exchangedb
 bench-db-postgres
-exchange-0001.sql
-shard-0000.sql
-shard-0001.sql
-drop0001.sql
 shard-drop0001.sqltest-exchangedb-by-j-postgres
 test-exchangedb-by-j-postgres
 perf-exchangedb-reserves-in-insert-postgres
+exchange-0002.sql
diff --git a/src/exchangedb/0002-account_merges.sql 
b/src/exchangedb/0002-account_merges.sql
new file mode 100644
index 00000000..b1995f20
--- /dev/null
+++ b/src/exchangedb/0002-account_merges.sql
@@ -0,0 +1,133 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_account_merges(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'account_merges';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE IF NOT EXISTS %I '
+      '(account_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY'
+      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
+      ',wallet_h_payto BYTEA NOT NULL CHECK (LENGTH(wallet_h_payto)=32)'
+      ',PRIMARY KEY (purse_pub)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Merge requests where a purse- and account-owner requested merging the 
purse into the account'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the target reserve'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'signature by the reserve private key affirming the merge, of type 
TALER_SIGNATURE_WALLET_ACCOUNT_MERGE'
+    ,'reserve_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_account_merges(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'account_merges';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- FIXME: change to materialized index by reserve_pub!?
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve_pub '
+    'ON ' || table_name || ' '
+    '(reserve_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_account_merge_request_serial_id_key'
+    ' UNIQUE (account_merge_request_serial_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_account_merges()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'account_merges';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
+    ' FOREIGN KEY (reserve_pub) '
+    ' REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_purse_pub'
+    ' FOREIGN KEY (purse_pub) '
+    ' REFERENCES purse_requests (purse_pub)'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('account_merges'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('account_merges'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('account_merges'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-aggregation_tracking.sql 
b/src/exchangedb/0002-aggregation_tracking.sql
new file mode 100644
index 00000000..f6135c5a
--- /dev/null
+++ b/src/exchangedb/0002-aggregation_tracking.sql
@@ -0,0 +1,117 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_aggregation_tracking(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'aggregation_tracking';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(aggregation_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',deposit_serial_id INT8 PRIMARY KEY'
+      ',wtid_raw BYTEA NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (deposit_serial_id)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'mapping from wire transfer identifiers (WTID) to deposits (and back)'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'identifier of the wire transfer'
+    ,'wtid_raw'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_aggregation_tracking(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'aggregation_tracking';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_wtid_raw_index '
+    'ON ' || table_name || ' '
+    '(wtid_raw);'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || '_by_wtid_raw_index '
+    'IS ' || quote_literal('for lookup_transactions') || ';'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_aggregation_serial_id_key'
+    ' UNIQUE (aggregation_serial_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_aggregation_tracking()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'aggregation_tracking';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_deposit'
+    ' FOREIGN KEY (deposit_serial_id) '
+    ' REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE' -- FIXME 
change to coin_pub + deposit_serial_id for more efficient deposit???
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('aggregation_tracking'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('aggregation_tracking'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('aggregation_tracking'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-aggregation_transient.sql 
b/src/exchangedb/0002-aggregation_transient.sql
new file mode 100644
index 00000000..2d77e63c
--- /dev/null
+++ b/src/exchangedb/0002-aggregation_transient.sql
@@ -0,0 +1,72 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_aggregation_transient(
+  IN shard_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'aggregation_transient';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+    '(amount_val INT8 NOT NULL'
+    ',amount_frac INT4 NOT NULL'
+    ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
+    ',merchant_pub BYTEA CHECK (LENGTH(merchant_pub)=32)'
+    ',exchange_account_section TEXT NOT NULL'
+    ',legitimization_requirement_serial_id INT8 NOT NULL DEFAULT(0)'
+    ',wtid_raw BYTEA NOT NULL CHECK (LENGTH(wtid_raw)=32)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (wire_target_h_payto)'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_table(
+    'aggregations currently happening (lacking wire_out, usually because the 
amount is too low); this table is not replicated'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+       'Sum of all of the aggregated deposits (without deposit fees)'
+      ,'amount_val'
+      ,table_name
+      ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+       'identifier of the wire transfer'
+      ,'wtid_raw'
+      ,table_name
+      ,shard_suffix
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('aggregation_transient'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-auditor_denom_sigs.sql 
b/src/exchangedb/0002-auditor_denom_sigs.sql
new file mode 100644
index 00000000..3ed645af
--- /dev/null
+++ b/src/exchangedb/0002-auditor_denom_sigs.sql
@@ -0,0 +1,32 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE TABLE auditor_denom_sigs
+  (auditor_denom_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,auditor_uuid INT8 NOT NULL REFERENCES auditors (auditor_uuid) ON DELETE 
CASCADE
+  ,denominations_serial INT8 NOT NULL REFERENCES denominations 
(denominations_serial) ON DELETE CASCADE
+  ,auditor_sig BYTEA CHECK (LENGTH(auditor_sig)=64)
+  ,PRIMARY KEY (denominations_serial, auditor_uuid)
+  );
+COMMENT ON TABLE auditor_denom_sigs
+  IS 'Table with auditor signatures on exchange denomination keys.';
+COMMENT ON COLUMN auditor_denom_sigs.auditor_uuid
+  IS 'Identifies the auditor.';
+COMMENT ON COLUMN auditor_denom_sigs.denominations_serial
+  IS 'Denomination the signature is for.';
+COMMENT ON COLUMN auditor_denom_sigs.auditor_sig
+  IS 'Signature of the auditor, of purpose 
TALER_SIGNATURE_AUDITOR_EXCHANGE_KEYS.';
diff --git a/src/exchangedb/0002-auditors.sql b/src/exchangedb/0002-auditors.sql
new file mode 100644
index 00000000..32ec8446
--- /dev/null
+++ b/src/exchangedb/0002-auditors.sql
@@ -0,0 +1,35 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE TABLE auditors
+  (auditor_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,auditor_pub BYTEA PRIMARY KEY CHECK (LENGTH(auditor_pub)=32)
+  ,auditor_name VARCHAR NOT NULL
+  ,auditor_url VARCHAR NOT NULL
+  ,is_active BOOLEAN NOT NULL
+  ,last_change INT8 NOT NULL
+  );
+COMMENT ON TABLE auditors
+  IS 'Table with auditors the exchange uses or has used in the past. Entries 
never expire as we need to remember the last_change column indefinitely.';
+COMMENT ON COLUMN auditors.auditor_pub
+  IS 'Public key of the auditor.';
+COMMENT ON COLUMN auditors.auditor_url
+  IS 'The base URL of the auditor.';
+COMMENT ON COLUMN auditors.is_active
+  IS 'true if we are currently supporting the use of this auditor.';
+COMMENT ON COLUMN auditors.last_change
+  IS 'Latest time when active status changed. Used to detect replays of old 
messages.';
diff --git a/src/exchangedb/0002-close_requests.sql 
b/src/exchangedb/0002-close_requests.sql
new file mode 100644
index 00000000..32149b1b
--- /dev/null
+++ b/src/exchangedb/0002-close_requests.sql
@@ -0,0 +1,143 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_close_requests(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'close_requests';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(close_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)'
+      ',close_timestamp INT8 NOT NULL'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',close_val INT8 NOT NULL'
+      ',close_frac INT4 NOT NULL'
+      ',close_fee_val INT8 NOT NULL'
+      ',close_fee_frac INT4 NOT NULL'
+      ',payto_uri VARCHAR NOT NULL'
+      ',done BOOL NOT NULL DEFAULT(FALSE)'
+      ',PRIMARY KEY (reserve_pub,close_timestamp)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Explicit requests by a reserve owner to close a reserve immediately'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'When the request was created by the client'
+    ,'close_timestamp'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature affirming that the reserve is to be closed'
+    ,'reserve_sig'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Balance of the reserve at the time of closing, to be wired to the 
associated bank account (minus the closing fee)'
+    ,'close_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the credited bank account. Optional.'
+    ,'payto_uri'
+    ,table_name
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_close_requests(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'close_requests';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_close_request_uuid_index '
+    'ON ' || table_name || ' '
+    '(close_request_serial_id);'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_close_request_done_index '
+    'ON ' || table_name || ' '
+    '(done);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_close_request_uuid_pkey'
+    ' UNIQUE (close_request_serial_id)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_close_requests()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'close_requests';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
+    ' FOREIGN KEY (reserve_pub) '
+    ' REFERENCES reserves(reserve_pub) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('close_requests'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('close_requests'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('close_requests'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-contracts.sql 
b/src/exchangedb/0002-contracts.sql
new file mode 100644
index 00000000..40965306
--- /dev/null
+++ b/src/exchangedb/0002-contracts.sql
@@ -0,0 +1,109 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_contracts(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'contracts';
+BEGIN
+  PERFORM create_partitioned_table(
+     'CREATE TABLE %I '
+     '(contract_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+     ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
+     ',pub_ckey BYTEA NOT NULL CHECK (LENGTH(pub_ckey)=32)'
+     ',contract_sig BYTEA NOT NULL CHECK (LENGTH(contract_sig)=64)'
+     ',e_contract BYTEA NOT NULL'
+     ',purse_expiration INT8 NOT NULL'
+     ',PRIMARY KEY (purse_pub)'
+     ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'encrypted contracts associated with purses'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the purse that the contract is associated with'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'signature over the encrypted contract by the purse contract key'
+    ,'contract_sig'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public ECDH key used to encrypt the contract, to be used with the purse 
private key for decryption'
+    ,'pub_ckey'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'AES-GCM encrypted contract terms (contains gzip compressed JSON after 
decryption)'
+    ,'e_contract'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_contracts(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'contracts';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_contract_serial_id_key'
+    ' UNIQUE (contract_serial_id) '
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('contracts'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('contracts'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-cs_nonce_locks.sql 
b/src/exchangedb/0002-cs_nonce_locks.sql
new file mode 100644
index 00000000..0cb88b3f
--- /dev/null
+++ b/src/exchangedb/0002-cs_nonce_locks.sql
@@ -0,0 +1,97 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_cs_nonce_locks(
+  partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(cs_nonce_lock_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',nonce BYTEA PRIMARY KEY CHECK (LENGTH(nonce)=32)'
+      ',op_hash BYTEA NOT NULL CHECK (LENGTH(op_hash)=64)'
+      ',max_denomination_serial INT8 NOT NULL'
+    ') %s ;'
+    ,'cs_nonce_locks'
+    ,'PARTITION BY HASH (nonce)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'ensures a Clause Schnorr client nonce is locked for use with an 
operation identified by a hash'
+    ,'cs_nonce_locks'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'actual nonce submitted by the client'
+    ,'nonce'
+    ,'cs_nonce_locks'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'hash (RC for refresh, blind coin hash for withdraw) the nonce may be 
used with'
+    ,'op_hash'
+    ,'cs_nonce_locks'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Maximum number of a CS denomination serial the nonce could be used with, 
for GC'
+    ,'max_denomination_serial'
+    ,'cs_nonce_locks'
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_cs_nonce_locks(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'cs_nonce_locks';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_cs_nonce_lock_serial_id_key'
+    ' UNIQUE (cs_nonce_lock_serial_id)'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('cs_nonce_locks'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('cs_nonce_locks'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/exchange-0001.sql.in 
b/src/exchangedb/0002-denomination_revocations.sql
similarity index 63%
rename from src/exchangedb/exchange-0001.sql.in
rename to src/exchangedb/0002-denomination_revocations.sql
index a01ac3a8..96e13cd1 100644
--- a/src/exchangedb/exchange-0001.sql.in
+++ b/src/exchangedb/0002-denomination_revocations.sql
@@ -14,20 +14,10 @@
 -- 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-0001', NULL, NULL);
-
--------------------- Schema ----------------------------
-
-CREATE SCHEMA exchange;
-COMMENT ON SCHEMA exchange IS 'taler-exchange data';
-
-SET search_path TO exchange;
-
-#include "common-0001.sql"
-#include "exchange-0001-part.sql"
-
-COMMIT;
+CREATE TABLE IF NOT EXISTS denomination_revocations
+  (denom_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,denominations_serial INT8 PRIMARY KEY REFERENCES denominations 
(denominations_serial) ON DELETE CASCADE
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  );
+COMMENT ON TABLE denomination_revocations
+  IS 'remembering which denomination keys have been revoked';
diff --git a/src/exchangedb/0002-denominations.sql 
b/src/exchangedb/0002-denominations.sql
new file mode 100644
index 00000000..d468a387
--- /dev/null
+++ b/src/exchangedb/0002-denominations.sql
@@ -0,0 +1,50 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+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!)
+  ,age_mask INT4 NOT NULL DEFAULT (0)
+  ,denom_pub BYTEA NOT NULL
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,valid_from INT8 NOT NULL
+  ,expire_withdraw INT8 NOT NULL
+  ,expire_deposit INT8 NOT NULL
+  ,expire_legal INT8 NOT NULL
+  ,coin_val INT8 NOT NULL
+  ,coin_frac INT4 NOT NULL
+  ,fee_withdraw_val INT8 NOT NULL
+  ,fee_withdraw_frac INT4 NOT NULL
+  ,fee_deposit_val INT8 NOT NULL
+  ,fee_deposit_frac INT4 NOT NULL
+  ,fee_refresh_val INT8 NOT NULL
+  ,fee_refresh_frac INT4 NOT NULL
+  ,fee_refund_val INT8 NOT NULL
+  ,fee_refund_frac INT4 NOT NULL
+  );
+COMMENT ON TABLE denominations
+  IS 'Main denominations table. All the valid denominations the exchange knows 
about.';
+COMMENT ON COLUMN denominations.denom_type
+  IS 'determines cipher type for blind signatures used with this denomination; 
0 is for RSA';
+COMMENT ON COLUMN denominations.age_mask
+  IS 'bitmask with the age restrictions that are being used for this 
denomination; 0 if denomination does not support the use of age restrictions';
+COMMENT ON COLUMN denominations.denominations_serial
+  IS 'needed for exchange-auditor replication logic';
+
+CREATE INDEX denominations_by_expire_legal_index
+  ON denominations
+  (expire_legal);
diff --git a/src/exchangedb/0002-deposits.sql b/src/exchangedb/0002-deposits.sql
new file mode 100644
index 00000000..92210afa
--- /dev/null
+++ b/src/exchangedb/0002-deposits.sql
@@ -0,0 +1,427 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_deposits(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',shard INT8 NOT NULL'
+      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+      ',known_coin_id INT8 NOT NULL' -- FIXME: column needed!?
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+      ',wallet_timestamp INT8 NOT NULL'
+      ',exchange_timestamp INT8 NOT NULL'
+      ',refund_deadline INT8 NOT NULL'
+      ',wire_deadline INT8 NOT NULL'
+      ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)'
+      ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)'
+      ',coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)'
+      ',wire_salt BYTEA NOT NULL CHECK (LENGTH(wire_salt)=16)'
+      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
+      ',done BOOLEAN NOT NULL DEFAULT FALSE'
+      ',policy_blocked BOOLEAN NOT NULL DEFAULT FALSE'
+      ',policy_details_serial_id INT8'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+    'Deposits we have received and for which we need to make (aggregate) wire 
transfers (and manage refunds).'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Used for load sharding in the materialized indices. Should be set based 
on merchant_pub. 64-bit value because we need an *unsigned* 32-bit value.'
+    ,'shard'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Used for garbage collection'
+    ,'known_coin_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the target bank account and KYC status'
+    ,'wire_target_h_payto'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Salt used when hashing the payto://-URI to get the h_wire'
+    ,'wire_salt'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Set to TRUE once we have included this deposit in some aggregate wire 
transfer to the merchant'
+    ,'done'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'True if the aggregation of the deposit is currently blocked by some 
policy extension mechanism. Used to filter out deposits that must not be 
processed by the canonical deposit logic.'
+    ,'policy_blocked'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'References policy extensions table, NULL if extensions are not used'
+    ,'policy_details_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_deposits(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_deposit_serial_id_pkey'
+    ' PRIMARY KEY (deposit_serial_id) '
+    ',ADD CONSTRAINT ' || table_name || 
'_coin_pub_merchant_pub_h_contract_terms_key'
+    ' UNIQUE (coin_pub, merchant_pub, h_contract_terms)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_deposits()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (coin_pub) '
+    ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_coin_id'
+    ' FOREIGN KEY (known_coin_id) '
+    ' REFERENCES known_coins (known_coin_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_policy_details'
+    ' FOREIGN KEY (policy_details_serial_id) '
+    ' REFERENCES policy_details (policy_details_serial_id) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+CREATE FUNCTION create_table_deposits_by_ready(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits_by_ready';
+BEGIN
+  PERFORM create_partitioned_table(
+  'CREATE TABLE %I'
+    '(wire_deadline INT8 NOT NULL'
+    ',shard INT8 NOT NULL'
+    ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+    ',deposit_serial_id INT8'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY RANGE (wire_deadline)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+    'Enables fast lookups for deposits_get_ready, auto-populated via TRIGGER 
below'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_deposits_by_ready(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits_by_ready';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_main_index '
+    'ON ' || table_name || ' '
+    '(wire_deadline ASC, shard ASC, coin_pub);'
+  );
+END
+$$;
+
+
+CREATE FUNCTION create_table_deposits_for_matching(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits_for_matching';
+BEGIN
+  PERFORM create_partitioned_table(
+  'CREATE TABLE %I'
+    '(refund_deadline INT8 NOT NULL'
+    ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)'
+    ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub) ON DELETE CASCADE
+    ',deposit_serial_id INT8'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY RANGE (refund_deadline)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Enables fast lookups for deposits_iterate_matching, auto-populated via 
TRIGGER below'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_deposits_for_matching(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'deposits_for_matching';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_main_index'
+    ' ON ' || table_name || ' '
+    '(refund_deadline ASC, merchant_pub, coin_pub);'
+  );
+END
+$$;
+
+
+CREATE OR REPLACE FUNCTION deposits_insert_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+DECLARE
+  is_ready BOOLEAN;
+BEGIN
+  is_ready  = NOT (NEW.done OR NEW.policy_blocked);
+
+  IF (is_ready)
+  THEN
+    INSERT INTO exchange.deposits_by_ready
+      (wire_deadline
+      ,shard
+      ,coin_pub
+      ,deposit_serial_id)
+    VALUES
+      (NEW.wire_deadline
+      ,NEW.shard
+      ,NEW.coin_pub
+      ,NEW.deposit_serial_id);
+    INSERT INTO exchange.deposits_for_matching
+      (refund_deadline
+      ,merchant_pub
+      ,coin_pub
+      ,deposit_serial_id)
+    VALUES
+      (NEW.refund_deadline
+      ,NEW.merchant_pub
+      ,NEW.coin_pub
+      ,NEW.deposit_serial_id);
+  END IF;
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION deposits_insert_trigger()
+  IS 'Replicate deposit inserts into materialized indices.';
+
+
+CREATE OR REPLACE FUNCTION deposits_update_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+DECLARE
+  was_ready BOOLEAN;
+DECLARE
+  is_ready BOOLEAN;
+BEGIN
+  was_ready = NOT (OLD.done OR OLD.policy_blocked);
+  is_ready  = NOT (NEW.done OR NEW.policy_blocked);
+  IF (was_ready AND NOT is_ready)
+  THEN
+    DELETE FROM exchange.deposits_by_ready
+     WHERE wire_deadline = OLD.wire_deadline
+       AND shard = OLD.shard
+       AND coin_pub = OLD.coin_pub
+       AND deposit_serial_id = OLD.deposit_serial_id;
+    DELETE FROM exchange.deposits_for_matching
+     WHERE refund_deadline = OLD.refund_deadline
+       AND merchant_pub = OLD.merchant_pub
+       AND coin_pub = OLD.coin_pub
+       AND deposit_serial_id = OLD.deposit_serial_id;
+  END IF;
+  IF (is_ready AND NOT was_ready)
+  THEN
+    INSERT INTO exchange.deposits_by_ready
+      (wire_deadline
+      ,shard
+      ,coin_pub
+      ,deposit_serial_id)
+    VALUES
+      (NEW.wire_deadline
+      ,NEW.shard
+      ,NEW.coin_pub
+      ,NEW.deposit_serial_id);
+    INSERT INTO exchange.deposits_for_matching
+      (refund_deadline
+      ,merchant_pub
+      ,coin_pub
+      ,deposit_serial_id)
+    VALUES
+      (NEW.refund_deadline
+      ,NEW.merchant_pub
+      ,NEW.coin_pub
+      ,NEW.deposit_serial_id);
+  END IF;
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION deposits_update_trigger()
+  IS 'Replicate deposits changes into materialized indices.';
+
+
+CREATE OR REPLACE FUNCTION deposits_delete_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+DECLARE
+  was_ready BOOLEAN;
+BEGIN
+  was_ready  = NOT (OLD.done OR OLD.policy_blocked);
+
+  IF (was_ready)
+  THEN
+    DELETE FROM exchange.deposits_by_ready
+     WHERE wire_deadline = OLD.wire_deadline
+       AND shard = OLD.shard
+       AND coin_pub = OLD.coin_pub
+       AND deposit_serial_id = OLD.deposit_serial_id;
+    DELETE FROM exchange.deposits_for_matching
+     WHERE refund_deadline = OLD.refund_deadline
+       AND merchant_pub = OLD.merchant_pub
+       AND coin_pub = OLD.coin_pub
+       AND deposit_serial_id = OLD.deposit_serial_id;
+  END IF;
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION deposits_delete_trigger()
+  IS 'Replicate deposit deletions into materialized indices.';
+
+
+CREATE FUNCTION master_table_deposits()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  CREATE TRIGGER deposits_on_insert
+    AFTER INSERT
+     ON deposits
+     FOR EACH ROW EXECUTE FUNCTION deposits_insert_trigger();
+  CREATE TRIGGER deposits_on_update
+    AFTER UPDATE
+      ON deposits
+     FOR EACH ROW EXECUTE FUNCTION deposits_update_trigger();
+  CREATE TRIGGER deposits_on_delete
+    AFTER DELETE
+     ON deposits
+     FOR EACH ROW EXECUTE FUNCTION deposits_delete_trigger();
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('deposits'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('deposits'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('deposits'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE),
+    ('deposits_by_ready'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,TRUE),
+    ('deposits_by_ready'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,TRUE),
+    ('deposits_for_matching'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,TRUE),
+    ('deposits_for_matching'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,TRUE),
+    ('deposits'
+    ,'exchange-0002'
+    ,'master'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-exchange_sign_keys.sql 
b/src/exchangedb/0002-exchange_sign_keys.sql
new file mode 100644
index 00000000..d6acc6bb
--- /dev/null
+++ b/src/exchangedb/0002-exchange_sign_keys.sql
@@ -0,0 +1,36 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE exchange_sign_keys
+  (esk_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,exchange_pub BYTEA PRIMARY KEY CHECK (LENGTH(exchange_pub)=32)
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,valid_from INT8 NOT NULL
+  ,expire_sign INT8 NOT NULL
+  ,expire_legal INT8 NOT NULL
+  );
+COMMENT ON TABLE exchange_sign_keys
+  IS 'Table with master public key signatures on exchange online signing 
keys.';
+COMMENT ON COLUMN exchange_sign_keys.exchange_pub
+  IS 'Public online signing key of the exchange.';
+COMMENT ON COLUMN exchange_sign_keys.master_sig
+  IS 'Signature affirming the validity of the signing key of purpose 
TALER_SIGNATURE_MASTER_SIGNING_KEY_VALIDITY.';
+COMMENT ON COLUMN exchange_sign_keys.valid_from
+  IS 'Time when this online signing key will first be used to sign messages.';
+COMMENT ON COLUMN exchange_sign_keys.expire_sign
+  IS 'Time when this online signing key will no longer be used to sign.';
+COMMENT ON COLUMN exchange_sign_keys.expire_legal
+  IS 'Time when this online signing key legally expires.';
diff --git a/src/exchangedb/exchange-0002.sql.in 
b/src/exchangedb/0002-extensions.sql
similarity index 60%
copy from src/exchangedb/exchange-0002.sql.in
copy to src/exchangedb/0002-extensions.sql
index b25555ce..5642ea13 100644
--- a/src/exchangedb/exchange-0002.sql.in
+++ b/src/exchangedb/0002-extensions.sql
@@ -14,17 +14,14 @@
 -- 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 "common-0002.sql"
-#include "exchange-0002-part.sql"
-
-COMMIT;
+CREATE TABLE extensions
+  (extension_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,name VARCHAR NOT NULL UNIQUE
+  ,manifest BYTEA
+  );
+COMMENT ON TABLE extensions
+  IS 'Configurations of the activated extensions';
+COMMENT ON COLUMN extensions.name
+  IS 'Name of the extension';
+COMMENT ON COLUMN extensions.manifest
+  IS 'Manifest of the extension as JSON-blob, maybe NULL.  It contains common 
meta-information and extension-specific configuration.';
diff --git a/src/exchangedb/0002-global_fee.sql 
b/src/exchangedb/0002-global_fee.sql
new file mode 100644
index 00000000..0a2f9b49
--- /dev/null
+++ b/src/exchangedb/0002-global_fee.sql
@@ -0,0 +1,40 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE global_fee
+  (global_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,start_date INT8 NOT NULL
+  ,end_date INT8 NOT NULL
+  ,history_fee_val INT8 NOT NULL
+  ,history_fee_frac INT4 NOT NULL
+  ,account_fee_val INT8 NOT NULL
+  ,account_fee_frac INT4 NOT NULL
+  ,purse_fee_val INT8 NOT NULL
+  ,purse_fee_frac INT4 NOT NULL
+  ,purse_timeout INT8 NOT NULL
+  ,history_expiration INT8 NOT NULL
+  ,purse_account_limit INT4 NOT NULL
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,PRIMARY KEY (start_date)
+  );
+COMMENT ON TABLE global_fee
+  IS 'list of the global fees of this exchange, by date';
+COMMENT ON COLUMN global_fee.global_fee_serial
+  IS 'needed for exchange-auditor replication logic';
+
+CREATE INDEX global_fee_by_end_date_index
+  ON global_fee
+  (end_date);
diff --git a/src/exchangedb/0002-history_requests.sql 
b/src/exchangedb/0002-history_requests.sql
new file mode 100644
index 00000000..5cd5c7b7
--- /dev/null
+++ b/src/exchangedb/0002-history_requests.sql
@@ -0,0 +1,99 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_history_requests(
+  IN shard_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'history_requests';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(history_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE
+      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)'
+      ',request_timestamp INT8 NOT NULL'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',history_fee_val INT8 NOT NULL'
+      ',history_fee_frac INT4 NOT NULL'
+      ',PRIMARY KEY (reserve_pub,request_timestamp)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Paid history requests issued by a client against a reserve'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'When was the history request made'
+    ,'request_timestamp'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature approving payment for the history request'
+    ,'reserve_sig'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'History fee approved by the signature'
+    ,'history_fee_val'
+    ,table_name
+    ,shard_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION foreign_table_history_requests()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'history_requests';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
+    ' FOREIGN KEY (reserve_pub) '
+    ' REFERENCES reserves(reserve_pub) ON DELETE CASCADE'
+  );
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('history_requests'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('history_requests'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-known_coins.sql 
b/src/exchangedb/0002-known_coins.sql
new file mode 100644
index 00000000..4cdb974e
--- /dev/null
+++ b/src/exchangedb/0002-known_coins.sql
@@ -0,0 +1,137 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_known_coins(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'known_coins';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(known_coin_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',denominations_serial INT8 NOT NULL'
+      ',coin_pub BYTEA NOT NULL PRIMARY KEY CHECK (LENGTH(coin_pub)=32)'
+      ',age_commitment_hash BYTEA CHECK (LENGTH(age_commitment_hash)=32)'
+      ',denom_sig BYTEA NOT NULL'
+      ',remaining_val INT8 NOT NULL DEFAULT(0)'
+      ',remaining_frac INT4 NOT NULL DEFAULT(0)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'information about coins and their signatures, so we do not have to store 
the signatures more than once if a coin is involved in multiple operations'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Denomination of the coin, determines the value of the original coin and 
applicable fees for coin-specific operations.'
+    ,'denominations_serial'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'EdDSA public key of the coin'
+    ,'coin_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Value of the coin that remains to be spent'
+    ,'remaining_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Optional hash of the age commitment for age restrictions as per DD 24 
(active if denom_type has the respective bit set)'
+    ,'age_commitment_hash'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'This is the signature of the exchange that affirms that the coin is a 
valid coin. The specific signature type depends on denom_type of the 
denomination.'
+    ,'denom_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_known_coins(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'known_coins';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_known_coin_id_key'
+    ' UNIQUE (known_coin_id)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_known_coins()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'known_coins';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_denominations'
+    ' FOREIGN KEY (denominations_serial) '
+    ' REFERENCES denominations (denominations_serial) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('known_coins'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('known_coins'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('known_coins'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/exchange-0002.sql.in 
b/src/exchangedb/0002-kyc_alerts.sql
similarity index 56%
copy from src/exchangedb/exchange-0002.sql.in
copy to src/exchangedb/0002-kyc_alerts.sql
index b25555ce..8e54846c 100644
--- a/src/exchangedb/exchange-0002.sql.in
+++ b/src/exchangedb/0002-kyc_alerts.sql
@@ -14,17 +14,14 @@
 -- 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 "common-0002.sql"
-#include "exchange-0002-part.sql"
-
-COMMIT;
+CREATE TABLE kyc_alerts
+  (h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=32)
+  ,trigger_type INT4 NOT NULL
+  ,UNIQUE(trigger_type,h_payto)
+  );
+COMMENT ON TABLE kyc_alerts
+  IS 'alerts about completed KYC events reliably notifying other components 
(even if they are not running)';
+COMMENT ON COLUMN kyc_alerts.h_payto
+  IS 'hash of the payto://-URI for which the KYC status changed';
+COMMENT ON COLUMN kyc_alerts.trigger_type
+  IS 'identifies the receiver of the alert, as the same h_payto may require 
multiple components to be notified';
diff --git a/src/exchangedb/0002-legitimization_processes.sql 
b/src/exchangedb/0002-legitimization_processes.sql
new file mode 100644
index 00000000..6248da1f
--- /dev/null
+++ b/src/exchangedb/0002-legitimization_processes.sql
@@ -0,0 +1,129 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_legitimization_processes(
+  IN shard_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(legitimization_process_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY' -- UNIQUE'
+      ',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
+      ',expiration_time INT8 NOT NULL DEFAULT (0)'
+      ',provider_section VARCHAR NOT NULL'
+      ',provider_user_id VARCHAR DEFAULT NULL'
+      ',provider_legitimization_id VARCHAR DEFAULT NULL'
+      ',UNIQUE (h_payto, provider_section)'
+    ') %s ;'
+    ,'legitimization_processes'
+    ,'PARTITION BY HASH (h_payto)'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_table(
+    'List of legitimization processes (ongoing and completed) by account and 
provider'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'unique ID for this legitimization process at the exchange'
+    ,'legitimization_process_serial_id'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'foreign key linking the entry to the wire_targets table, NOT a primary 
key (multiple legitimizations are possible per wire target)'
+    ,'h_payto'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'in the future if the respective KYC check was passed successfully'
+    ,'expiration_time'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Configuration file section with details about this provider'
+    ,'provider_section'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifier for the user at the provider that was used for the 
legitimization. NULL if provider is unaware.'
+    ,'provider_user_id'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifier for the specific legitimization process at the provider. NULL 
if legitimization was not started.'
+    ,'provider_legitimization_id'
+    ,'legitimization_processes'
+    ,shard_suffix
+  );
+END
+$$;
+
+-- We need a separate function for this, as we call create_table only once but 
need to add
+-- those constraints to each partition which gets created
+CREATE FUNCTION constrain_table_legitimization_processes(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  partition_name VARCHAR;
+BEGIN
+  partition_name = concat_ws('_', 'legitimization_processes', 
partition_suffix);
+
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || partition_name
+    || ' '
+      'ADD CONSTRAINT ' || partition_name || '_serial_key '
+        'UNIQUE (legitimization_process_serial_id)');
+  EXECUTE FORMAT (
+    'CREATE INDEX IF NOT EXISTS ' || partition_name || 
'_by_provider_and_legi_index '
+        'ON '|| partition_name || ' '
+        '(provider_section,provider_legitimization_id)'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || partition_name || '_by_provider_and_legi_index '
+    'IS ' || quote_literal('used (rarely) in kyc_provider_account_lookup') || 
';'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('legitimization_processes'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('legitimization_processes'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-legitimization_requirements.sql 
b/src/exchangedb/0002-legitimization_requirements.sql
new file mode 100644
index 00000000..7aaf7b79
--- /dev/null
+++ b/src/exchangedb/0002-legitimization_requirements.sql
@@ -0,0 +1,97 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_legitimization_requirements(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(legitimization_requirement_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY' -- UNIQUE'
+      ',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
+      ',required_checks VARCHAR NOT NULL'
+      ',UNIQUE (h_payto, required_checks)'
+    ') %s ;'
+    ,'legitimization_requirements'
+    ,'PARTITION BY HASH (h_payto)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'List of required legitimizations by account'
+    ,'legitimization_requirements'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'unique ID for this legitimization requirement at the exchange'
+    ,'legitimization_requirement_serial_id'
+    ,'legitimization_requirements'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'foreign key linking the entry to the wire_targets table, NOT a primary 
key (multiple legitimizations are possible per wire target)'
+    ,'h_payto'
+    ,'legitimization_requirements'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'space-separated list of required checks'
+    ,'required_checks'
+    ,'legitimization_requirements'
+    ,partition_suffix
+  );
+END
+$$;
+
+-- We need a separate function for this, as we call create_table only once but 
need to add
+-- those constraints to each partition which gets created
+CREATE FUNCTION constrain_table_legitimization_requirements(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  partition_name VARCHAR;
+BEGIN
+  partition_name = concat_ws('_', 'legitimization_requirements', 
partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || partition_name || ' '
+    'ADD CONSTRAINT ' || partition_name || '_serial_id_key '
+    'UNIQUE (legitimization_requirement_serial_id)');
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('legitimization_requirements'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('legitimization_requirements'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-partner_accounts.sql 
b/src/exchangedb/0002-partner_accounts.sql
new file mode 100644
index 00000000..0f4af92c
--- /dev/null
+++ b/src/exchangedb/0002-partner_accounts.sql
@@ -0,0 +1,33 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE TABLE partner_accounts
+  (payto_uri VARCHAR PRIMARY KEY
+  ,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE 
CASCADE
+  ,partner_master_sig BYTEA CHECK (LENGTH(partner_master_sig)=64)
+  ,last_seen INT8 NOT NULL
+  );
+CREATE INDEX IF NOT EXISTS partner_accounts_index_by_partner_and_time
+  ON partner_accounts (partner_serial_id,last_seen);
+COMMENT ON TABLE partner_accounts
+  IS 'Table with bank accounts of the partner exchange. Entries never expire 
as we need to remember the signature for the auditor.';
+COMMENT ON COLUMN partner_accounts.payto_uri
+  IS 'payto URI (RFC 8905) with the bank account of the partner exchange.';
+COMMENT ON COLUMN partner_accounts.partner_master_sig
+  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS by the partner 
master public key';
+COMMENT ON COLUMN partner_accounts.last_seen
+  IS 'Last time we saw this account as being active at the partner exchange. 
Used to select the most recent entry, and to detect when we should check 
again.';
diff --git a/src/exchangedb/0002-partners.sql b/src/exchangedb/0002-partners.sql
new file mode 100644
index 00000000..ff57f8fc
--- /dev/null
+++ b/src/exchangedb/0002-partners.sql
@@ -0,0 +1,49 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE partners
+  (partner_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,partner_master_pub BYTEA NOT NULL CHECK(LENGTH(partner_master_pub)=32)
+  ,start_date INT8 NOT NULL
+  ,end_date INT8 NOT NULL
+  ,next_wad INT8 NOT NULL DEFAULT (0)
+  ,wad_frequency INT8 NOT NULL
+  ,wad_fee_val INT8 NOT NULL
+  ,wad_fee_frac INT4 NOT NULL
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,partner_base_url TEXT NOT NULL
+  );
+COMMENT ON TABLE partners
+  IS 'exchanges we do wad transfers to';
+COMMENT ON COLUMN partners.partner_master_pub
+  IS 'offline master public key of the partner';
+COMMENT ON COLUMN partners.start_date
+  IS 'starting date of the partnership';
+COMMENT ON COLUMN partners.end_date
+  IS 'end date of the partnership';
+COMMENT ON COLUMN partners.next_wad
+  IS 'at what time should we do the next wad transfer to this partner 
(frequently updated); set to forever after the end_date';
+COMMENT ON COLUMN partners.wad_frequency
+  IS 'how often do we promise to do wad transfers';
+COMMENT ON COLUMN partners.wad_fee_val
+  IS 'how high is the fee for a wallet to be added to a wad to this partner';
+COMMENT ON COLUMN partners.partner_base_url
+  IS 'base URL of the REST API for this partner';
+COMMENT ON COLUMN partners.master_sig
+  IS 'signature of our master public key affirming the partnership, of purpose 
TALER_SIGNATURE_MASTER_PARTNER_DETAILS';
+
+CREATE INDEX IF NOT EXISTS partner_by_wad_time
+  ON partners (next_wad ASC);
diff --git a/src/exchangedb/0002-policy_details.sql 
b/src/exchangedb/0002-policy_details.sql
new file mode 100644
index 00000000..c9bfd157
--- /dev/null
+++ b/src/exchangedb/0002-policy_details.sql
@@ -0,0 +1,59 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+-- FIXME: this table should be sharded!
+
+CREATE TABLE policy_details
+  (policy_details_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,policy_hash_code BYTEA PRIMARY KEY CHECK(LENGTH(policy_hash_code)=16)
+  ,policy_json VARCHAR
+  ,deadline INT8 NOT NULL
+  ,commitment_val INT8 NOT NULL
+  ,commitment_frac INT4 NOT NULL
+  ,accumulated_total_val INT8 NOT NULL
+  ,accumulated_total_frac INT4 NOT NULL
+  ,fee_val INT8 NOT NULL
+  ,fee_frac INT4 NOT NULL
+  ,transferable_val INT8 NOT NULL
+  ,transferable_frac INT8 NOT NULL
+  ,fulfillment_state smallint NOT NULL CHECK(fulfillment_state between 0 and 5)
+  ,fulfillment_id BIGINT NULL REFERENCES policy_fulfillments (fulfillment_id) 
ON DELETE CASCADE
+  );
+COMMENT ON TABLE policy_details
+  IS 'Policies that were provided with deposits via policy extensions.';
+COMMENT ON COLUMN policy_details.policy_hash_code
+  IS 'ID (GNUNET_HashCode) that identifies a policy.  Will be calculated by 
the policy extension based on the content';
+COMMENT ON COLUMN policy_details.policy_json
+  IS 'JSON object with options set that the exchange needs to consider when 
executing a deposit. Supported details depend on the policy extensions 
supported by the exchange.';
+COMMENT ON COLUMN policy_details.deadline
+  IS 'Deadline until the policy must be marked as fulfilled (maybe "forever")';
+COMMENT ON COLUMN policy_details.commitment_val
+  IS 'The amount that this policy commits to.  Invariant: commitment >= fee';
+COMMENT ON COLUMN policy_details.accumulated_total_val
+  IS 'The sum of all contributions of all deposit that reference this policy.  
Invariant: The fulfilment_state must be Insufficient as long as 
accumulated_total < commitment';
+COMMENT ON COLUMN policy_details.fee_val
+  IS 'The fee for this policy, due when the policy is fulfilled or timed out';
+COMMENT ON COLUMN policy_details.transferable_val
+  IS 'The amount that on fulfillment or timeout will be transferred to the 
payto-URI''s of the corresponding deposit''s.  The policy fees must have been 
already deducted from it.  Invariant: fee+transferable <= accumulated_total.  
The remaining amount (accumulated_total - fee - transferable) can be refreshed 
by the owner of the coins when the state is Timeout or Success.';
+COMMENT ON COLUMN policy_details.fulfillment_state
+  IS 'State of the fulfillment:
+       - 0 (Failure)
+       - 1 (Insufficient)
+       - 2 (Ready)
+       - 4 (Success)
+       - 5 (Timeout)';
+COMMENT ON COLUMN policy_details.fulfillment_id
+  IS 'Reference to the proof of the fulfillment of this policy, if it exists.  
Invariant: If not NULL, this entry''s .hash_code MUST be part of the 
corresponding policy_fulfillments.policy_hash_codes array.';
diff --git a/src/exchangedb/0002-policy_fulfillments.sql 
b/src/exchangedb/0002-policy_fulfillments.sql
new file mode 100644
index 00000000..54f44df5
--- /dev/null
+++ b/src/exchangedb/0002-policy_fulfillments.sql
@@ -0,0 +1,35 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+-- FIXME: this table should be sharded!
+
+CREATE TABLE policy_fulfillments
+  (fulfillment_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE PRIMARY KEY
+  ,fulfillment_timestamp INT8 NOT NULL
+  ,fulfillment_proof VARCHAR
+  ,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))
+  );
+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';
diff --git a/src/exchangedb/0002-prewire.sql b/src/exchangedb/0002-prewire.sql
new file mode 100644
index 00000000..fb8dc221
--- /dev/null
+++ b/src/exchangedb/0002-prewire.sql
@@ -0,0 +1,114 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_prewire(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'prewire';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %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 BY HASH (prewire_uuid)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'pre-commit data for wire transfers we are about to execute'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'set to TRUE if the bank responded with a non-transient failure to our 
transfer request'
+    ,'failed'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'set to TRUE once bank confirmed receiving the wire transfer request'
+    ,'finished'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'serialized data to send to the bank to execute the wire transfer'
+    ,'buf'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_prewire(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'prewire';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_finished_index '
+    'ON ' || table_name || ' '
+    '(finished);'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || '_by_finished_index '
+    'IS ' || quote_literal('for gc_prewire') || ';'
+  );
+  -- FIXME: find a way to combine these two indices?
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_failed_finished_index '
+    'ON ' || table_name || ' '
+    '(failed,finished);'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || '_by_failed_finished_index '
+    'IS ' || quote_literal('for wire_prepare_data_get') || ';'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('prewire'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('prewire'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-profit_drains.sql 
b/src/exchangedb/0002-profit_drains.sql
new file mode 100644
index 00000000..4aba9b46
--- /dev/null
+++ b/src/exchangedb/0002-profit_drains.sql
@@ -0,0 +1,43 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE profit_drains
+  (profit_drain_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,wtid BYTEA PRIMARY KEY CHECK (LENGTH(wtid)=32)
+  ,account_section VARCHAR NOT NULL
+  ,payto_uri VARCHAR NOT NULL
+  ,trigger_date INT8 NOT NULL
+  ,amount_val INT8 NOT NULL
+  ,amount_frac INT4 NOT NULL
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,executed BOOLEAN NOT NULL DEFAULT FALSE
+  );
+COMMENT ON TABLE profit_drains
+  IS 'transactions to be performed to move profits from the escrow account of 
the exchange to a regular account';
+COMMENT ON COLUMN profit_drains.wtid
+  IS 'randomly chosen nonce, unique to prevent double-submission';
+COMMENT ON COLUMN profit_drains.account_section
+  IS 'specifies the configuration section in the taler-exchange-drain 
configuration with the wire account to drain';
+COMMENT ON COLUMN profit_drains.payto_uri
+  IS 'specifies the account to be credited';
+COMMENT ON COLUMN profit_drains.trigger_date
+  IS 'set by taler-exchange-offline at the time of making the signature; not 
necessarily the exact date of execution of the wire transfer, just for 
orientation';
+COMMENT ON COLUMN profit_drains.amount_val
+  IS 'amount to be transferred';
+COMMENT ON COLUMN profit_drains.master_sig
+  IS 'EdDSA signature of type TALER_SIGNATURE_MASTER_DRAIN_PROFIT';
+COMMENT ON COLUMN profit_drains.executed
+  IS 'set to TRUE by taler-exchange-drain on execution of the transaction, not 
replicated to auditor';
diff --git a/src/exchangedb/0002-purse_decision.sql 
b/src/exchangedb/0002-purse_decision.sql
new file mode 100644
index 00000000..e738292c
--- /dev/null
+++ b/src/exchangedb/0002-purse_decision.sql
@@ -0,0 +1,88 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_purse_decision(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_decision';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(purse_decision_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
+      ',action_timestamp INT8 NOT NULL'
+      ',refunded BOOL NOT NULL'
+      ',PRIMARY KEY (purse_pub)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Purses that were decided upon (refund or merge)'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+CREATE FUNCTION constrain_table_purse_decision(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_decision';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_purse_action_serial_id_key'
+    ' UNIQUE (purse_decision_serial_id) '
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_decision'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('purse_decision'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-purse_deposits.sql 
b/src/exchangedb/0002-purse_deposits.sql
new file mode 100644
index 00000000..9452f434
--- /dev/null
+++ b/src/exchangedb/0002-purse_deposits.sql
@@ -0,0 +1,146 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_purse_deposits(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_deposits';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',partner_serial_id INT8'
+      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
+      ',coin_pub BYTEA NOT NULL'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
+      ',PRIMARY KEY (purse_pub,coin_pub)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Requests depositing coins into a purse'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'identifies the partner exchange, NULL in case the target purse lives at 
this exchange'
+    ,'partner_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the coin being deposited'
+    ,'coin_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total amount being deposited'
+    ,'amount_with_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature of the coin affirming the deposit into the purse, of type 
TALER_SIGNATURE_PURSE_DEPOSIT'
+    ,'coin_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_purse_deposits(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_deposits';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- FIXME: change to materialized index by coin_pub!
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_coin_pub'
+    ' ON ' || table_name || ' (coin_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_purse_deposit_serial_id_key'
+    ' UNIQUE (purse_deposit_serial_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_purse_deposits()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_deposits';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_partner'
+    ' FOREIGN KEY (partner_serial_id) '
+    ' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (coin_pub) '
+    ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_deposits'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('purse_deposits'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('purse_deposits'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-purse_merges.sql 
b/src/exchangedb/0002-purse_merges.sql
new file mode 100644
index 00000000..df369514
--- /dev/null
+++ b/src/exchangedb/0002-purse_merges.sql
@@ -0,0 +1,152 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_purse_merges(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_merges';
+BEGIN
+  PERFORM create_partitioned_table(
+    '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)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Merge requests where a purse-owner requested merging the purse into the 
account'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'identifies the partner exchange, NULL in case the target reserve lives 
at this exchange'
+    ,'partner_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the target reserve'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_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
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'when was the merge message signed'
+    ,'merge_timestamp'
+    ,table_name
+    ,partition_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, partition_suffix);
+  -- FIXME: change to materialized index by reserve_pub!
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_reserve_pub '
+    'ON ' || table_name || ' '
+    '(reserve_pub);'
+  );
+  EXECUTE FORMAT (
+    '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 FUNCTION foreign_table_purse_merges()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_merges';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_partner_serial_id'
+    ' FOREIGN KEY (partner_serial_id) '
+    ' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
+    ' FOREIGN KEY (reserve_pub) '
+    ' REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_purse_pub'
+    ' FOREIGN KEY (purse_pub) '
+    ' REFERENCES purse_requests (purse_pub) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_merges'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('purse_merges'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('purse_merges'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-purse_requests.sql 
b/src/exchangedb/0002-purse_requests.sql
new file mode 100644
index 00000000..5038c241
--- /dev/null
+++ b/src/exchangedb/0002-purse_requests.sql
@@ -0,0 +1,167 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_purse_requests(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_requests';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(purse_requests_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
+      ',merge_pub BYTEA NOT NULL CHECK (LENGTH(merge_pub)=32)'
+      ',purse_creation INT8 NOT NULL'
+      ',purse_expiration INT8 NOT NULL'
+      ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)'
+      ',age_limit INT4 NOT NULL'
+      ',flags INT4 NOT NULL'
+      ',in_reserve_quota BOOLEAN NOT NULL DEFAULT(FALSE)'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+      ',purse_fee_val INT8 NOT NULL'
+      ',purse_fee_frac INT4 NOT NULL'
+      ',balance_val INT8 NOT NULL DEFAULT (0)'
+      ',balance_frac INT4 NOT NULL DEFAULT (0)'
+      ',purse_sig BYTEA NOT NULL CHECK(LENGTH(purse_sig)=64)'
+      ',PRIMARY KEY (purse_pub)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Requests establishing purses, associating them with a contract but 
without a target reserve'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Local time when the purse was created. Determines applicable purse fees.'
+    ,'purse_creation'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'When the purse is set to expire'
+    ,'purse_expiration'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Hash of the contract the parties are to agree to'
+    ,'h_contract_terms'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'see the enum TALER_WalletAccountMergeFlags'
+    ,'flags'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'set to TRUE if this purse currently counts against the number of free 
purses in the respective reserve'
+    ,'in_reserve_quota'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total amount expected to be in the purse'
+    ,'amount_with_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Purse fee the client agreed to pay from the reserve (accepted by the 
exchange at the time the purse was created). Zero if in_reserve_quota is TRUE.'
+    ,'purse_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+    'Total amount actually in the purse (updated)'
+    ,'balance_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature of the purse affirming the purse parameters, of type 
TALER_SIGNATURE_PURSE_REQUEST'
+    ,'purse_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+CREATE FUNCTION constrain_table_purse_requests(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'purse_requests';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- FIXME: change to materialized index by merge_pub!
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_merge_pub '
+    'ON ' || table_name || ' '
+    '(merge_pub);'
+  );
+  -- FIXME: drop index on master (crosses partitions)?
+  -- Or use materialized index? (needed?)
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_purse_expiration '
+    'ON ' || table_name || ' '
+    '(purse_expiration);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_purse_requests_serial_id_key'
+    ' UNIQUE (purse_requests_serial_id) '
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_requests'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('purse_requests'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-recoup.sql b/src/exchangedb/0002-recoup.sql
new file mode 100644
index 00000000..36e36d9d
--- /dev/null
+++ b/src/exchangedb/0002-recoup.sql
@@ -0,0 +1,248 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_recoup(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(recoup_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
+      ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)'
+      ',amount_val INT8 NOT NULL'
+      ',amount_frac INT4 NOT NULL'
+      ',recoup_timestamp INT8 NOT NULL'
+      ',reserve_out_serial_id INT8 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub);'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Information about recoups that were executed between a coin and a 
reserve. In this type of recoup, the amount is credited back to the reserve 
from which the coin originated.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Coin that is being debited in the recoup. Do not CASCADE ON DROP on the 
coin_pub, as we may keep the coin alive!'
+    ,'coin_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the h_blind_ev of the recouped coin and provides the link to 
the credited reserve.'
+    ,'reserve_out_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature by the coin affirming the recoup, of type 
TALER_SIGNATURE_WALLET_COIN_RECOUP'
+    ,'coin_sig'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Denomination blinding key used when creating the blinded coin from the 
planchet. Secret revealed during the recoup to provide the linkage between the 
coin and the withdraw operation.'
+    ,'coin_blind'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_recoup(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_coin_pub_index '
+    'ON ' || table_name || ' '
+    '(coin_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_recoup_uuid_key'
+    ' UNIQUE (recoup_uuid) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_recoup()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserves_out'
+    ' FOREIGN KEY (reserve_out_serial_id) '
+    ' REFERENCES reserves_out (reserve_out_serial_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (coin_pub) '
+    ' REFERENCES known_coins (coin_pub)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION create_table_recoup_by_reserve(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup_by_reserve';
+BEGIN
+  PERFORM create_partitioned_table(
+  'CREATE TABLE %I'
+    '(reserve_out_serial_id INT8 NOT NULL' -- REFERENCES reserves 
(reserve_out_serial_id) ON DELETE CASCADE
+    ',coin_pub BYTEA CHECK (LENGTH(coin_pub)=32)' -- REFERENCES known_coins 
(coin_pub)
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_out_serial_id)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Information in this table is strictly redundant with that of recoup, but 
saved by a different primary key for fast lookups by reserve_out_serial_id.'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_recoup_by_reserve(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup_by_reserve';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_main_index '
+    'ON ' || table_name || ' '
+    '(reserve_out_serial_id);'
+  );
+END
+$$;
+
+
+CREATE FUNCTION recoup_insert_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  INSERT INTO exchange.recoup_by_reserve
+    (reserve_out_serial_id
+    ,coin_pub)
+  VALUES
+    (NEW.reserve_out_serial_id
+    ,NEW.coin_pub);
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION recoup_insert_trigger()
+  IS 'Replicate recoup inserts into recoup_by_reserve table.';
+
+
+CREATE FUNCTION recoup_delete_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  DELETE FROM exchange.recoup_by_reserve
+   WHERE reserve_out_serial_id = OLD.reserve_out_serial_id
+     AND coin_pub = OLD.coin_pub;
+  RETURN OLD;
+END $$;
+COMMENT ON FUNCTION recoup_delete_trigger()
+  IS 'Replicate recoup deletions into recoup_by_reserve table.';
+
+
+CREATE FUNCTION master_table_recoup()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  CREATE TRIGGER recoup_on_insert
+    AFTER INSERT
+     ON recoup
+     FOR EACH ROW EXECUTE FUNCTION recoup_insert_trigger();
+  CREATE TRIGGER recoup_on_delete
+    AFTER DELETE
+      ON recoup
+     FOR EACH ROW EXECUTE FUNCTION recoup_delete_trigger();
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('recoup'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('recoup'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('recoup'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE),
+    ('recoup_by_reserve'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('recoup_by_reserve'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('recoup'
+    ,'exchange-0002'
+    ,'master'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-recoup_refresh.sql 
b/src/exchangedb/0002-recoup_refresh.sql
new file mode 100644
index 00000000..bfcfb3d8
--- /dev/null
+++ b/src/exchangedb/0002-recoup_refresh.sql
@@ -0,0 +1,151 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_recoup_refresh(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup_refresh';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+    '(recoup_refresh_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+    ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+    ',known_coin_id BIGINT NOT NULL'
+    ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
+    ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)'
+    ',amount_val INT8 NOT NULL'
+    ',amount_frac INT4 NOT NULL'
+    ',recoup_timestamp INT8 NOT NULL'
+    ',rrc_serial INT8 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Table of coins that originated from a refresh operation and that were 
recouped. Links the (fresh) coin to the melted operation (and thus the old 
coin). A recoup on a refreshed coin credits the old coin and debits the fresh 
coin.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Refreshed coin of a revoked denomination where the residual value is 
credited to the old coin. Do not CASCADE ON DROP on the coin_pub, as we may 
keep the coin alive!'
+    ,'coin_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'FIXME: (To be) used for garbage collection (in the absence of foreign 
constraints, in the future)'
+    ,'known_coin_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Link to the refresh operation. Also identifies the h_blind_ev of the 
recouped coin (as h_coin_ev).'
+    ,'rrc_serial'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Denomination blinding key used when creating the blinded coin from the 
planchet. Secret revealed during the recoup to provide the linkage between the 
coin and the refresh operation.'
+    ,'coin_blind'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_recoup_refresh(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup_refresh';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  -- FIXME: any query using this index will be slow. Materialize index or 
change query?
+  -- Also: which query uses this index?
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_rrc_serial_index'
+    ' ON ' || table_name || ' '
+    '(rrc_serial);'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_coin_pub_index'
+    ' ON ' || table_name || ' '
+    '(coin_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_recoup_refresh_uuid_key'
+    ' UNIQUE (recoup_refresh_uuid) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_recoup_refresh()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'recoup_refresh';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (coin_pub) '
+    ' REFERENCES known_coins (coin_pub)'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_known_coin_id'
+    ' FOREIGN KEY (known_coin_id) '
+    ' REFERENCES known_coins (known_coin_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_rrc_serial'
+    ' FOREIGN KEY (rrc_serial) '
+    ' REFERENCES refresh_revealed_coins (rrc_serial) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('recoup_refresh'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('recoup_refresh'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('recoup_refresh'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-refresh_commitments.sql 
b/src/exchangedb/0002-refresh_commitments.sql
new file mode 100644
index 00000000..c63995c7
--- /dev/null
+++ b/src/exchangedb/0002-refresh_commitments.sql
@@ -0,0 +1,131 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_refresh_commitments(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_commitments';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(melt_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
+      ',rc BYTEA PRIMARY KEY CHECK (LENGTH(rc)=64)'
+      ',old_coin_pub BYTEA NOT NULL'
+      ',old_coin_sig BYTEA NOT NULL CHECK(LENGTH(old_coin_sig)=64)'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+      ',noreveal_index INT4 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (rc)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Commitments made when melting coins and the gamma value chosen by the 
exchange.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'The gamma value chosen by the exchange in the cut-and-choose protocol'
+    ,'noreveal_index'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Commitment made by the client, hash over the various client inputs in 
the cut-and-choose protocol'
+    ,'rc'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Coin being melted in the refresh process.'
+    ,'old_coin_pub'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_refresh_commitments(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_commitments';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- Note: index spans partitions, may need to be materialized.
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_old_coin_pub_index '
+    'ON ' || table_name || ' '
+    '(old_coin_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_melt_serial_id_key'
+    ' UNIQUE (melt_serial_id)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_refresh_commitments()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_commitments';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (old_coin_pub) '
+    ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('refresh_commitments'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('refresh_commitments'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('refresh_commitments'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-refresh_revealed_coins.sql 
b/src/exchangedb/0002-refresh_revealed_coins.sql
new file mode 100644
index 00000000..912e4bbb
--- /dev/null
+++ b/src/exchangedb/0002-refresh_revealed_coins.sql
@@ -0,0 +1,163 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_refresh_revealed_coins(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_revealed_coins';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(rrc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',melt_serial_id INT8 NOT NULL'
+      ',freshcoin_index INT4 NOT NULL'
+      ',link_sig BYTEA NOT NULL CHECK(LENGTH(link_sig)=64)'
+      ',denominations_serial INT8 NOT NULL'
+      ',coin_ev BYTEA NOT NULL'
+      ',h_coin_ev BYTEA NOT NULL CHECK(LENGTH(h_coin_ev)=64)'
+      ',ev_sig BYTEA NOT NULL'
+      ',ewv BYTEA NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (melt_serial_id)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Revelations about the new coins that are to be created during a melting 
session.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'needed for exchange-auditor replication logic'
+    ,'rrc_serial'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the refresh commitment (rc) of the melt operation.'
+    ,'melt_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'index of the fresh coin being created (one melt operation may result in 
multiple fresh coins)'
+    ,'freshcoin_index'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'envelope of the new coin to be signed'
+    ,'coin_ev'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'exchange contributed values in the creation of the fresh coin (see /csr)'
+    ,'ewv'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'hash of the envelope of the new coin to be signed (for lookups)'
+    ,'h_coin_ev'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'exchange signature over the envelope'
+    ,'ev_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_refresh_revealed_coins(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_revealed_coins';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_coins_by_melt_serial_id_index '
+    'ON ' || table_name || ' '
+    '(melt_serial_id);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_rrc_serial_key'
+    ' UNIQUE (rrc_serial) '
+    ',ADD CONSTRAINT ' || table_name || '_coin_ev_key'
+    ' UNIQUE (coin_ev) '
+    ',ADD CONSTRAINT ' || table_name || '_h_coin_ev_key'
+    ' UNIQUE (h_coin_ev) '
+    ',ADD PRIMARY KEY (melt_serial_id, freshcoin_index)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_refresh_revealed_coins()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_revealed_coins';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_melt'
+    ' FOREIGN KEY (melt_serial_id)'
+    ' REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_denom'
+    ' FOREIGN KEY (denominations_serial)'
+    ' REFERENCES denominations (denominations_serial) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('refresh_revealed_coins'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('refresh_revealed_coins'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('refresh_revealed_coins'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-refresh_transfer_keys.sql 
b/src/exchangedb/0002-refresh_transfer_keys.sql
new file mode 100644
index 00000000..4d10dda1
--- /dev/null
+++ b/src/exchangedb/0002-refresh_transfer_keys.sql
@@ -0,0 +1,127 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_refresh_transfer_keys(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_transfer_keys';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(rtc_serial BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',melt_serial_id INT8 PRIMARY KEY'
+      ',transfer_pub BYTEA NOT NULL CHECK(LENGTH(transfer_pub)=32)'
+      ',transfer_privs BYTEA NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (melt_serial_id)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Transfer keys of a refresh operation (the data revealed to the 
exchange).'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'needed for exchange-auditor replication logic'
+    ,'rtc_serial'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the refresh commitment (rc) of the operation.'
+    ,'melt_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'transfer public key for the gamma index'
+    ,'transfer_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'array of TALER_CNC_KAPPA-1 transfer private keys that have been 
revealed, with the gamma entry being skipped'
+    ,'transfer_privs'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_refresh_transfer_keys(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_transfer_keys';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_rtc_serial_key'
+    ' UNIQUE (rtc_serial)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_refresh_transfer_keys()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refresh_transfer_keys';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || 'foreign_melt_serial_id'
+    ' FOREIGN KEY (melt_serial_id)'
+    ' REFERENCES refresh_commitments (melt_serial_id) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('refresh_transfer_keys'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('refresh_transfer_keys'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('refresh_transfer_keys'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-refunds.sql b/src/exchangedb/0002-refunds.sql
new file mode 100644
index 00000000..88af42db
--- /dev/null
+++ b/src/exchangedb/0002-refunds.sql
@@ -0,0 +1,127 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_refunds(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refunds';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+      ',deposit_serial_id INT8 NOT NULL'
+      ',merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)'
+      ',rtransaction_id INT8 NOT NULL'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Data on coins that were refunded. Technically, refunds always apply 
against specific deposit operations involving a coin. The combination of 
coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, 
and we usually select by coin_pub so that one goes first.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. 
Multiple deposits may match a refund, this only identifies one of them.'
+    ,'deposit_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'used by the merchant to make refunds unique in case the same coin for 
the same deposit gets a subsequent (higher) refund'
+    ,'rtransaction_id'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_refunds (
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refunds';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_coin_pub_index '
+    'ON ' || table_name || ' '
+    '(coin_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_refund_serial_id_key'
+    ' UNIQUE (refund_serial_id) '
+    ',ADD PRIMARY KEY (deposit_serial_id, rtransaction_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_refunds ()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'refunds';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_coin_pub'
+    ' FOREIGN KEY (coin_pub) '
+    ' REFERENCES known_coins (coin_pub) ON DELETE CASCADE'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_deposit'
+    ' FOREIGN KEY (deposit_serial_id) '
+    ' REFERENCES deposits (deposit_serial_id) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('refunds'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('refunds'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('refunds'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves.sql b/src/exchangedb/0002-reserves.sql
new file mode 100644
index 00000000..03d17aee
--- /dev/null
+++ b/src/exchangedb/0002-reserves.sql
@@ -0,0 +1,148 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'reserves';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(reserve_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',reserve_pub BYTEA PRIMARY KEY CHECK(LENGTH(reserve_pub)=32)'
+      ',current_balance_val INT8 NOT NULL DEFAULT(0)'
+      ',current_balance_frac INT4 NOT NULL DEFAULT(0)'
+      ',purses_active INT8 NOT NULL DEFAULT(0)'
+      ',purses_allowed INT8 NOT NULL DEFAULT(0)'
+      ',max_age INT4 NOT NULL DEFAULT(120)'
+      ',expiration_date INT8 NOT NULL'
+      ',gc_date INT8 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Summarizes the balance of a reserve. Updated when new funds are added or 
withdrawn.'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'EdDSA public key of the reserve. Knowledge of the private key implies 
ownership over the balance.'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Current balance remaining with the reserve.'
+    ,'current_balance_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Number of purses that were created by this reserve that are not expired 
and not fully paid.'
+    ,'purses_active'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Number of purses that this reserve is allowed to have active at most.'
+    ,'purses_allowed'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Used to trigger closing of reserves that have not been drained after 
some time'
+    ,'expiration_date'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Used to forget all information about a reserve during garbage collection'
+    ,'gc_date'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_reserves(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'reserves';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_unique_uuid'
+    ' UNIQUE (reserve_uuid)'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_expiration_index '
+    'ON ' || table_name || ' '
+    '(expiration_date'
+    ',current_balance_val'
+    ',current_balance_frac'
+    ');'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || '_by_expiration_index '
+    'IS ' || quote_literal('used in get_expired_reserves') || ';'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve_uuid_index '
+    'ON ' || table_name || ' '
+    '(reserve_uuid);'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_gc_date_index '
+    'ON ' || table_name || ' '
+    '(gc_date);'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || '_by_gc_date_index '
+    'IS ' || quote_literal('for reserve garbage collection') || ';'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves_close.sql 
b/src/exchangedb/0002-reserves_close.sql
new file mode 100644
index 00000000..52931b87
--- /dev/null
+++ b/src/exchangedb/0002-reserves_close.sql
@@ -0,0 +1,117 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves_close(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_close';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(close_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',reserve_pub BYTEA NOT NULL'
+      ',execution_date INT8 NOT NULL'
+      ',wtid BYTEA NOT NULL CHECK (LENGTH(wtid)=32)'
+      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
+      ',amount_val INT8 NOT NULL'
+      ',amount_frac INT4 NOT NULL'
+      ',closing_fee_val INT8 NOT NULL'
+      ',closing_fee_frac INT4 NOT NULL'
+      ',close_request_row INT8 NOT NULL DEFAULT(0)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'wire transfers executed by the reserve to close reserves'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the credited bank account (and KYC status). Note that closing 
does not depend on KYC.'
+    ,'wire_target_h_payto'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_reserves_close(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_close';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_close_uuid_pkey'
+    ' PRIMARY KEY (close_uuid)'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve_pub_index '
+    'ON ' || table_name || ' (reserve_pub);'
+  );
+END $$;
+
+
+CREATE FUNCTION foreign_table_reserves_close()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_close';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub'
+    ' FOREIGN KEY (reserve_pub)'
+    ' REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
+  );
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves_close'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_close'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('reserves_close'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves_in.sql 
b/src/exchangedb/0002-reserves_in.sql
new file mode 100644
index 00000000..d722a49e
--- /dev/null
+++ b/src/exchangedb/0002-reserves_in.sql
@@ -0,0 +1,123 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves_in(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_in';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(reserve_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE'
+      ',reserve_pub BYTEA PRIMARY KEY' -- REFERENCES reserves (reserve_pub) ON 
DELETE CASCADE'
+      ',wire_reference INT8 NOT NULL'
+      ',credit_val INT8 NOT NULL'
+      ',credit_frac INT4 NOT NULL'
+      ',wire_source_h_payto BYTEA CHECK (LENGTH(wire_source_h_payto)=32)'
+      ',exchange_account_section TEXT NOT NULL'
+      ',execution_date INT8 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'list of transfers of funds into the reserves, one per incoming wire 
transfer'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the debited bank account and KYC status'
+    ,'wire_source_h_payto'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the reserve. Private key signifies ownership of the 
remaining balance.'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Amount that was transferred into the reserve'
+    ,'credit_val'
+    ,table_name
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_reserves_in(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_in';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_reserve_in_serial_id_key'
+    ' UNIQUE (reserve_in_serial_id)'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve_in_serial_id_index '
+    'ON ' || table_name || ' '
+    '(reserve_in_serial_id);'
+  );
+  -- FIXME: where do we need this index? Can we do better?
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || 
'_by_exch_accnt_section_execution_date_idx '
+    'ON ' || table_name || ' '
+    '(exchange_account_section '
+    ',execution_date'
+    ');'
+  );
+  -- FIXME: where do we need this index? Can we do better?
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_exch_accnt_reserve_in_serial_id_idx '
+    'ON ' || table_name || ' '
+    '(exchange_account_section'
+    ',reserve_in_serial_id DESC'
+    ');'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves_in'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_in'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves_open_deposits.sql 
b/src/exchangedb/0002-reserves_open_deposits.sql
new file mode 100644
index 00000000..35605d36
--- /dev/null
+++ b/src/exchangedb/0002-reserves_open_deposits.sql
@@ -0,0 +1,100 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves_open_deposits(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_open_deposits';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(reserve_open_deposit_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)'
+      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
+      ',coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)'
+      ',contribution_val INT8 NOT NULL'
+      ',contribution_frac INT4 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (coin_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'coin contributions paying for a reserve to remain open'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the specific reserve being paid for (possibly together with 
reserve_sig).'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_reserves_open_deposits(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_open_deposits';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name || ' '
+      'ADD CONSTRAINT ' || table_name || '_coin_unique '
+        'PRIMARY KEY (coin_pub,coin_sig)'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_uuid '
+    'ON ' || table_name || ' '
+    '(reserve_open_deposit_uuid);'
+  );
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve '
+    'ON ' || table_name || ' '
+    '(reserve_pub);'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves_open_deposits'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_open_deposits'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves_open_requests.sql 
b/src/exchangedb/0002-reserves_open_requests.sql
new file mode 100644
index 00000000..bbd5ec90
--- /dev/null
+++ b/src/exchangedb/0002-reserves_open_requests.sql
@@ -0,0 +1,115 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves_open_requests(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_open_requests';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(open_request_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',reserve_pub BYTEA NOT NULL'
+      ',request_timestamp INT8 NOT NULL'
+      ',expiration_date INT8 NOT NULL'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',reserve_payment_val INT8 NOT NULL'
+      ',reserve_payment_frac INT4 NOT NULL'
+      ',requested_purse_limit INT4 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (reserve_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table (
+     'requests to keep a reserve open'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column (
+     'Fee to pay for the request from the reserve balance itself.'
+    ,'reserve_payment_val'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_reserves_open_requests(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_open_requests';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_by_uuid'
+    ' PRIMARY KEY (open_request_uuid)'
+    ',ADD CONSTRAINT ' || table_name || '_by_time'
+    ' UNIQUE (reserve_pub,request_timestamp)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_reserves_open_requests()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_open_requests';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_reserve_pub '
+    ' FOREIGN KEY (reserve_pub)'
+    ' REFERENCES reserves (reserve_pub) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves_open_requests'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_open_requests'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('reserves_open_requests'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-reserves_out.sql 
b/src/exchangedb/0002-reserves_out.sql
new file mode 100644
index 00000000..25d717a5
--- /dev/null
+++ b/src/exchangedb/0002-reserves_out.sql
@@ -0,0 +1,240 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_reserves_out(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_out';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I'
+      '(reserve_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64) UNIQUE'
+      ',denominations_serial INT8 NOT NULL'
+      ',denom_sig BYTEA NOT NULL'
+      ',reserve_uuid INT8 NOT NULL'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',execution_date INT8 NOT NULL'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+    ') %s ;'
+    ,'reserves_out'
+    ,'PARTITION BY HASH (h_blind_ev)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table (
+     'Withdraw operations performed on reserves.'
+    ,'reserves_out'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column (
+     'Hash of the blinded coin, used as primary key here so that broken 
clients that use a non-random coin or blinding factor fail to withdraw 
(otherwise they would fail on deposit when the coin is not unique there).'
+    ,'h_blind_ev'
+    ,'reserves_out'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column (
+     'We do not CASCADE ON DELETE for the foreign constrain here, as we may 
keep the denomination data alive'
+    ,'denominations_serial'
+    ,'reserves_out'
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_reserves_out(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_out';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_reserve_out_serial_id_key'
+    ' UNIQUE (reserve_out_serial_id)'
+  );
+  -- FIXME: change query to use reserves_out_by_reserve instead and 
materialize execution_date there as well???
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || 
'_by_reserve_uuid_and_execution_date_index '
+    'ON ' || table_name || ' '
+    '(reserve_uuid, execution_date);'
+  );
+  EXECUTE FORMAT (
+    'COMMENT ON INDEX ' || table_name || 
'_by_reserve_uuid_and_execution_date_index '
+    'IS ' || quote_literal('for get_reserves_out and 
exchange_do_withdraw_limit_check') || ';'
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_reserves_out()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR default 'reserves_out';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_denom'
+    ' FOREIGN KEY (denominations_serial)'
+    ' REFERENCES denominations (denominations_serial)'
+    ',ADD CONSTRAINT ' || table_name || '_foreign_reserve '
+    ' FOREIGN KEY (reserve_uuid)'
+    ' REFERENCES reserves (reserve_uuid) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+CREATE FUNCTION create_table_reserves_out_by_reserve(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'reserves_out_by_reserve';
+BEGIN
+  PERFORM create_partitioned_table(
+  'CREATE TABLE %I'
+    '(reserve_uuid INT8 NOT NULL' -- REFERENCES reserves (reserve_uuid) ON 
DELETE CASCADE
+    ',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64)'
+    ') %s '
+    ,table_name
+    ,'PARTITION BY HASH (reserve_uuid)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table (
+     'Information in this table is strictly redundant with that of 
reserves_out, but saved by a different primary key for fast lookups by reserve 
public key/uuid.'
+    ,table_name
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_reserves_out_by_reserve(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'reserves_out_by_reserve';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_main_index '
+    'ON ' || table_name || ' '
+    '(reserve_uuid);'
+  );
+END $$;
+
+
+CREATE FUNCTION reserves_out_by_reserve_insert_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  INSERT INTO exchange.reserves_out_by_reserve
+    (reserve_uuid
+    ,h_blind_ev)
+  VALUES
+    (NEW.reserve_uuid
+    ,NEW.h_blind_ev);
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION reserves_out_by_reserve_insert_trigger()
+  IS 'Replicate reserve_out inserts into reserve_out_by_reserve table.';
+
+
+CREATE FUNCTION reserves_out_by_reserve_delete_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  DELETE FROM exchange.reserves_out_by_reserve
+   WHERE reserve_uuid = OLD.reserve_uuid;
+  RETURN OLD;
+END $$;
+COMMENT ON FUNCTION reserves_out_by_reserve_delete_trigger()
+  IS 'Replicate reserve_out deletions into reserve_out_by_reserve table.';
+
+
+CREATE FUNCTION master_table_reserves_out()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  CREATE TRIGGER reserves_out_on_insert
+  AFTER INSERT
+   ON reserves_out
+   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_insert_trigger();
+  CREATE TRIGGER reserves_out_on_delete
+  AFTER DELETE
+    ON reserves_out
+   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_delete_trigger();
+END $$;
+COMMENT ON FUNCTION master_table_reserves_out()
+  IS 'Setup triggers to replicate reserve_out into reserve_out_by_reserve.';
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('reserves_out'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_out'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('reserves_out'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE),
+    ('reserves_out_by_reserve'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('reserves_out_by_reserve'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('reserves_out'
+    ,'exchange-0002'
+    ,'master'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-revolving_work_shards.sql 
b/src/exchangedb/0002-revolving_work_shards.sql
new file mode 100644
index 00000000..83094297
--- /dev/null
+++ b/src/exchangedb/0002-revolving_work_shards.sql
@@ -0,0 +1,46 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE UNLOGGED TABLE revolving_work_shards
+  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,last_attempt INT8 NOT NULL
+  ,start_row INT4 NOT NULL
+  ,end_row INT4 NOT NULL
+  ,active BOOLEAN NOT NULL DEFAULT FALSE
+  ,job_name VARCHAR NOT NULL
+  ,PRIMARY KEY (job_name, start_row)
+  );
+COMMENT ON TABLE revolving_work_shards
+  IS 'coordinates work between multiple processes working on the same job with 
partitions that need to be repeatedly processed; unlogged because on system 
crashes the locks represented by this table will have to be cleared anyway, 
typically using "taler-exchange-dbinit -s"';
+COMMENT ON COLUMN revolving_work_shards.shard_serial_id
+  IS 'unique serial number identifying the shard';
+COMMENT ON COLUMN revolving_work_shards.last_attempt
+  IS 'last time a worker attempted to work on the shard';
+COMMENT ON COLUMN revolving_work_shards.active
+  IS 'set to TRUE when a worker is active on the shard';
+COMMENT ON COLUMN revolving_work_shards.start_row
+  IS 'row at which the shard scope starts, inclusive';
+COMMENT ON COLUMN revolving_work_shards.end_row
+  IS 'row at which the shard scope ends, exclusive';
+COMMENT ON COLUMN revolving_work_shards.job_name
+  IS 'unique name of the job the workers on this shard are performing';
+
+CREATE INDEX revolving_work_shards_by_job_name_active_last_attempt_index
+  ON revolving_work_shards
+  (job_name
+  ,active
+  ,last_attempt
+  );
diff --git a/src/exchangedb/exchange-0002.sql.in 
b/src/exchangedb/0002-signkey_revocations.sql
similarity index 65%
copy from src/exchangedb/exchange-0002.sql.in
copy to src/exchangedb/0002-signkey_revocations.sql
index b25555ce..37ab32c6 100644
--- a/src/exchangedb/exchange-0002.sql.in
+++ b/src/exchangedb/0002-signkey_revocations.sql
@@ -14,17 +14,10 @@
 -- 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 "common-0002.sql"
-#include "exchange-0002-part.sql"
-
-COMMIT;
+CREATE TABLE signkey_revocations
+  (signkey_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,esk_serial INT8 PRIMARY KEY REFERENCES exchange_sign_keys (esk_serial) ON 
DELETE CASCADE
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  );
+COMMENT ON TABLE signkey_revocations
+  IS 'Table storing which online signing keys have been revoked';
diff --git a/src/exchangedb/0002-wad_in_entries.sql 
b/src/exchangedb/0002-wad_in_entries.sql
new file mode 100644
index 00000000..63c8bca2
--- /dev/null
+++ b/src/exchangedb/0002-wad_in_entries.sql
@@ -0,0 +1,188 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_wad_in_entries(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_in_entries';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(wad_in_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',wad_in_serial_id INT8'
+      ',reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)'
+      ',purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)'
+      ',h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)'
+      ',purse_expiration INT8 NOT NULL'
+      ',merge_timestamp INT8 NOT NULL'
+      ',amount_with_fee_val INT8 NOT NULL'
+      ',amount_with_fee_frac INT4 NOT NULL'
+      ',wad_fee_val INT8 NOT NULL'
+      ',wad_fee_frac INT4 NOT NULL'
+      ',deposit_fees_val INT8 NOT NULL'
+      ',deposit_fees_frac INT4 NOT NULL'
+      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+      ',purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'list of purses aggregated in a wad according to the sending exchange'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'wad for which the given purse was included in the aggregation'
+    ,'wad_in_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'target account of the purse (must be at the local exchange)'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'public key of the purse that was merged'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+    'hash of the contract terms of the purse'
+    ,'h_contract'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the purse was set to expire'
+    ,'purse_expiration'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the merge was approved'
+    ,'merge_timestamp'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total amount in the purse'
+    ,'amount_with_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total wad fees paid by the purse'
+    ,'wad_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total deposit fees paid when depositing coins into the purse'
+    ,'deposit_fees_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature by the receiving reserve, of purpose 
TALER_SIGNATURE_ACCOUNT_MERGE'
+    ,'reserve_sig'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE'
+    ,'purse_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_wad_in_entries(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_in_entries';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- FIXME: change to materialized index by reserve_pub!
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_reserve_pub '
+    'ON ' || table_name || ' '
+    '(reserve_pub);'
+  );
+  EXECUTE FORMAT (
+    '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 || '_wad_in_entry_serial_id_key'
+    ' UNIQUE (wad_in_entry_serial_id) '
+  );
+END $$;
+
+
+CREATE FUNCTION foreign_table_wad_in_entries()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_in_entries';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_wad_in'
+    ' FOREIGN KEY(wad_in_serial_id)'
+    ' REFERENCES wads_in (wad_in_serial_id) ON DELETE CASCADE'
+  );
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wad_in_entries'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wad_in_entries'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('wad_in_entries'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-wad_out_entries.sql 
b/src/exchangedb/0002-wad_out_entries.sql
new file mode 100644
index 00000000..45a4813c
--- /dev/null
+++ b/src/exchangedb/0002-wad_out_entries.sql
@@ -0,0 +1,188 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE FUNCTION create_table_wad_out_entries(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_out_entries';
+BEGIN
+  PERFORM create_partitioned_table(
+     'CREATE TABLE %I '
+     '(wad_out_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+     ',wad_out_serial_id INT8'
+     ',reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)'
+     ',purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)'
+     ',h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)'
+     ',purse_expiration INT8 NOT NULL'
+     ',merge_timestamp INT8 NOT NULL'
+     ',amount_with_fee_val INT8 NOT NULL'
+     ',amount_with_fee_frac INT4 NOT NULL'
+     ',wad_fee_val INT8 NOT NULL'
+     ',wad_fee_frac INT4 NOT NULL'
+     ',deposit_fees_val INT8 NOT NULL'
+     ',deposit_fees_frac INT4 NOT NULL'
+     ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
+     ',purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)'
+     ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (purse_pub)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+    'Purses combined into a wad'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Wad the purse was part of'
+    ,'wad_out_serial_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Target reserve for the purse'
+    ,'reserve_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Public key of the purse'
+    ,'purse_pub'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Hash of the contract associated with the purse'
+    ,'h_contract'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the purse expires'
+    ,'purse_expiration'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the merge was approved'
+    ,'merge_timestamp'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total amount in the purse'
+    ,'amount_with_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+    'Wad fee charged to the purse'
+    ,'wad_fee_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Total deposit fees charged to the purse'
+    ,'deposit_fees_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature by the receiving reserve, of purpose 
TALER_SIGNATURE_ACCOUNT_MERGE'
+    ,'reserve_sig'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE'
+    ,'purse_sig'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_wad_out_entries(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_out_entries';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+
+  -- FIXME: change to materialized index by reserve_pub!
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_reserve_pub '
+    'ON ' || table_name || ' '
+    '(reserve_pub);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_wad_out_entry_serial_id_key'
+    ' UNIQUE (wad_out_entry_serial_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_wad_out_entries()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wad_out_entries';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_wad_out'
+    ' FOREIGN KEY(wad_out_serial_id)'
+    ' REFERENCES wads_out (wad_out_serial_id) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wad_out_entries'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wad_out_entries'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('wad_out_entries'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-wads_in.sql b/src/exchangedb/0002-wads_in.sql
new file mode 100644
index 00000000..013b1635
--- /dev/null
+++ b/src/exchangedb/0002-wads_in.sql
@@ -0,0 +1,108 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_wads_in(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wads_in';
+BEGIN
+  PERFORM create_partitioned_table(
+     'CREATE TABLE %I '
+     '(wad_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+     ',wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)'
+     ',origin_exchange_url TEXT NOT NULL'
+     ',amount_val INT8 NOT NULL'
+     ',amount_frac INT4 NOT NULL'
+     ',arrival_time INT8 NOT NULL'
+     ',UNIQUE (wad_id, origin_exchange_url)'
+     ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (wad_id)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Incoming exchange-to-exchange wad wire transfers'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Unique identifier of the wad, part of the wire transfer subject'
+    ,'wad_id'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Base URL of the originating URL, also part of the wire transfer subject'
+    ,'origin_exchange_url'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Actual amount that was received by our exchange'
+    ,'amount_val'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the wad was received'
+    ,'arrival_time'
+    ,table_name
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_wads_in(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wads_in';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_wad_in_serial_id_key'
+    ' UNIQUE (wad_in_serial_id) '
+    ',ADD CONSTRAINT ' || table_name || '_wad_is_origin_exchange_url_key'
+    ' UNIQUE (wad_id, origin_exchange_url) '
+  );
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wads_in'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wads_in'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-wads_out.sql b/src/exchangedb/0002-wads_out.sql
new file mode 100644
index 00000000..edad4a68
--- /dev/null
+++ b/src/exchangedb/0002-wads_out.sql
@@ -0,0 +1,129 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_wads_out(
+  IN shard_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wads_out';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE %I '
+      '(wad_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)'
+      ',partner_serial_id INT8 NOT NULL'
+      ',amount_val INT8 NOT NULL'
+      ',amount_frac INT4 NOT NULL'
+      ',execution_time INT8 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (wad_id)'
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'Wire transfers made to another exchange to transfer purse funds'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Unique identifier of the wad, part of the wire transfer subject'
+    ,'wad_id'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'target exchange of the wad'
+    ,'partner_serial_id'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Amount that was wired'
+    ,'amount_val'
+    ,table_name
+    ,shard_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Time when the wire transfer was scheduled'
+    ,'execution_time'
+    ,table_name
+    ,shard_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_wads_out(
+  IN partition_suffix VARCHAR
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wads_out';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_wad_out_serial_id_key'
+    ' UNIQUE (wad_out_serial_id) '
+  );
+END
+$$;
+
+
+CREATE FUNCTION foreign_table_wads_out()
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wads_out';
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_foreign_partner'
+    ' FOREIGN KEY(partner_serial_id)'
+    ' REFERENCES partners(partner_serial_id) ON DELETE CASCADE'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wads_out'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wads_out'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('wads_out'
+    ,'exchange-0002'
+    ,'foreign'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-wire_accounts.sql 
b/src/exchangedb/0002-wire_accounts.sql
new file mode 100644
index 00000000..628bc599
--- /dev/null
+++ b/src/exchangedb/0002-wire_accounts.sql
@@ -0,0 +1,34 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE wire_accounts
+  (payto_uri VARCHAR PRIMARY KEY
+  ,master_sig BYTEA CHECK (LENGTH(master_sig)=64)
+  ,is_active BOOLEAN NOT NULL
+  ,last_change INT8 NOT NULL
+  );
+COMMENT ON TABLE wire_accounts
+  IS 'Table with current and historic bank accounts of the exchange. Entries 
never expire as we need to remember the last_change column indefinitely.';
+COMMENT ON COLUMN wire_accounts.payto_uri
+  IS 'payto URI (RFC 8905) with the bank account of the exchange.';
+COMMENT ON COLUMN wire_accounts.master_sig
+  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS';
+COMMENT ON COLUMN wire_accounts.is_active
+  IS 'true if we are currently supporting the use of this account.';
+COMMENT ON COLUMN wire_accounts.last_change
+  IS 'Latest time when active status changed. Used to detect replays of old 
messages.';
+-- "wire_accounts" has no sequence because it is a 'mutable' table
+--            and is of no concern to the auditor
diff --git a/src/exchangedb/exchange-0002-part.sql 
b/src/exchangedb/0002-wire_fee.sql
similarity index 52%
rename from src/exchangedb/exchange-0002-part.sql
rename to src/exchangedb/0002-wire_fee.sql
index 1697a375..deb26cef 100644
--- a/src/exchangedb/exchange-0002-part.sql
+++ b/src/exchangedb/0002-wire_fee.sql
@@ -14,20 +14,23 @@
 -- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
 --
 
--- ------------------------------ wire_targets 
----------------------------------------
-
-SELECT create_table_wire_targets();
-
-COMMENT ON TABLE wire_targets
-  IS 'All senders and recipients of money via the exchange';
-COMMENT ON COLUMN wire_targets.payto_uri
-  IS 'Can be a regular bank account, or also be a URI identifying a 
reserve-account (for P2P payments)';
-COMMENT ON COLUMN wire_targets.wire_target_h_payto
-  IS 'Unsalted hash of payto_uri';
-
-CREATE TABLE IF NOT EXISTS wire_targets_default
-  PARTITION OF wire_targets
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wire_targets_partition('default');
+CREATE TABLE wire_fee
+  (wire_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,wire_method VARCHAR NOT NULL
+  ,start_date INT8 NOT NULL
+  ,end_date INT8 NOT NULL
+  ,wire_fee_val INT8 NOT NULL
+  ,wire_fee_frac INT4 NOT NULL
+  ,closing_fee_val INT8 NOT NULL
+  ,closing_fee_frac INT4 NOT NULL
+  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+  ,PRIMARY KEY (wire_method, start_date)
+  );
+COMMENT ON TABLE wire_fee
+  IS 'list of the wire fees of this exchange, by date';
+COMMENT ON COLUMN wire_fee.wire_fee_serial
+  IS 'needed for exchange-auditor replication logic';
 
+CREATE INDEX wire_fee_by_end_date_index
+  ON wire_fee
+  (end_date);
diff --git a/src/exchangedb/0002-wire_out.sql b/src/exchangedb/0002-wire_out.sql
new file mode 100644
index 00000000..9c459fe9
--- /dev/null
+++ b/src/exchangedb/0002-wire_out.sql
@@ -0,0 +1,131 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_wire_out(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wire_out';
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE IF NOT EXISTS %I'
+      '(wireout_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY'
+      ',execution_date INT8 NOT NULL'
+      ',wtid_raw BYTEA UNIQUE NOT NULL CHECK (LENGTH(wtid_raw)=32)'
+      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
+      ',exchange_account_section TEXT NOT NULL'
+      ',amount_val INT8 NOT NULL'
+      ',amount_frac INT4 NOT NULL'
+    ') %s ;'
+    ,table_name
+    ,'PARTITION BY HASH (wtid_raw)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'wire transfers the exchange has executed'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'identifies the configuration section with the debit account of this 
payment'
+    ,'exchange_account_section'
+    ,table_name
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Identifies the credited bank account and KYC status'
+    ,'wire_target_h_payto'
+    ,table_name
+    ,partition_suffix
+  );
+END
+$$;
+
+
+CREATE FUNCTION constrain_table_wire_out(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wire_out';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'CREATE INDEX ' || table_name || '_by_wire_target_h_payto_index '
+    'ON ' || table_name || ' '
+    '(wire_target_h_payto);'
+  );
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_wireout_uuid_pkey'
+    ' PRIMARY KEY (wireout_uuid)'
+  );
+END
+$$;
+
+
+CREATE FUNCTION wire_out_delete_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  DELETE FROM exchange.aggregation_tracking
+   WHERE wtid_raw = OLD.wtid_raw;
+  RETURN OLD;
+END $$;
+COMMENT ON FUNCTION wire_out_delete_trigger()
+  IS 'Replicate reserve_out deletions into aggregation_tracking. This replaces 
an earlier use of an ON DELETE CASCADE that required a DEFERRABLE constraint 
and conflicted with nice partitioning.';
+
+
+CREATE FUNCTION master_table_wire_out()
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  CREATE TRIGGER wire_out_on_delete
+    AFTER DELETE
+      ON wire_out
+     FOR EACH ROW EXECUTE FUNCTION wire_out_delete_trigger();
+END $$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wire_out'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wire_out'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('wire_out'
+    ,'exchange-0002'
+    ,'master'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-wire_targets.sql 
b/src/exchangedb/0002-wire_targets.sql
new file mode 100644
index 00000000..5e542108
--- /dev/null
+++ b/src/exchangedb/0002-wire_targets.sql
@@ -0,0 +1,89 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE FUNCTION create_table_wire_targets(
+  IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  PERFORM create_partitioned_table(
+    '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'
+    ') %s ;'
+    ,'wire_targets'
+    ,'PARTITION BY HASH (wire_target_h_payto)'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_table(
+     'All senders and recipients of money via the exchange'
+    ,'wire_targets'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Can be a regular bank account, or also be a URI identifying a 
reserve-account (for P2P payments)'
+    ,'payto_uri'
+    ,'wire_targets'
+    ,partition_suffix
+  );
+  PERFORM comment_partitioned_column(
+     'Unsalted hash of payto_uri'
+    ,'wire_target_h_payto'
+    ,'wire_targets'
+    ,partition_suffix
+  );
+END $$;
+
+
+CREATE FUNCTION constrain_table_wire_targets(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+DECLARE
+  table_name VARCHAR DEFAULT 'wire_targets';
+BEGIN
+  table_name = concat_ws('_', table_name, partition_suffix);
+  EXECUTE FORMAT (
+    'ALTER TABLE ' || table_name ||
+    ' ADD CONSTRAINT ' || table_name || '_wire_target_serial_id_key'
+    ' UNIQUE (wire_target_serial_id)'
+  );
+END
+$$;
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('wire_targets'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('wire_targets'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/0002-work_shards.sql 
b/src/exchangedb/0002-work_shards.sql
new file mode 100644
index 00000000..fbe7e708
--- /dev/null
+++ b/src/exchangedb/0002-work_shards.sql
@@ -0,0 +1,46 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE TABLE work_shards
+  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
+  ,last_attempt INT8 NOT NULL
+  ,start_row INT8 NOT NULL
+  ,end_row INT8 NOT NULL
+  ,completed BOOLEAN NOT NULL DEFAULT FALSE
+  ,job_name VARCHAR NOT NULL
+  ,PRIMARY KEY (job_name, start_row)
+  );
+COMMENT ON TABLE work_shards
+  IS 'coordinates work between multiple processes working on the same job';
+COMMENT ON COLUMN work_shards.shard_serial_id
+  IS 'unique serial number identifying the shard';
+COMMENT ON COLUMN work_shards.last_attempt
+  IS 'last time a worker attempted to work on the shard';
+COMMENT ON COLUMN work_shards.completed
+  IS 'set to TRUE once the shard is finished by a worker';
+COMMENT ON COLUMN work_shards.start_row
+  IS 'row at which the shard scope starts, inclusive';
+COMMENT ON COLUMN work_shards.end_row
+  IS 'row at which the shard scope ends, exclusive';
+COMMENT ON COLUMN work_shards.job_name
+  IS 'unique name of the job the workers on this shard are performing';
+
+CREATE INDEX work_shards_by_job_name_completed_last_attempt_index
+  ON work_shards
+  (job_name
+  ,completed
+  ,last_attempt ASC
+  );
diff --git a/src/exchangedb/0003-purse_actions.sql 
b/src/exchangedb/0003-purse_actions.sql
new file mode 100644
index 00000000..c77dfb3c
--- /dev/null
+++ b/src/exchangedb/0003-purse_actions.sql
@@ -0,0 +1,74 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+
+CREATE TABLE IF NOT EXISTS purse_actions
+  (purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32)
+  ,action_date INT8 NOT NULL
+  ,partner_serial_id INT8
+  );
+COMMENT ON TABLE purse_actions
+  IS 'purses awaiting some action by the router';
+COMMENT ON COLUMN purse_actions.purse_pub
+  IS 'public (contract) key of the purse';
+COMMENT ON COLUMN purse_actions.action_date
+  IS 'when is the purse ready for action';
+COMMENT ON COLUMN purse_actions.partner_serial_id
+  IS 'wad target of an outgoing wire transfer, 0 for local, NULL if the purse 
is unmerged and thus the target is still unknown';
+
+CREATE INDEX IF NOT EXISTS purse_action_by_target
+  ON purse_actions
+  (partner_serial_id,action_date);
+
+
+CREATE OR REPLACE FUNCTION purse_requests_insert_trigger()
+  RETURNS trigger
+  LANGUAGE plpgsql
+  AS $$
+BEGIN
+  INSERT INTO
+    purse_actions
+    (purse_pub
+    ,action_date)
+  VALUES
+    (NEW.purse_pub
+    ,NEW.purse_expiration);
+  RETURN NEW;
+END $$;
+COMMENT ON FUNCTION purse_requests_insert_trigger()
+  IS 'When a purse is created, insert it into the purse_action table to take 
action when the purse expires.';
+
+CREATE TRIGGER purse_requests_on_insert
+  AFTER INSERT
+   ON purse_requests
+   FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger();
+COMMENT ON TRIGGER purse_requests_on_insert
+        ON purse_requests
+  IS 'Here we install an entry for the purse expiration.';
+
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_actions'
+    ,'exchange-0002'
+    ,'create'
+    ,FALSE
+    ,FALSE);
diff --git a/src/exchangedb/0003-purse_deletion.sql 
b/src/exchangedb/0003-purse_deletion.sql
new file mode 100644
index 00000000..e655ee61
--- /dev/null
+++ b/src/exchangedb/0003-purse_deletion.sql
@@ -0,0 +1,94 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+CREATE OR REPLACE FUNCTION create_table_purse_deletion(
+  IN shard_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  PERFORM create_partitioned_table(
+    'CREATE TABLE IF NOT EXISTS %I'
+      '(purse_deletion_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE'
+      ',purse_sig BYTEA CHECK (LENGTH(purse_sig)=64)'
+      ',XXX VARCHAR NOT NULL'
+    ') %s ;'
+    ,'purse_deletion'
+    ,'PARTITION BY HASH (XXX)'
+    ,shard_suffix
+  );
+  COMMENT ON TABLE purse_deletion
+    IS 'signatures affirming explicit purse deletions';
+  COMMENT ON COLUMN purse_deletion.purse_sig
+    IS 'signature of type XXX';
+END
+$$;
+COMMENT ON FUNCTION create_table_purse_deletion
+  IS 'Creates the purse_deletion table';
+
+CREATE OR REPLACE FUNCTION constrain_table_purse_deletion(
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE purse_deletion_' || partition_suffix || ' '
+      'ADD CONSTRAINT purse_deletion_' || partition_suffix || '_XXX '
+        'UNIQUE (XXX)'
+  );
+END
+$$;
+
+CREATE OR REPLACE FUNCTION alter_create_was_deleted_table_purse_requests (
+  IN partition_suffix VARCHAR
+)
+RETURNS void
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  EXECUTE FORMAT (
+    'ALTER TABLE purse_requests_' || partition_suffix ||
+    ' ADD COLUMN'
+    ' was_deleted BOOLEAN NOT NULL DEFAULT(FALSE)'
+  );
+END
+$$;
+
+INSERT INTO exchange_tables
+    (name
+    ,version
+    ,action
+    ,partitioned
+    ,by_range)
+  VALUES
+    ('purse_deletion'
+    ,'exchange-0002'
+    ,'create'
+    ,TRUE
+    ,FALSE),
+    ('purse_deletion'
+    ,'exchange-0002'
+    ,'constrain'
+    ,TRUE
+    ,FALSE),
+    ('purse_requests'
+    ,'exchange-0002'
+    ,'alter_create_was_deleted'
+    ,TRUE
+    ,FALSE);
diff --git a/src/exchangedb/Makefile.am b/src/exchangedb/Makefile.am
index 043b438c..1d4ba1f5 100644
--- a/src/exchangedb/Makefile.am
+++ b/src/exchangedb/Makefile.am
@@ -15,55 +15,37 @@ pkgcfg_DATA = \
 sqldir = $(prefix)/share/taler/sql/exchange/
 
 sqlinputs = \
-  common-0001.sql \
-  exchange-0001.sql.in \
-  exchange-0001-part.sql \
-  shard-0001-part.sql \
-  shard-0001.sql.in \
-  common-0002.sql \
+  0002-*.sql \
+  0003-*.sql \
   exchange-0002.sql.in \
-  exchange-0002-part.sql \
-  shard-0002-part.sql \
-  shard-0002.sql.in
+  exchange-0003.sql.in
 
 sql_DATA = \
   benchmark-0001.sql \
   versioning.sql \
   exchange-0001.sql \
+  exchange-0002.sql \
   drop.sql \
-  procedures.sql \
-  shard-0001.sql
+  procedures.sql
 
 BUILT_SOURCES = \
-  shard-0001.sql \
-  exchange-0001.sql \
+  benchmark-0001.sql \
   drop.sql \
+  exchange-0001.sql \
   procedures.sql
 
 CLEANFILES = \
-  shard-0001.sql \
-  exchange-0001.sql \
-  shard-0002.sql \
-  exchange-0002.sql 
+  exchange-0002.sql \
+  exchange-0003.sql
 
-exchange-0001.sql: common-0001.sql exchange-0001-part.sql exchange-0001.sql.in
-       chmod +w $@ || true
-       gcc -E -P -undef - < exchange-0001.sql.in 2>/dev/null | sed -e 
"s/--.*//" | awk 'NF' - >$@
-       chmod ugo-w $@
-
-exchange-0002.sql: common-0002.sql exchange-0002-part.sql exchange-0002.sql.in
+exchange-0002.sql: exchange-0002.sql.in 0002-*.sql
        chmod +w $@ || true
        gcc -E -P -undef - < exchange-0002.sql.in 2>/dev/null | sed -e 
"s/--.*//" | awk 'NF' - >$@
        chmod ugo-w $@
 
-shard-0001.sql: common-0001.sql shard-0001-part.sql exchange-0001.sql.in
-       chmod +w $@ || true
-       gcc -E -P -undef - < shard-0001.sql.in 2>/dev/null | sed -e "s/--.*//" 
| awk 'NF' - >$@
-       chmod ugo-w $@
-
-shard-0002.sql: common-0002.sql shard-0002-part.sql exchange-0002.sql.in
+exchange-0003.sql: exchange-0003.sql.in 0003-*.sql
        chmod +w $@ || true
-       gcc -E -P -undef - < shard-0002.sql.in 2>/dev/null | sed -e "s/--.*//" 
| awk 'NF' - >$@
+       gcc -E -P -undef - < exchange-0003.sql.in 2>/dev/null | sed -e 
"s/--.*//" | awk 'NF' - >$@
        chmod ugo-w $@
 
 EXTRA_DIST = \
@@ -111,7 +93,6 @@ libtaler_plugin_exchangedb_postgres_la_SOURCES = \
   pg_select_contract_by_purse.h pg_select_contract_by_purse.c \
   pg_insert_drain_profit.h pg_insert_drain_profit.c \
   pg_create_tables.h pg_create_tables.c \
-  pg_setup_foreign_servers.h pg_setup_foreign_servers.c \
   pg_event_listen.h pg_event_listen.c \
   pg_event_listen_cancel.h pg_event_listen_cancel.c \
   pg_event_notify.h pg_event_notify.c \
@@ -225,7 +206,6 @@ libtaler_plugin_exchangedb_postgres_la_SOURCES = \
   pg_do_batch_withdraw_insert.h pg_do_batch_withdraw_insert.c \
   pg_do_reserve_open.c pg_do_reserve_open.h \
   pg_do_withdraw.h pg_do_withdraw.c \
-  pg_create_shard_tables.h pg_create_shard_tables.c \
   pg_preflight.h pg_preflight.c \
   pg_iterate_active_signkeys.h pg_iterate_active_signkeys.c \
   pg_commit.h pg_commit.c \
@@ -233,7 +213,6 @@ libtaler_plugin_exchangedb_postgres_la_SOURCES = \
   pg_get_expired_reserves.c pg_get_expired_reserves.h \
   pg_start.h pg_start.c \
   pg_rollback.h pg_rollback.c \
-  pg_setup_partitions.h pg_setup_partitions.c \
   pg_get_purse_request.c pg_get_purse_request.h \
   pg_get_reserve_history.c pg_get_reserve_history.h \
   pg_get_unfinished_close_requests.c pg_get_unfinished_close_requests.h \
diff --git a/src/exchangedb/common-0001.sql b/src/exchangedb/common-0001.sql
deleted file mode 100644
index a95d74d2..00000000
--- a/src/exchangedb/common-0001.sql
+++ /dev/null
@@ -1,3035 +0,0 @@
---
--- This file is part of TALER
--- Copyright (C) 2014--2022 Taler Systems SA
---
--- TALER is free software; you can redistribute it and/or modify it under the
--- terms of the GNU General Public License as published by the Free Software
--- Foundation; either version 3, or (at your option) any later version.
---
--- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
--- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
--- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
---
--- You should have received a copy of the GNU General Public License along with
--- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
---
-
--------------------- Tables ----------------------------
-
-CREATE OR REPLACE 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
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  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
-$$;
-
------------------------ wire_targets ---------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wire_targets(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(wire_target_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE'
-      ',wire_target_h_payto BYTEA PRIMARY KEY CHECK 
(LENGTH(wire_target_h_payto)=32)'
-      ',payto_uri VARCHAR NOT NULL'
-    ') %s ;'
-    ,'wire_targets'
-    ,'PARTITION BY HASH (wire_target_h_payto)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
--- We need a separate function for this, as we call create_table only once but 
need to add
--- those constraints to each partition which gets created
-CREATE OR REPLACE FUNCTION add_constraints_to_wire_targets_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  EXECUTE FORMAT (
-    'ALTER TABLE wire_targets_' || partition_suffix || ' '
-      'ADD CONSTRAINT wire_targets_' || partition_suffix || 
'_wire_target_serial_id_key '
-        'UNIQUE (wire_target_serial_id)'
-  );
-END
-$$;
-
-
------------------------ legitimization_processes ---------------------------
-
-CREATE OR REPLACE FUNCTION create_table_legitimization_processes(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(legitimization_process_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY' -- UNIQUE'
-      ',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
-      ',expiration_time INT8 NOT NULL DEFAULT (0)'
-      ',provider_section VARCHAR NOT NULL'
-      ',provider_user_id VARCHAR DEFAULT NULL'
-      ',provider_legitimization_id VARCHAR DEFAULT NULL'
-      ',UNIQUE (h_payto, provider_section)'
-    ') %s ;'
-    ,'legitimization_processes'
-    ,'PARTITION BY HASH (h_payto)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
--- We need a separate function for this, as we call create_table only once but 
need to add
--- those constraints to each partition which gets created
-CREATE OR REPLACE FUNCTION 
add_constraints_to_legitimization_processes_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  partition_name VARCHAR;
-BEGIN
-
-  partition_name = concat_ws('_', 'legitimization_processes', 
partition_suffix);
-
-  EXECUTE FORMAT (
-    'ALTER TABLE ' || partition_name
-    || ' '
-      'ADD CONSTRAINT ' || partition_name || '_serial_key '
-        'UNIQUE (legitimization_process_serial_id)');
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || partition_name || 
'_by_provider_and_legi_index '
-        'ON '|| partition_name || ' '
-        '(provider_section,provider_legitimization_id)'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || partition_name || '_by_provider_and_legi_index '
-    'IS ' || quote_literal('used (rarely) in kyc_provider_account_lookup') || 
';'
-  );
-END
-$$;
-
-
------------------------ legitimization_requirements ---------------------------
-
-CREATE OR REPLACE FUNCTION create_table_legitimization_requirements(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(legitimization_requirement_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY' -- UNIQUE'
-      ',h_payto BYTEA NOT NULL CHECK (LENGTH(h_payto)=32)'
-      ',required_checks VARCHAR NOT NULL'
-      ',UNIQUE (h_payto, required_checks)'
-    ') %s ;'
-    ,'legitimization_requirements'
-    ,'PARTITION BY HASH (h_payto)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
--- We need a separate function for this, as we call create_table only once but 
need to add
--- those constraints to each partition which gets created
-CREATE OR REPLACE FUNCTION 
add_constraints_to_legitimization_requirements_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  partition_name VARCHAR;
-BEGIN
-
-  partition_name = concat_ws('_', 'legitimization_requirements', 
partition_suffix);
-
-  EXECUTE FORMAT (
-    'ALTER TABLE ' || partition_name
-    || ' '
-      'ADD CONSTRAINT ' || partition_name || '_serial_id_key '
-        'UNIQUE (legitimization_requirement_serial_id)');
-END
-$$;
-
-
------------------------- reserves -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'reserves';
-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)'
-      ',current_balance_val INT8 NOT NULL DEFAULT(0)'
-      ',current_balance_frac INT4 NOT NULL DEFAULT(0)'
-      ',purses_active INT8 NOT NULL DEFAULT(0)'
-      ',purses_allowed INT8 NOT NULL DEFAULT(0)'
-      ',max_age INT4 NOT NULL DEFAULT(120)'
-      ',expiration_date INT8 NOT NULL'
-      ',gc_date INT8 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_expiration_index '
-    'ON ' || table_name || ' '
-    '(expiration_date'
-    ',current_balance_val'
-    ',current_balance_frac'
-    ');'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_by_expiration_index '
-    'IS ' || quote_literal('used in get_expired_reserves') || ';'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_reserve_uuid_index '
-    'ON ' || table_name || ' '
-    '(reserve_uuid);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_gc_date_index '
-    'ON ' || table_name || ' '
-    '(gc_date);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_by_gc_date_index '
-    'IS ' || quote_literal('for reserve garbage collection') || ';'
-  );
-
-END
-$$;
-
------------------------ reserves_in ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves_in(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'reserves_in';
-BEGIN
-
-  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'
-      ',wire_reference INT8 NOT NULL'
-      ',credit_val INT8 NOT NULL'
-      ',credit_frac INT4 NOT NULL'
-      ',wire_source_h_payto BYTEA CHECK (LENGTH(wire_source_h_payto)=32)'
-      ',exchange_account_section TEXT NOT NULL'
-      ',execution_date INT8 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_reserve_in_serial_id_index '
-    'ON ' || table_name || ' '
-    '(reserve_in_serial_id);'
-  );
-  -- FIXME: where do we need this index? Can we do better?
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_exch_accnt_section_execution_date_idx '
-    'ON ' || table_name || ' '
-    '(exchange_account_section '
-    ',execution_date'
-    ');'
-  );
-  -- FIXME: where do we need this index? Can we do better?
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_exch_accnt_reserve_in_serial_id_idx '
-    'ON ' || table_name || ' '
-    '(exchange_account_section,'
-    'reserve_in_serial_id DESC'
-    ');'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_reserves_in_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE reserves_in_' || partition_suffix || ' '
-      'ADD CONSTRAINT reserves_in_' || partition_suffix || 
'_reserve_in_serial_id_key '
-        'UNIQUE (reserve_in_serial_id)'
-  );
-END
-$$;
-
---------------------------- reserves_close -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves_close(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'reserves_close';
-BEGIN
-
-  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'
-      ',execution_date INT8 NOT NULL'
-      ',wtid BYTEA NOT NULL CHECK (LENGTH(wtid)=32)'
-      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
-      ',amount_val INT8 NOT NULL'
-      ',amount_frac INT4 NOT NULL'
-      ',closing_fee_val INT8 NOT NULL'
-      ',closing_fee_frac INT4 NOT NULL'
-      ',close_request_row INT8 NOT NULL DEFAULT(0)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_close_uuid_index '
-    'ON ' || table_name || ' '
-    '(close_uuid);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_reserve_pub_index '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_reserves_close_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE reserves_close_' || partition_suffix || ' '
-      'ADD CONSTRAINT reserves_close_' || partition_suffix || 
'_close_uuid_pkey '
-        'PRIMARY KEY (close_uuid)'
-  );
-END
-$$;
-
-
---------------------------- close_requests ---------------------------
-
-CREATE OR REPLACE FUNCTION create_table_close_requests(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'close_requests';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(close_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE'
-      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)' -- 
REFERENCES reserves(reserve_pub) ON DELETE CASCADE
-      ',close_timestamp INT8 NOT NULL'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',close_val INT8 NOT NULL'
-      ',close_frac INT4 NOT NULL'
-      ',close_fee_val INT8 NOT NULL'
-      ',close_fee_frac INT4 NOT NULL'
-      ',payto_uri VARCHAR NOT NULL'
-      ',done BOOL NOT NULL DEFAULT(FALSE)'
-      ',PRIMARY KEY (reserve_pub,close_timestamp)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION add_constraints_to_close_requests(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'close_requests';
-BEGIN
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_close_request_uuid_index '
-    'ON ' || table_name || ' '
-    '(close_request_serial_id);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_close_request_done_index '
-    'ON ' || table_name || ' '
-    '(done);'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_close_requests_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE close_requests_' || partition_suffix || ' '
-      'ADD CONSTRAINT close_requests_' || partition_suffix || 
'_close_request_uuid_pkey '
-        'UNIQUE (close_request_serial_id)'
-  );
-END
-$$;
-
-
---------------------------- reserves_open_requests 
-------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves_open_requests(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'reserves_open_requests';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(open_request_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE / 
PRIMARY KEY'
-      ',reserve_pub BYTEA NOT NULL' -- REFERENCES reserves (reserve_pub) ON 
DELETE CASCADE'
-      ',request_timestamp INT8 NOT NULL'
-      ',expiration_date INT8 NOT NULL'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',reserve_payment_val INT8 NOT NULL'
-      ',reserve_payment_frac INT4 NOT NULL'
-      ',requested_purse_limit INT4 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_reserve_open_uuid_index '
-    'ON ' || table_name || ' '
-    '(open_request_uuid);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_reserve_pub_index '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_reserves_open_request_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE reserves_open_requests_' || partition_suffix || ' '
-      'ADD CONSTRAINT reserves_open_requests_' || partition_suffix || 
'_by_uuid '
-        'PRIMARY KEY (open_request_uuid),'
-      'ADD CONSTRAINT reserves_open_requests_' || partition_suffix || 
'_by_time '
-        'UNIQUE (reserve_pub,request_timestamp)'
-  );
-END
-$$;
-
-
---------------------------- reserves_open_deposits 
-------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves_open_deposits(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'reserves_open_deposits';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(reserve_open_deposit_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE / PRIMARY KEY'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)'
-      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
-      ',coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)'
-      ',contribution_val INT8 NOT NULL'
-      ',contribution_frac INT4 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (coin_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_uuid '
-    'ON ' || table_name || ' '
-    '(reserve_open_deposit_uuid);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_reserve '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_reserves_open_deposits_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE reserves_open_deposits_' || partition_suffix || ' '
-      'ADD CONSTRAINT reserves_open_deposits_' || partition_suffix || 
'_coin_unique '
-        'PRIMARY KEY (coin_pub,coin_sig)'
-  );
-END
-$$;
-
-
----------------------------- reserves_out -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_reserves_out(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'reserves_out';
-BEGIN
-
-  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'
-      ',denominations_serial INT8 NOT NULL' -- REFERENCES denominations 
(denominations_serial)'
-      ',denom_sig BYTEA NOT NULL'
-      ',reserve_uuid INT8 NOT NULL' -- REFERENCES reserves (reserve_uuid) ON 
DELETE CASCADE'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',execution_date INT8 NOT NULL'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-    ') %s ;'
-    ,'reserves_out'
-    ,'PARTITION BY HASH (h_blind_ev)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_reserve_out_serial_id_index '
-    'ON ' || table_name || ' '
-    '(reserve_out_serial_id);'
-  );
-  -- FIXME: change query to use reserves_out_by_reserve instead and 
materialize execution_date there as well???
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_reserve_uuid_and_execution_date_index '
-    'ON ' || table_name || ' '
-    '(reserve_uuid, execution_date);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || 
'_by_reserve_uuid_and_execution_date_index '
-    'IS ' || quote_literal('for get_reserves_out and 
exchange_do_withdraw_limit_check') || ';'
-  );
-
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION add_constraints_to_reserves_out_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE reserves_out_' || partition_suffix || ' '
-      'ADD CONSTRAINT reserves_out_' || partition_suffix || 
'_reserve_out_serial_id_key '
-        'UNIQUE (reserve_out_serial_id)'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION create_table_reserves_out_by_reserve(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'reserves_out_by_reserve';
-BEGIN
-
-  PERFORM create_partitioned_table(
-  'CREATE TABLE IF NOT EXISTS %I'
-    '(reserve_uuid INT8 NOT NULL' -- REFERENCES reserves (reserve_uuid) ON 
DELETE CASCADE
-    ',h_blind_ev BYTEA CHECK (LENGTH(h_blind_ev)=64)'
-    ') %s '
-    ,table_name
-    ,'PARTITION BY HASH (reserve_uuid)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_main_index '
-    'ON ' || table_name || ' '
-    '(reserve_uuid);'
-  );
-
-END
-$$;
-
----------------------------- known_coins -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_known_coins(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR default 'known_coins';
-BEGIN
-
-  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'
-      ',coin_pub BYTEA NOT NULL PRIMARY KEY CHECK (LENGTH(coin_pub)=32)'
-      ',age_commitment_hash BYTEA CHECK (LENGTH(age_commitment_hash)=32)'
-      ',denom_sig BYTEA NOT NULL'
-      ',remaining_val INT8 NOT NULL DEFAULT(0)'
-      ',remaining_frac INT4 NOT NULL DEFAULT(0)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (coin_pub)' -- FIXME: or include denominations_serial? 
or multi-level partitioning?;
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_known_coins_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE known_coins_' || partition_suffix || ' '
-      'ADD CONSTRAINT known_coins_' || partition_suffix || '_known_coin_id_key 
'
-        'UNIQUE (known_coin_id)'
-  );
-END
-$$;
-
----------------------------- refresh_commitments 
-------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_refresh_commitments(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'refresh_commitments';
-BEGIN
-
-  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)'
-      ',old_coin_pub BYTEA NOT NULL' -- REFERENCES known_coins (coin_pub) ON 
DELETE CASCADE'
-      ',old_coin_sig BYTEA NOT NULL CHECK(LENGTH(old_coin_sig)=64)'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',noreveal_index INT4 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (rc)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  -- Note: index spans partitions, may need to be materialized.
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_old_coin_pub_index '
-    'ON ' || table_name || ' '
-    '(old_coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_refresh_commitments_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE refresh_commitments_' || partition_suffix || ' '
-      'ADD CONSTRAINT refresh_commitments_' || partition_suffix || 
'_melt_serial_id_key '
-        'UNIQUE (melt_serial_id)'
-  );
-END
-$$;
-
------------------------------- refresh_revealed_coins 
--------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_refresh_revealed_coins(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'refresh_revealed_coins';
-BEGIN
-
-  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'
-      ',freshcoin_index INT4 NOT NULL'
-      ',link_sig BYTEA NOT NULL CHECK(LENGTH(link_sig)=64)'
-      ',denominations_serial INT8 NOT NULL' -- REFERENCES denominations 
(denominations_serial) ON DELETE CASCADE'
-      ',coin_ev BYTEA NOT NULL' -- UNIQUE'
-      ',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 BY HASH (melt_serial_id)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_coins_by_melt_serial_id_index '
-    'ON ' || table_name || ' '
-    '(melt_serial_id);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_refresh_revealed_coins_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE refresh_revealed_coins_' || partition_suffix || ' '
-      'ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || 
'_rrc_serial_key '
-        'UNIQUE (rrc_serial) '
-      ',ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || 
'_coin_ev_key '
-        'UNIQUE (coin_ev) '
-      ',ADD CONSTRAINT refresh_revealed_coins_' || partition_suffix || 
'_h_coin_ev_key '
-        'UNIQUE (h_coin_ev) '
-      ',ADD PRIMARY KEY (melt_serial_id, freshcoin_index) '
-  );
-END
-$$;
-
------------------------------ refresh_transfer_keys 
------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_refresh_transfer_keys(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'refresh_transfer_keys';
-BEGIN
-
-  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 BY HASH (melt_serial_id)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_refresh_transfer_keys_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE refresh_transfer_keys_' || partition_suffix || ' '
-      'ADD CONSTRAINT refresh_transfer_keys_' || partition_suffix || 
'_rtc_serial_key '
-        'UNIQUE (rtc_serial)'
-  );
-END
-$$;
-
----------------------------- deposits -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_deposits(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'deposits';
-BEGIN
-
-  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'
-      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub) ON DELETE CASCADE
-      ',known_coin_id INT8 NOT NULL' -- REFERENCES known_coins (known_coin_id) 
ON DELETE CASCADE' --- FIXME: column needed???
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',wallet_timestamp INT8 NOT NULL'
-      ',exchange_timestamp INT8 NOT NULL'
-      ',refund_deadline INT8 NOT NULL'
-      ',wire_deadline INT8 NOT NULL'
-      ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)'
-      ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)'
-      ',coin_sig BYTEA NOT NULL CHECK (LENGTH(coin_sig)=64)'
-      ',wire_salt BYTEA NOT NULL CHECK (LENGTH(wire_salt)=16)'
-      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
-      ',done BOOLEAN NOT NULL DEFAULT FALSE'
-      ',policy_blocked BOOLEAN NOT NULL DEFAULT FALSE'
-      ',policy_details_serial_id INT8' -- REFERENCES policy_details 
(policy_details_serial_id) ON DELETE CASCADE'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (coin_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub_index '
-    'ON ' || table_name || ' '
-    '(coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_deposits_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE deposits_' || partition_suffix || ' '
-      'ADD CONSTRAINT deposits_' || partition_suffix || 
'_deposit_serial_id_pkey '
-        'PRIMARY KEY (deposit_serial_id) '
-      ',ADD CONSTRAINT deposits_' || partition_suffix || 
'_coin_pub_merchant_pub_h_contract_terms_key '
-        'UNIQUE (coin_pub, merchant_pub, h_contract_terms)'
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION create_table_deposits_by_ready(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'deposits_by_ready';
-BEGIN
-
-  PERFORM create_partitioned_table(
-  'CREATE TABLE IF NOT EXISTS %I'
-    '(wire_deadline INT8 NOT NULL'
-    ',shard INT8 NOT NULL'
-    ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)'
-    ',deposit_serial_id INT8'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY RANGE (wire_deadline)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_main_index '
-    'ON ' || table_name || ' '
-    '(wire_deadline ASC, shard ASC, coin_pub);'
-  );
-
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION create_table_deposits_for_matching(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'deposits_for_matching';
-BEGIN
-
-  PERFORM create_partitioned_table(
-  'CREATE TABLE IF NOT EXISTS %I'
-    '(refund_deadline INT8 NOT NULL'
-    ',merchant_pub BYTEA NOT NULL CHECK (LENGTH(merchant_pub)=32)'
-    ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub) ON DELETE CASCADE
-    ',deposit_serial_id INT8'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY RANGE (refund_deadline)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_main_index '
-    'ON ' || table_name || ' '
-    '(refund_deadline ASC, merchant_pub, coin_pub);'
-  );
-
-END
-$$;
-
------------------------------ refunds ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_refunds(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'refunds';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(refund_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
-      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub) ON DELETE CASCADE
-      ',deposit_serial_id INT8 NOT NULL' -- REFERENCES deposits 
(deposit_serial_id) ON DELETE CASCADE'
-      ',merchant_sig BYTEA NOT NULL CHECK(LENGTH(merchant_sig)=64)'
-      ',rtransaction_id INT8 NOT NULL'
-      ',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 BY HASH (coin_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub_index '
-    'ON ' || table_name || ' '
-    '(coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_refunds_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE refunds_' || partition_suffix || ' '
-      'ADD CONSTRAINT refunds_' || partition_suffix || '_refund_serial_id_key '
-        'UNIQUE (refund_serial_id) '
-      ',ADD PRIMARY KEY (deposit_serial_id, rtransaction_id) '
-  );
-END
-$$;
-
----------------------------- wire_out -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wire_out(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'wire_out';
-BEGIN
-
-  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'
-      ',wtid_raw BYTEA UNIQUE NOT NULL CHECK (LENGTH(wtid_raw)=32)'
-      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
-      ',exchange_account_section TEXT NOT NULL'
-      ',amount_val INT8 NOT NULL'
-      ',amount_frac INT4 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (wtid_raw)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || 
'_by_wire_target_h_payto_index '
-    'ON ' || table_name || ' '
-    '(wire_target_h_payto);'
-  );
-
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_wire_out_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE wire_out_' || partition_suffix || ' '
-      'ADD CONSTRAINT wire_out_' || partition_suffix || '_wireout_uuid_pkey '
-        'PRIMARY KEY (wireout_uuid)'
-  );
-END
-$$;
-
----------------------------- aggregation_transient 
------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_aggregation_transient(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'aggregation_transient';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(amount_val INT8 NOT NULL'
-      ',amount_frac INT4 NOT NULL'
-      ',wire_target_h_payto BYTEA CHECK (LENGTH(wire_target_h_payto)=32)'
-      ',merchant_pub BYTEA CHECK (LENGTH(merchant_pub)=32)'
-      ',exchange_account_section TEXT NOT NULL'
-      ',legitimization_requirement_serial_id INT8 NOT NULL DEFAULT(0)'
-      ',wtid_raw BYTEA NOT NULL CHECK (LENGTH(wtid_raw)=32)'
-      ') %s ;'
-      ,table_name
-      ,'PARTITION BY HASH (wire_target_h_payto)'
-      ,shard_suffix
-  );
-
-END
-$$;
-
----------------------------- aggregation_tracking 
-------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_aggregation_tracking(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'aggregation_tracking';
-BEGIN
-
-  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' -- FIXME change to coin_pub + 
deposit_serial_id for more efficient depost -- or something else ???
-      ',wtid_raw BYTEA NOT NULL' -- CONSTRAINT wire_out_ref REFERENCES 
wire_out(wtid_raw) ON DELETE CASCADE DEFERRABLE'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (deposit_serial_id)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_wtid_raw_index '
-    'ON ' || table_name || ' '
-    '(wtid_raw);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_by_wtid_raw_index '
-    'IS ' || quote_literal('for lookup_transactions') || ';'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_aggregation_tracking_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE aggregation_tracking_' || partition_suffix || ' '
-      'ADD CONSTRAINT aggregation_tracking_' || partition_suffix || 
'_aggregation_serial_id_key '
-        'UNIQUE (aggregation_serial_id) '
-  );
-END
-$$;
-
------------------------------ recoup ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_recoup(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'recoup';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(recoup_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
-      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub)
-      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
-      ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)'
-      ',amount_val INT8 NOT NULL'
-      ',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 BY HASH (coin_pub);'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub_index '
-    'ON ' || table_name || ' '
-    '(coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_recoup_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE recoup_' || partition_suffix || ' '
-      'ADD CONSTRAINT recoup_' || partition_suffix || '_recoup_uuid_key '
-        'UNIQUE (recoup_uuid) '
-  );
-END
-$$;
-
-CREATE OR REPLACE FUNCTION create_table_recoup_by_reserve(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'recoup_by_reserve';
-BEGIN
-
-  PERFORM create_partitioned_table(
-  'CREATE TABLE IF NOT EXISTS %I'
-    '(reserve_out_serial_id INT8 NOT NULL' -- REFERENCES reserves 
(reserve_out_serial_id) ON DELETE CASCADE
-    ',coin_pub BYTEA CHECK (LENGTH(coin_pub)=32)' -- REFERENCES known_coins 
(coin_pub)
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_out_serial_id)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_main_index '
-    'ON ' || table_name || ' '
-    '(reserve_out_serial_id);'
-  );
-
-END
-$$;
-
----------------------------- recoup_refresh ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_recoup_refresh(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'recoup_refresh';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(recoup_refresh_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY' -- UNIQUE'
-      ',coin_pub BYTEA NOT NULL CHECK (LENGTH(coin_pub)=32)' -- REFERENCES 
known_coins (coin_pub)
-      ',known_coin_id BIGINT NOT NULL' -- REFERENCES known_coins 
(known_coin_id) ON DELETE CASCADE
-      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
-      ',coin_blind BYTEA NOT NULL CHECK(LENGTH(coin_blind)=32)'
-      ',amount_val INT8 NOT NULL'
-      ',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 BY HASH (coin_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  -- FIXME: any query using this index will be slow. Materialize index or 
change query?
-  -- Also: which query uses this index?
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_rrc_serial_index '
-    'ON ' || table_name || ' '
-    '(rrc_serial);'
-  );
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub_index '
-    'ON ' || table_name || ' '
-    '(coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_recoup_refresh_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE recoup_refresh_' || partition_suffix || ' '
-      'ADD CONSTRAINT recoup_refresh_' || partition_suffix || 
'_recoup_refresh_uuid_key '
-        'UNIQUE (recoup_refresh_uuid) '
-  );
-END
-$$;
-
------------------------------ prewire ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_prewire(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'prewire';
-BEGIN
-
-  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 BY HASH (prewire_uuid)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_finished_index '
-    'ON ' || table_name || ' '
-    '(finished);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_by_finished_index '
-    'IS ' || quote_literal('for gc_prewire') || ';'
-  );
-  -- FIXME: find a way to combine these two indices?
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_failed_finished_index '
-    'ON ' || table_name || ' '
-    '(failed,finished);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_by_failed_finished_index '
-    'IS ' || quote_literal('for wire_prepare_data_get') || ';'
-  );
-
-END
-$$;
-
------------------------------ cs_nonce_locks ------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_cs_nonce_locks(
-  shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(cs_nonce_lock_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE'
-      ',nonce BYTEA PRIMARY KEY CHECK (LENGTH(nonce)=32)'
-      ',op_hash BYTEA NOT NULL CHECK (LENGTH(op_hash)=64)'
-      ',max_denomination_serial INT8 NOT NULL'
-    ') %s ;'
-    ,'cs_nonce_locks'
-    ,'PARTITION BY HASH (nonce)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_cs_nonce_locks_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE cs_nonce_locks_' || partition_suffix || ' '
-      'ADD CONSTRAINT cs_nonce_locks_' || partition_suffix || 
'_cs_nonce_lock_serial_id_key '
-        'UNIQUE (cs_nonce_lock_serial_id)'
-  );
-END
-$$;
-
---------------------------------------------------------------------------
---                        Tables for P2P payments
---------------------------------------------------------------------------
-
-------------------------------- purse_requests 
----------------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_purse_requests(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'purse_requests';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(purse_requests_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE
-      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
-      ',merge_pub BYTEA NOT NULL CHECK (LENGTH(merge_pub)=32)'
-      ',purse_creation INT8 NOT NULL'
-      ',purse_expiration INT8 NOT NULL'
-      ',h_contract_terms BYTEA NOT NULL CHECK (LENGTH(h_contract_terms)=64)'
-      ',age_limit INT4 NOT NULL'
-      ',flags INT4 NOT NULL'
-      ',in_reserve_quota BOOLEAN NOT NULL DEFAULT(FALSE)'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',purse_fee_val INT8 NOT NULL'
-      ',purse_fee_frac INT4 NOT NULL'
-      ',balance_val INT8 NOT NULL DEFAULT (0)'
-      ',balance_frac INT4 NOT NULL DEFAULT (0)'
-      ',purse_sig BYTEA NOT NULL CHECK(LENGTH(purse_sig)=64)'
-      ',PRIMARY KEY (purse_pub)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  -- FIXME: change to materialized index by merge_pub!
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_merge_pub '
-    'ON ' || table_name || ' '
-    '(merge_pub);'
-  );
-
-  -- FIXME: drop index on master (crosses shards)?
-  -- Or use materialized index? (needed?)
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_purse_expiration '
-    'ON ' || table_name || ' '
-    '(purse_expiration);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_purse_requests_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE purse_requests_' || partition_suffix || ' '
-      'ADD CONSTRAINT purse_requests_' || partition_suffix || 
'_purse_requests_serial_id_key '
-        'UNIQUE (purse_requests_serial_id) '
-  );
-END
-$$;
-
-
----------------------------- purse_merges -----------------------------
-
-CREATE OR REPLACE FUNCTION create_table_purse_merges(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-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)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  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 '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_reserve_pub '
-    'IS ' || quote_literal('needed in reserve history computation') || ';'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_purse_merges_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-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) '
-  );
-END
-$$;
-
-------------------------- account_merges ----------------------------
-
-CREATE OR REPLACE FUNCTION create_table_account_merges(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'account_merges';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(account_merge_request_serial_id BIGINT GENERATED BY DEFAULT AS 
IDENTITY' -- UNIQUE
-      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)' -- 
REFERENCES reserves (reserve_pub) ON DELETE CASCADE
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)' -- REFERENCES 
purse_requests (purse_pub)
-      ',wallet_h_payto BYTEA NOT NULL CHECK (LENGTH(wallet_h_payto)=32)'
-      ',PRIMARY KEY (purse_pub)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  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 || '_by_reserve_pub '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_account_merges_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE account_merges_' || partition_suffix || ' '
-      'ADD CONSTRAINT account_merges_' || partition_suffix || 
'_account_merge_request_serial_id_key '
-        'UNIQUE (account_merge_request_serial_id) '
-  );
-END
-$$;
-
-
-------------------------------- purse_decision 
----------------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_purse_decision(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'purse_decision';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(purse_decision_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE
-      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
-      ',action_timestamp INT8 NOT NULL'
-      ',refunded BOOL NOT NULL'
-      ',PRIMARY KEY (purse_pub)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_purse_decision_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE purse_decision_' || partition_suffix || ' '
-      'ADD CONSTRAINT purse_decision_' || partition_suffix || 
'_purse_action_serial_id_key '
-        'UNIQUE (purse_decision_serial_id) '
-  );
-END
-$$;
-
-
-------------------------- contracts -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_contracts(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'contracts';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(contract_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' --UNIQUE
-      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
-      ',pub_ckey BYTEA NOT NULL CHECK (LENGTH(pub_ckey)=32)'
-      ',contract_sig BYTEA NOT NULL CHECK (LENGTH(contract_sig)=64)'
-      ',e_contract BYTEA NOT NULL'
-      ',purse_expiration INT8 NOT NULL'
-      ',PRIMARY KEY (purse_pub)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_contracts_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE contracts_' || partition_suffix || ' '
-      'ADD CONSTRAINT contracts_' || partition_suffix || 
'_contract_serial_id_key '
-        'UNIQUE (contract_serial_id) '
-  );
-END
-$$;
-
---------------------------- history_requests --------------------------
-
-
-CREATE OR REPLACE FUNCTION create_table_history_requests(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'history_requests';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(history_request_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE'
-      ',reserve_pub BYTEA NOT NULL CHECK (LENGTH(reserve_pub)=32)' -- 
REFERENCES reserves(reserve_pub) ON DELETE CASCADE
-      ',request_timestamp INT8 NOT NULL'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',history_fee_val INT8 NOT NULL'
-      ',history_fee_frac INT4 NOT NULL'
-      ',PRIMARY KEY (reserve_pub,request_timestamp)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (reserve_pub)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-------------------------------- purse_deposits -------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_purse_deposits(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'purse_deposits';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(purse_deposit_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE
-      ',partner_serial_id INT8' -- REFERENCES partners(partner_serial_id) ON 
DELETE CASCADE'
-      ',purse_pub BYTEA NOT NULL CHECK (LENGTH(purse_pub)=32)'
-      ',coin_pub BYTEA NOT NULL' -- REFERENCES known_coins (coin_pub) ON 
DELETE CASCADE'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',coin_sig BYTEA NOT NULL CHECK(LENGTH(coin_sig)=64)'
-      ',PRIMARY KEY (purse_pub,coin_pub)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  table_name = concat_ws('_', table_name, shard_suffix);
-
-  -- FIXME: change to materialized index by coin_pub!
-  EXECUTE FORMAT (
-    'CREATE INDEX IF NOT EXISTS ' || table_name || '_by_coin_pub '
-    'ON ' || table_name || ' '
-    '(coin_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_purse_deposits_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE purse_deposits_' || partition_suffix || ' '
-      'ADD CONSTRAINT purse_deposits_' || partition_suffix || 
'_purse_deposit_serial_id_key '
-        'UNIQUE (purse_deposit_serial_id) '
-  );
-END
-$$;
-
----------------------------- wads_out -------------------------------
-CREATE OR REPLACE FUNCTION create_table_wads_out(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'wads_out';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(wad_out_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' --UNIQUE
-      ',wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)'
-      ',partner_serial_id INT8 NOT NULL' -- REFERENCES 
partners(partner_serial_id) ON DELETE CASCADE
-      ',amount_val INT8 NOT NULL'
-      ',amount_frac INT4 NOT NULL'
-      ',execution_time INT8 NOT NULL'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (wad_id)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_wads_out_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE wads_out_' || partition_suffix || ' '
-      'ADD CONSTRAINT wads_out_' || partition_suffix || 
'_wad_out_serial_id_key '
-        'UNIQUE (wad_out_serial_id) '
-  );
-END
-$$;
-
---------------------------- wad_out_entries --------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wad_out_entries(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'wad_out_entries';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(wad_out_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE
-      ',wad_out_serial_id INT8' -- REFERENCES wads_out (wad_out_serial_id) ON 
DELETE CASCADE
-      ',reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)'
-      ',purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)'
-      ',h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)'
-      ',purse_expiration INT8 NOT NULL'
-      ',merge_timestamp INT8 NOT NULL'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',wad_fee_val INT8 NOT NULL'
-      ',wad_fee_frac INT4 NOT NULL'
-      ',deposit_fees_val INT8 NOT NULL'
-      ',deposit_fees_frac INT4 NOT NULL'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  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 || '_by_reserve_pub '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_wad_out_entries_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE wad_out_entries_' || partition_suffix || ' '
-      'ADD CONSTRAINT wad_out_entries_' || partition_suffix || 
'_wad_out_entry_serial_id_key '
-        'UNIQUE (wad_out_entry_serial_id) '
-  );
-END
-$$;
-
--------------------------- wads_in --------------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wads_in(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'wads_in';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(wad_in_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' --UNIQUE
-      ',wad_id BYTEA PRIMARY KEY CHECK (LENGTH(wad_id)=24)'
-      ',origin_exchange_url TEXT NOT NULL'
-      ',amount_val INT8 NOT NULL'
-      ',amount_frac INT4 NOT NULL'
-      ',arrival_time INT8 NOT NULL'
-      ',UNIQUE (wad_id, origin_exchange_url)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (wad_id)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_wads_in_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE wads_in_' || partition_suffix || ' '
-      'ADD CONSTRAINT wads_in_' || partition_suffix || '_wad_in_serial_id_key '
-        'UNIQUE (wad_in_serial_id) '
-      ',ADD CONSTRAINT wads_in_' || partition_suffix || 
'_wad_is_origin_exchange_url_key '
-        'UNIQUE (wad_id, origin_exchange_url) '
-  );
-END
-$$;
-
-
-------------------------- wads_in_entries --------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wad_in_entries(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  table_name VARCHAR DEFAULT 'wad_in_entries';
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I '
-      '(wad_in_entry_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' 
--UNIQUE
-      ',wad_in_serial_id INT8' -- REFERENCES wads_in (wad_in_serial_id) ON 
DELETE CASCADE
-      ',reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)'
-      ',purse_pub BYTEA PRIMARY KEY CHECK(LENGTH(purse_pub)=32)'
-      ',h_contract BYTEA NOT NULL CHECK(LENGTH(h_contract)=64)'
-      ',purse_expiration INT8 NOT NULL'
-      ',merge_timestamp INT8 NOT NULL'
-      ',amount_with_fee_val INT8 NOT NULL'
-      ',amount_with_fee_frac INT4 NOT NULL'
-      ',wad_fee_val INT8 NOT NULL'
-      ',wad_fee_frac INT4 NOT NULL'
-      ',deposit_fees_val INT8 NOT NULL'
-      ',deposit_fees_frac INT4 NOT NULL'
-      ',reserve_sig BYTEA NOT NULL CHECK (LENGTH(reserve_sig)=64)'
-      ',purse_sig BYTEA NOT NULL CHECK (LENGTH(purse_sig)=64)'
-    ') %s ;'
-    ,table_name
-    ,'PARTITION BY HASH (purse_pub)'
-    ,shard_suffix
-  );
-
-  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 '
-    'ON ' || table_name || ' '
-    '(reserve_pub);'
-  );
-  EXECUTE FORMAT (
-    'COMMENT ON INDEX ' || table_name || '_reserve_pub '
-    'IS ' || quote_literal('needed in reserve history computation') || ';'
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION add_constraints_to_wad_in_entries_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-  EXECUTE FORMAT (
-    'ALTER TABLE wad_in_entries_' || partition_suffix || ' '
-      'ADD CONSTRAINT wad_in_entries_' || partition_suffix || 
'_wad_in_entry_serial_id_key '
-        'UNIQUE (wad_in_entry_serial_id) '
-  );
-END
-$$;
-
--------------------------------------------------------------------
-------------------------- Partitions ------------------------------
--------------------------------------------------------------------
-
-CREATE OR REPLACE FUNCTION create_hash_partition(
-    source_table_name VARCHAR
-    ,modulus INTEGER
-    ,partition_num INTEGER
-  )
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Creating partition %_%', source_table_name, partition_num;
-
-  EXECUTE FORMAT(
-    'CREATE TABLE IF NOT EXISTS %I '
-      'PARTITION OF %I '
-      'FOR VALUES WITH (MODULUS %s, REMAINDER %s)'
-    ,source_table_name || '_' || partition_num
-    ,source_table_name
-    ,modulus
-    ,partition_num-1
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION create_range_partition(
-  source_table_name VARCHAR
-  ,partition_num INTEGER
-)
-  RETURNS void
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-  RAISE NOTICE 'TODO';
-END
-$$;
-
-CREATE OR REPLACE FUNCTION detach_default_partitions()
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Detaching all default table partitions';
-
-  ALTER TABLE IF EXISTS wire_targets
-    DETACH PARTITION wire_targets_default;
-
-  ALTER TABLE IF EXISTS reserves
-    DETACH PARTITION reserves_default;
-
-  ALTER TABLE IF EXISTS reserves_in
-    DETACH PARTITION reserves_in_default;
-
-  ALTER TABLE IF EXISTS reserves_close
-    DETACH PARTITION reserves_close_default;
-
-  ALTER TABLE IF EXISTS history_requests
-    DETACH partition history_requests_default;
-
-  ALTER TABLE IF EXISTS close_requests
-    DETACH partition close_requests_default;
-
-  ALTER TABLE IF EXISTS reserves_open_requests
-    DETACH partition reserves_open_requests_default;
-
-  ALTER TABLE IF EXISTS reserves_out
-    DETACH PARTITION reserves_out_default;
-
-  ALTER TABLE IF EXISTS reserves_out_by_reserve
-    DETACH PARTITION reserves_out_by_reserve_default;
-
-  ALTER TABLE IF EXISTS known_coins
-    DETACH PARTITION known_coins_default;
-
-  ALTER TABLE IF EXISTS refresh_commitments
-    DETACH PARTITION refresh_commitments_default;
-
-  ALTER TABLE IF EXISTS refresh_revealed_coins
-    DETACH PARTITION refresh_revealed_coins_default;
-
-  ALTER TABLE IF EXISTS refresh_transfer_keys
-    DETACH PARTITION refresh_transfer_keys_default;
-
-  ALTER TABLE IF EXISTS deposits
-    DETACH PARTITION deposits_default;
-
---- TODO range partitioning
---  ALTER TABLE IF EXISTS deposits_by_ready
---    DETACH PARTITION deposits_by_ready_default;
---
---  ALTER TABLE IF EXISTS deposits_for_matching
---    DETACH PARTITION deposits_default_for_matching_default;
-
-  ALTER TABLE IF EXISTS refunds
-    DETACH PARTITION refunds_default;
-
-  ALTER TABLE IF EXISTS wire_out
-    DETACH PARTITION wire_out_default;
-
-  ALTER TABLE IF EXISTS aggregation_transient
-    DETACH PARTITION aggregation_transient_default;
-
-  ALTER TABLE IF EXISTS aggregation_tracking
-    DETACH PARTITION aggregation_tracking_default;
-
-  ALTER TABLE IF EXISTS recoup
-    DETACH PARTITION recoup_default;
-
-  ALTER TABLE IF EXISTS recoup_by_reserve
-    DETACH PARTITION recoup_by_reserve_default;
-
-  ALTER TABLE IF EXISTS recoup_refresh
-    DETACH PARTITION recoup_refresh_default;
-
-  ALTER TABLE IF EXISTS prewire
-    DETACH PARTITION prewire_default;
-
-  ALTER TABLE IF EXISTS cs_nonce_locks
-    DETACH partition cs_nonce_locks_default;
-
-  ALTER TABLE IF EXISTS purse_requests
-    DETACH partition purse_requests_default;
-
-  ALTER TABLE IF EXISTS purse_decision
-    DETACH partition purse_decision_default;
-
-  ALTER TABLE IF EXISTS purse_merges
-    DETACH partition purse_merges_default;
-
-  ALTER TABLE IF EXISTS account_merges
-    DETACH partition account_merges_default;
-
-  ALTER TABLE IF EXISTS contracts
-    DETACH partition contracts_default;
-
-  ALTER TABLE IF EXISTS purse_deposits
-    DETACH partition purse_deposits_default;
-
-  ALTER TABLE IF EXISTS wad_out_entries
-    DETACH partition wad_out_entries_default;
-
-  ALTER TABLE IF EXISTS wads_in
-    DETACH partition wads_in_default;
-
-  ALTER TABLE IF EXISTS wad_in_entries
-    DETACH partition wad_in_entries_default;
-END
-$$;
-
-COMMENT ON FUNCTION detach_default_partitions
-  IS 'We need to drop default and create new one before deleting the default 
partitions
-      otherwise constraints get lost too. Might be needed in sharding too';
-
-
-CREATE OR REPLACE FUNCTION drop_default_partitions()
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Dropping default table partitions';
-
-  DROP TABLE IF EXISTS wire_targets_default;
-  DROP TABLE IF EXISTS reserves_default;
-  DROP TABLE IF EXISTS reserves_in_default;
-  DROP TABLE IF EXISTS reserves_close_default;
-  DROP TABLE IF EXISTS reserves_open_requests_default;
-  DROP TABLE IF EXISTS history_requests_default;
-  DROP TABLE IF EXISTS close_requests_default;
-
-  DROP TABLE IF EXISTS reserves_out_default;
-  DROP TABLE IF EXISTS reserves_out_by_reserve_default;
-  DROP TABLE IF EXISTS known_coins_default;
-  DROP TABLE IF EXISTS refresh_commitments_default;
-  DROP TABLE IF EXISTS refresh_revealed_coins_default;
-  DROP TABLE IF EXISTS refresh_transfer_keys_default;
-  DROP TABLE IF EXISTS deposits_default;
---DROP TABLE IF EXISTS deposits_by_ready_default;
---DROP TABLE IF EXISTS deposits_for_matching_default;
-  DROP TABLE IF EXISTS refunds_default;
-  DROP TABLE IF EXISTS wire_out_default;
-  DROP TABLE IF EXISTS aggregation_transient_default;
-  DROP TABLE IF EXISTS aggregation_tracking_default;
-  DROP TABLE IF EXISTS recoup_default;
-  DROP TABLE IF EXISTS recoup_by_reserve_default;
-  DROP TABLE IF EXISTS recoup_refresh_default;
-  DROP TABLE IF EXISTS prewire_default;
-  DROP TABLE IF EXISTS cs_nonce_locks_default;
-
-  DROP TABLE IF EXISTS purse_requests_default;
-  DROP TABLE IF EXISTS purse_decision_default;
-  DROP TABLE IF EXISTS purse_merges_default;
-  DROP TABLE IF EXISTS account_merges_default;
-  DROP TABLE IF EXISTS purse_deposits_default;
-  DROP TABLE IF EXISTS contracts_default;
-
-  DROP TABLE IF EXISTS wad_out_entries_default;
-  DROP TABLE IF EXISTS wads_in_default;
-  DROP TABLE IF EXISTS wad_in_entries_default;
-
-END
-$$;
-
-COMMENT ON FUNCTION drop_default_partitions
-  IS 'Drop all default partitions once other partitions are attached.
-      Might be needed in sharding too.';
-
-CREATE OR REPLACE FUNCTION create_partitions(
-    num_partitions INTEGER
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  modulus INTEGER;
-BEGIN
-
-  modulus := num_partitions;
-
-  PERFORM detach_default_partitions();
-
-  LOOP
-
-    PERFORM create_hash_partition(
-      'wire_targets'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_wire_targets_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'reserves'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'reserves_in'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_reserves_in_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'reserves_close'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_reserves_close_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'reserves_out'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_reserves_out_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'reserves_out_by_reserve'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'known_coins'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_known_coins_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'refresh_commitments'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_refresh_commitments_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'refresh_revealed_coins'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_refresh_revealed_coins_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'refresh_transfer_keys'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_refresh_transfer_keys_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'deposits'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_deposits_partition(num_partitions::varchar);
-
--- TODO: dynamically (!) creating/deleting deposits partitions:
---    create new partitions 'as needed', drop old ones once the aggregator has 
made
---    them empty; as 'new' deposits will always have deadlines in the future, 
this
---    would basically guarantee no conflict between aggregator and exchange 
service!
--- SEE also: 
https://www.cybertec-postgresql.com/en/automatic-partition-creation-in-postgresql/
--- (article is slightly wrong, as this works:)
---CREATE TABLE tab (
---  id bigint GENERATED ALWAYS AS IDENTITY,
---  ts timestamp NOT NULL,
---  data text
--- PARTITION BY LIST ((ts::date));
--- CREATE TABLE tab_def PARTITION OF tab DEFAULT;
--- BEGIN
--- CREATE TABLE tab_part2 (LIKE tab);
--- insert into tab_part2 (id,ts, data) values (5,'2022-03-21', 'foo');
--- alter table tab attach partition tab_part2 for values in ('2022-03-21');
--- commit;
--- Naturally, to ensure this is actually 100% conflict-free, we'd
--- need to create tables at the granularity of the wire/refund deadlines;
--- that is right now configurable via AGGREGATOR_SHIFT option.
-
--- FIXME: range partitioning
---    PERFORM create_range_partition(
---      'deposits_by_ready'
---      ,modulus
---      ,num_partitions
---    );
---
---    PERFORM create_range_partition(
---      'deposits_for_matching'
---      ,modulus
---      ,num_partitions
---    );
-
-    PERFORM create_hash_partition(
-      'refunds'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_refunds_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'wire_out'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_wire_out_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'aggregation_transient'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'aggregation_tracking'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_aggregation_tracking_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'recoup'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_recoup_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'recoup_by_reserve'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'recoup_refresh'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_recoup_refresh_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'prewire'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'cs_nonce_locks'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_cs_nonce_locks_partition(num_partitions::varchar);
-
-
-    PERFORM create_hash_partition(
-      'close_requests'
-      ,modulus
-      ,num_partitions
-    );
-
-    PERFORM create_hash_partition(
-      'reserves_open_requests'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_reserves_open_request_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'history_requests'
-      ,modulus
-      ,num_partitions
-    );
-
-
-    ---------------- P2P ----------------------
-
-    PERFORM create_hash_partition(
-      'purse_requests'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_purse_requests_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'purse_decision'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_purse_decision_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'purse_merges'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_purse_merges_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'account_merges'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_account_merges_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'contracts'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_contracts_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'purse_deposits'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_purse_deposits_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'wad_out_entries'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_wad_out_entries_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'wads_in'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_wads_in_partition(num_partitions::varchar);
-
-    PERFORM create_hash_partition(
-      'wad_in_entries'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM 
add_constraints_to_wad_in_entries_partition(num_partitions::varchar);
-
-    num_partitions=num_partitions-1;
-    EXIT WHEN num_partitions=0;
-
-  END LOOP;
-
-  PERFORM drop_default_partitions();
-
-END
-$$;
-
---------------------- Sharding ---------------------------
-
-CREATE OR REPLACE FUNCTION create_foreign_hash_partition(
-    source_table_name VARCHAR
-    ,modulus INTEGER
-    ,shard_suffix VARCHAR
-    ,current_shard_num INTEGER
-    ,local_user VARCHAR DEFAULT 'taler-exchange-httpd'
-  )
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Creating %_% on %', source_table_name, shard_suffix, 
shard_suffix;
-
-  EXECUTE FORMAT(
-    'CREATE FOREIGN TABLE IF NOT EXISTS %I '
-      'PARTITION OF %I '
-      'FOR VALUES WITH (MODULUS %s, REMAINDER %s) '
-      'SERVER %I'
-    ,source_table_name || '_' || shard_suffix
-    ,source_table_name
-    ,modulus
-    ,current_shard_num-1
-    ,shard_suffix
-  );
-
-  EXECUTE FORMAT(
-    'ALTER FOREIGN TABLE %I OWNER TO %I'
-    ,source_table_name || '_' || shard_suffix
-    ,local_user
-  );
-
-END
-$$;
-
-CREATE OR REPLACE FUNCTION create_foreign_range_partition(
-  source_table_name VARCHAR
-  ,partition_num INTEGER
-)
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-   RAISE NOTICE 'TODO';
-END
-$$;
-
-CREATE OR REPLACE FUNCTION prepare_sharding()
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  CREATE EXTENSION IF NOT EXISTS postgres_fdw;
-
-  PERFORM detach_default_partitions();
-
-  ALTER TABLE IF EXISTS wire_targets
-    DROP CONSTRAINT IF EXISTS wire_targets_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS reserves
-    DROP CONSTRAINT IF EXISTS reserves_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS reserves_in
-    DROP CONSTRAINT IF EXISTS reserves_in_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS reserves_close
-    DROP CONSTRAINT IF EXISTS reserves_close_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS reserves_out
-    DROP CONSTRAINT IF EXISTS reserves_out_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS reserves_out_denominations_serial_fkey
-    ,DROP CONSTRAINT IF EXISTS reserves_out_h_blind_ev_key
-  ;
-
-  ALTER TABLE IF EXISTS known_coins
-    DROP CONSTRAINT IF EXISTS known_coins_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS known_coins_denominations_serial_fkey
-  ;
-
-  ALTER TABLE IF EXISTS refresh_commitments
-    DROP CONSTRAINT IF EXISTS refresh_commitments_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS refresh_old_coin_pub_fkey
-  ;
-
-  ALTER TABLE IF EXISTS refresh_revealed_coins
-    DROP CONSTRAINT IF EXISTS refresh_revealed_coins_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS refresh_revealed_coins_denominations_serial_fkey
-  ;
-
-  ALTER TABLE IF EXISTS refresh_transfer_keys
-    DROP CONSTRAINT IF EXISTS refresh_transfer_keys_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS deposits
-    DROP CONSTRAINT IF EXISTS deposits_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS deposits_policy_details_serial_id_fkey
-    ,DROP CONSTRAINT IF EXISTS 
deposits_coin_pub_merchant_pub_h_contract_terms_key CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS refunds
-    DROP CONSTRAINT IF EXISTS refunds_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS wire_out
-    DROP CONSTRAINT IF EXISTS wire_out_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS wire_out_wtid_raw_key CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS aggregation_tracking
-    DROP CONSTRAINT IF EXISTS aggregation_tracking_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS aggregation_tracking_wtid_raw_fkey
-  ;
-
-  ALTER TABLE IF EXISTS recoup
-    DROP CONSTRAINT IF EXISTS recoup_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS recoup_refresh
-    DROP CONSTRAINT IF EXISTS recoup_refresh_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS prewire
-    DROP CONSTRAINT IF EXISTS prewire_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS cs_nonce_locks
-    DROP CONSTRAINT IF EXISTS cs_nonce_locks_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS purse_requests
-    DROP CONSTRAINT IF EXISTS purse_requests_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS purse_decision
-    DROP CONSTRAINT IF EXISTS purse_decision_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS purse_merges
-    DROP CONSTRAINT IF EXISTS purse_merges_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS account_merges
-    DROP CONSTRAINT IF EXISTS account_merges_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS contracts
-    DROP CONSTRAINT IF EXISTS contracts_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS history_requests
-    DROP CONSTRAINT IF EXISTS history_requests_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS close_requests
-    DROP CONSTRAINT IF EXISTS close_requests_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS purse_deposits
-    DROP CONSTRAINT IF EXISTS purse_deposits_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS wads_out
-    DROP CONSTRAINT IF EXISTS wads_out_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS wad_out_entries
-    DROP CONSTRAINT IF EXISTS wad_out_entries_pkey CASCADE
-  ;
-
-  ALTER TABLE IF EXISTS wads_in
-    DROP CONSTRAINT IF EXISTS wads_in_pkey CASCADE
-    ,DROP CONSTRAINT IF EXISTS wads_in_wad_id_origin_exchange_url_key
-  ;
-
-  ALTER TABLE IF EXISTS wad_in_entries
-    DROP CONSTRAINT IF EXISTS wad_in_entries_pkey CASCADE
-  ;
-
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION create_shard_server(
-    shard_suffix VARCHAR
-    ,total_num_shards INTEGER
-    ,current_shard_num INTEGER
-    ,remote_host VARCHAR
-    ,remote_user VARCHAR
-    ,remote_user_password VARCHAR
-    ,remote_db_name VARCHAR DEFAULT 'taler-exchange'
-    ,remote_port INTEGER DEFAULT '5432'
-    ,local_user VARCHAR DEFAULT 'taler-exchange-httpd'
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Creating server %', remote_host;
-
-  EXECUTE FORMAT(
-    'CREATE SERVER IF NOT EXISTS %I '
-      'FOREIGN DATA WRAPPER postgres_fdw '
-      'OPTIONS (dbname %L, host %L, port %L)'
-    ,shard_suffix
-    ,remote_db_name
-    ,remote_host
-    ,remote_port
-  );
-
-  EXECUTE FORMAT(
-    'CREATE USER MAPPING IF NOT EXISTS '
-      'FOR %I SERVER %I '
-      'OPTIONS (user %L, password %L)'
-    ,local_user
-    ,shard_suffix
-    ,remote_user
-    ,remote_user_password
-  );
-
-  EXECUTE FORMAT(
-    'GRANT ALL PRIVILEGES '
-      'ON FOREIGN SERVER %I '
-      'TO %I;'
-    ,shard_suffix
-    ,local_user
-  );
-
-  PERFORM create_foreign_hash_partition(
-    'wire_targets'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'reserves'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'reserves_in'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'reserves_out'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'reserves_out_by_reserve'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'reserves_close'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'history_requests'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'close_requests'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'open_requests'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'known_coins'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'refresh_commitments'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'refresh_revealed_coins'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'refresh_transfer_keys'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'deposits'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
---  PERFORM create_foreign_range_partition(
---    'deposits_by_ready'
---    ,total_num_shards
---    ,shard_suffix
---    ,current_shard_num
---    ,local_user
---  );
---  PERFORM create_foreign_range_partition(
---    'deposits_for_matching'
---    ,total_num_shards
---    ,shard_suffix
---    ,current_shard_num
---    ,local_user
---  );
-  PERFORM create_foreign_hash_partition(
-    'refunds'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'wire_out'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'aggregation_transient'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'aggregation_tracking'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'recoup'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'recoup_by_reserve'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'recoup_refresh'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'prewire'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'cs_nonce_locks'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-
-  ------------------- P2P --------------------
-
-  PERFORM create_foreign_hash_partition(
-    'purse_requests'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'purse_decision'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'purse_merges'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'account_merges'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'contracts'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-
-  PERFORM create_foreign_hash_partition(
-    'purse_deposits'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'wad_out_entries'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'wads_in'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-  PERFORM create_foreign_hash_partition(
-    'wad_in_entries'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-
-END
-$$;
-
-COMMENT ON FUNCTION create_shard_server
-  IS 'Create a shard server on the master
-      node with all foreign tables and user mappings';
-
-CREATE OR REPLACE FUNCTION create_foreign_servers(
-  amount INTEGER
-  ,domain VARCHAR
-  ,remote_user VARCHAR DEFAULT 'taler'
-  ,remote_user_password VARCHAR DEFAULT 'taler'
-)
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM prepare_sharding();
-
-  FOR i IN 1..amount LOOP
-    PERFORM create_shard_server(
-      i::varchar
-     ,amount
-     ,i
-     ,'shard-' || i::varchar || '.' || domain
-     ,remote_user
-     ,remote_user_password
-     ,'taler-exchange'
-     ,'5432'
-     ,'taler-exchange-httpd'
-    );
-  END LOOP;
-
-  PERFORM drop_default_partitions();
-
-END
-$$;
diff --git a/src/exchangedb/common-0002.sql b/src/exchangedb/common-0002.sql
deleted file mode 100644
index 0f7b1f52..00000000
--- a/src/exchangedb/common-0002.sql
+++ /dev/null
@@ -1,205 +0,0 @@
---
--- This file is part of TALER
--- Copyright (C) 2014--2022 Taler Systems SA
---
--- TALER is free software; you can redistribute it and/or modify it under the
--- terms of the GNU General Public License as published by the Free Software
--- Foundation; either version 3, or (at your option) any later version.
---
--- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
--- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
--- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
---
--- You should have received a copy of the GNU General Public License along with
--- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
---
-
--------------------- Tables ----------------------------
-
-CREATE OR REPLACE FUNCTION create_table_wire_targets(
-  IN shard_suffix VARCHAR DEFAULT NULL
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM create_partitioned_table(
-    'CREATE TABLE IF NOT EXISTS %I'
-      '(wire_target_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY' -- 
UNIQUE'
-      ',wire_target_h_payto BYTEA PRIMARY KEY CHECK 
(LENGTH(wire_target_h_payto)=32)'
-      ',payto_uri VARCHAR NOT NULL'
-    ') %s ;'
-    ,'wire_targets'
-    ,'PARTITION BY HASH (wire_target_h_payto)'
-    ,shard_suffix
-  );
-
-END
-$$;
-
--- We need a separate function for this, as we call create_table only once but 
need to add
--- those constraints to each partition which gets created
-CREATE OR REPLACE FUNCTION add_constraints_to_wire_targets_partition(
-  IN partition_suffix VARCHAR
-)
-RETURNS void
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  EXECUTE FORMAT (
-    'ALTER TABLE wire_targets_' || partition_suffix || ' '
-      'ADD CONSTRAINT wire_targets_' || partition_suffix || 
'_wire_target_serial_id_key '
-        'UNIQUE (wire_target_serial_id)'
-  );
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION detach_default_partitions2()
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Detaching all default table partitions';
-
-  ALTER TABLE IF EXISTS wire_targets
-    DETACH PARTITION wire_targets_default;
-
-END
-$$;
-
-COMMENT ON FUNCTION detach_default_partitions2
-  IS 'We need to drop default and create new one before deleting the default 
partitions
-      otherwise constraints get lost too. Might be needed in sharding too';
-
-
-CREATE OR REPLACE FUNCTION drop_default_partitions2()
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Dropping default table partitions';
-
-  DROP TABLE IF EXISTS wire_targets_default;
-END
-$$;
-
-COMMENT ON FUNCTION drop_default_partitions2
-  IS 'Drop all default partitions once other partitions are attached.
-      Might be needed in sharding too.';
-
-
-CREATE OR REPLACE FUNCTION create_partitions2(
-    num_partitions INTEGER
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  modulus INTEGER;
-BEGIN
-
-  modulus := num_partitions;
-
-  PERFORM detach_default_partitions2();
-
-  LOOP
-
-    PERFORM create_hash_partition(
-      'wire_targets'
-      ,modulus
-      ,num_partitions
-    );
-    PERFORM add_constraints_to_wire_targets_partition(num_partitions::varchar);
-
-  END LOOP;
-
-  PERFORM drop_default_partitions2();
-
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION prepare_sharding2()
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  PERFORM detach_default_partitions2();
-
-  ALTER TABLE IF EXISTS wire_targets
-    DROP CONSTRAINT IF EXISTS wire_targets_pkey CASCADE
-  ;
-
-END
-$$;
-
-
-CREATE OR REPLACE FUNCTION create_shard_server2(
-    shard_suffix VARCHAR
-    ,total_num_shards INTEGER
-    ,current_shard_num INTEGER
-    ,remote_host VARCHAR
-    ,remote_user VARCHAR
-    ,remote_user_password VARCHAR
-    ,remote_db_name VARCHAR DEFAULT 'taler-exchange'
-    ,remote_port INTEGER DEFAULT '5432'
-    ,local_user VARCHAR DEFAULT 'taler-exchange-httpd'
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-BEGIN
-
-  RAISE NOTICE 'Creating server %', remote_host;
-
-  PERFORM create_foreign_hash_partition(
-    'wire_targets'
-    ,total_num_shards
-    ,shard_suffix
-    ,current_shard_num
-    ,local_user
-  );
-END
-$$;
-
-COMMENT ON FUNCTION create_shard_server2
-  IS 'Create a shard server on the master
-      node with all foreign tables and user mappings';
-
-
-
---------------------------------
-
-CREATE TABLE IF NOT EXISTS partitioned_tables
-  (name VARCHAR PRIMARY KEY NOT NULL);
-
-INSERT INTO partitioned_tables
-    (name)
-  VALUES
-    ('wire_targets')
-   ,('refunds')
-  ON CONFLICT DO NOTHING;
-
-
-CREATE OR REPLACE FUNCTION drop_default_partitions()
-  RETURNS VOID
-  LANGUAGE plpgsql
-AS $$
-DECLARE
-  tc CURSOR FOR SELECT name FROM partitioned_tables;
-BEGIN
-
-  RAISE NOTICE 'Dropping default table partitions';
-  FOR rec IN tc
-  LOOP
-    EXECUTE FORMAT (
-      'DROP TABLE IF EXISTS %s_default ;'::text,
-    rec.name;
-END  
-$$;
diff --git a/src/exchangedb/drop.sql b/src/exchangedb/drop.sql
index 4a4dafb1..ff383d74 100644
--- a/src/exchangedb/drop.sql
+++ b/src/exchangedb/drop.sql
@@ -19,6 +19,7 @@ BEGIN;
 
 
 SELECT _v.unregister_patch('exchange-0001');
+SELECT _v.unregister_patch('exchange-0002');
 
 DROP SCHEMA exchange CASCADE;
 
diff --git a/src/exchangedb/exchange-0001-part.sql 
b/src/exchangedb/exchange-0001-part.sql
deleted file mode 100644
index 72b08410..00000000
--- a/src/exchangedb/exchange-0001-part.sql
+++ /dev/null
@@ -1,1522 +0,0 @@
---
--- This file is part of TALER
--- Copyright (C) 2014--2022 Taler Systems SA
---
--- TALER is free software; you can redistribute it and/or modify it under the
--- terms of the GNU General Public License as published by the Free Software
--- Foundation; either version 3, or (at your option) any later version.
---
--- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
--- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
--- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
---
--- You should have received a copy of the GNU General Public License along with
--- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
---
-
--- ------------------------------ denominations 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS 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!)
-  ,age_mask INT4 NOT NULL DEFAULT (0)
-  ,denom_pub BYTEA NOT NULL
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,valid_from INT8 NOT NULL
-  ,expire_withdraw INT8 NOT NULL
-  ,expire_deposit INT8 NOT NULL
-  ,expire_legal INT8 NOT NULL
-  ,coin_val INT8 NOT NULL
-  ,coin_frac INT4 NOT NULL
-  ,fee_withdraw_val INT8 NOT NULL
-  ,fee_withdraw_frac INT4 NOT NULL
-  ,fee_deposit_val INT8 NOT NULL
-  ,fee_deposit_frac INT4 NOT NULL
-  ,fee_refresh_val INT8 NOT NULL
-  ,fee_refresh_frac INT4 NOT NULL
-  ,fee_refund_val INT8 NOT NULL
-  ,fee_refund_frac INT4 NOT NULL
-  );
-COMMENT ON TABLE denominations
-  IS 'Main denominations table. All the valid denominations the exchange knows 
about.';
-COMMENT ON COLUMN denominations.denom_type
-  IS 'determines cipher type for blind signatures used with this denomination; 
0 is for RSA';
-COMMENT ON COLUMN denominations.age_mask
-  IS 'bitmask with the age restrictions that are being used for this 
denomination; 0 if denomination does not support the use of age restrictions';
-COMMENT ON COLUMN denominations.denominations_serial
-  IS 'needed for exchange-auditor replication logic';
-
-CREATE INDEX IF NOT EXISTS denominations_by_expire_legal_index
-  ON denominations
-  (expire_legal);
-
-
--- ------------------------------ denomination_revocations 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS denomination_revocations
-  (denom_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,denominations_serial INT8 PRIMARY KEY REFERENCES denominations 
(denominations_serial) ON DELETE CASCADE
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  );
-COMMENT ON TABLE denomination_revocations
-  IS 'remembering which denomination keys have been revoked';
-
-
-
--- -------------------------- kyc_alerts 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS kyc_alerts
-  (h_payto BYTEA PRIMARY KEY CHECK (LENGTH(h_payto)=32)
-  ,trigger_type INT4 NOT NULL
-  ,UNIQUE(trigger_type,h_payto)
-  );
-COMMENT ON TABLE kyc_alerts
-  IS 'alerts about completed KYC events reliably notifying other components 
(even if they are not running)';
-COMMENT ON COLUMN kyc_alerts.h_payto
-  IS 'hash of the payto://-URI for which the KYC status changed';
-COMMENT ON COLUMN kyc_alerts.trigger_type
-  IS 'identifies the receiver of the alert, as the same h_payto may require 
multiple components to be notified';
-
-
--- ------------------------------ profit drains 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS profit_drains
-  (profit_drain_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,wtid BYTEA PRIMARY KEY CHECK (LENGTH(wtid)=32)
-  ,account_section VARCHAR NOT NULL
-  ,payto_uri VARCHAR NOT NULL
-  ,trigger_date INT8 NOT NULL
-  ,amount_val INT8 NOT NULL
-  ,amount_frac INT4 NOT NULL
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,executed BOOLEAN NOT NULL DEFAULT FALSE
-  );
-COMMENT ON TABLE profit_drains
-  IS 'transactions to be performed to move profits from the escrow account of 
the exchange to a regular account';
-COMMENT ON COLUMN profit_drains.wtid
-  IS 'randomly chosen nonce, unique to prevent double-submission';
-COMMENT ON COLUMN profit_drains.account_section
-  IS 'specifies the configuration section in the taler-exchange-drain 
configuration with the wire account to drain';
-COMMENT ON COLUMN profit_drains.payto_uri
-  IS 'specifies the account to be credited';
-COMMENT ON COLUMN profit_drains.trigger_date
-  IS 'set by taler-exchange-offline at the time of making the signature; not 
necessarily the exact date of execution of the wire transfer, just for 
orientation';
-COMMENT ON COLUMN profit_drains.amount_val
-  IS 'amount to be transferred';
-COMMENT ON COLUMN profit_drains.master_sig
-  IS 'EdDSA signature of type TALER_SIGNATURE_MASTER_DRAIN_PROFIT';
-COMMENT ON COLUMN profit_drains.executed
-  IS 'set to TRUE by taler-exchange-drain on execution of the transaction, not 
replicated to auditor';
-
-
--- ------------------------------ wire_targets 
----------------------------------------
-
-SELECT create_table_wire_targets();
-
-COMMENT ON TABLE wire_targets
-  IS 'All senders and recipients of money via the exchange';
-COMMENT ON COLUMN wire_targets.payto_uri
-  IS 'Can be a regular bank account, or also be a URI identifying a 
reserve-account (for P2P payments)';
-COMMENT ON COLUMN wire_targets.wire_target_h_payto
-  IS 'Unsalted hash of payto_uri';
-
-CREATE TABLE IF NOT EXISTS wire_targets_default
-  PARTITION OF wire_targets
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wire_targets_partition('default');
-
-
--- ------------------------------ legitimization_processes 
----------------------------------------
-
-SELECT create_table_legitimization_processes();
-
-COMMENT ON TABLE legitimization_processes
-  IS 'List of legitimization processes (ongoing and completed) by account and 
provider';
-COMMENT ON COLUMN legitimization_processes.legitimization_process_serial_id
-  IS 'unique ID for this legitimization process at the exchange';
-COMMENT ON COLUMN legitimization_processes.h_payto
-  IS 'foreign key linking the entry to the wire_targets table, NOT a primary 
key (multiple legitimizations are possible per wire target)';
-COMMENT ON COLUMN legitimization_processes.expiration_time
-  IS 'in the future if the respective KYC check was passed successfully';
-COMMENT ON COLUMN legitimization_processes.provider_section
-  IS 'Configuration file section with details about this provider';
-COMMENT ON COLUMN legitimization_processes.provider_user_id
-  IS 'Identifier for the user at the provider that was used for the 
legitimization. NULL if provider is unaware.';
-COMMENT ON COLUMN legitimization_processes.provider_legitimization_id
-  IS 'Identifier for the specific legitimization process at the provider. NULL 
if legitimization was not started.';
-
-CREATE TABLE IF NOT EXISTS legitimization_processes_default
-  PARTITION OF legitimization_processes
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_legitimization_processes_partition('default');
-
-
--- ------------------------------ legitimization_requirements_ 
----------------------------------------
-
-SELECT create_table_legitimization_requirements();
-
-COMMENT ON TABLE legitimization_requirements
-  IS 'List of required legitimization by account';
-COMMENT ON COLUMN 
legitimization_requirements.legitimization_requirement_serial_id
-  IS 'unique ID for this legitimization requirement at the exchange';
-COMMENT ON COLUMN legitimization_requirements.h_payto
-  IS 'foreign key linking the entry to the wire_targets table, NOT a primary 
key (multiple legitimizations are possible per wire target)';
-COMMENT ON COLUMN legitimization_requirements.required_checks
-  IS 'space-separated list of required checks';
-
-CREATE TABLE IF NOT EXISTS legitimization_requirements_default
-  PARTITION OF legitimization_requirements
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_legitimization_requirements_partition('default');
-
-
-
--- ------------------------------ reserves 
----------------------------------------
-
-SELECT create_table_reserves();
-
-COMMENT ON TABLE reserves
-  IS 'Summarizes the balance of a reserve. Updated when new funds are added or 
withdrawn.';
-COMMENT ON COLUMN reserves.reserve_pub
-  IS 'EdDSA public key of the reserve. Knowledge of the private key implies 
ownership over the balance.';
-COMMENT ON COLUMN reserves.current_balance_val
-  IS 'Current balance remaining with the reserve.';
-COMMENT ON COLUMN reserves.purses_active
-  IS 'Number of purses that were created by this reserve that are not expired 
and not fully paid.';
-COMMENT ON COLUMN reserves.purses_allowed
-  IS 'Number of purses that this reserve is allowed to have active at most.';
-COMMENT ON COLUMN reserves.expiration_date
-  IS 'Used to trigger closing of reserves that have not been drained after 
some time';
-COMMENT ON COLUMN reserves.gc_date
-  IS 'Used to forget all information about a reserve during garbage 
collection';
-
-CREATE TABLE IF NOT EXISTS reserves_default
-  PARTITION OF reserves
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
--- ------------------------------ reserves_in 
----------------------------------------
-
-SELECT create_table_reserves_in();
-
-COMMENT ON TABLE reserves_in
-  IS 'list of transfers of funds into the reserves, one per incoming wire 
transfer';
-COMMENT ON COLUMN reserves_in.wire_source_h_payto
-  IS 'Identifies the debited bank account and KYC status';
-COMMENT ON COLUMN reserves_in.reserve_pub
-  IS 'Public key of the reserve. Private key signifies ownership of the 
remaining balance.';
-COMMENT ON COLUMN reserves_in.credit_val
-  IS 'Amount that was transferred into the reserve';
-
-CREATE TABLE IF NOT EXISTS reserves_in_default
-  PARTITION OF reserves_in
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_reserves_in_partition('default');
-
--- ------------------------------ reserves_close 
----------------------------------------
-
-SELECT create_table_reserves_close();
-
-COMMENT ON TABLE reserves_close
-  IS 'wire transfers executed by the reserve to close reserves';
-COMMENT ON COLUMN reserves_close.wire_target_h_payto
-  IS 'Identifies the credited bank account (and KYC status). Note that closing 
does not depend on KYC.';
-
-CREATE TABLE IF NOT EXISTS reserves_close_default
-  PARTITION OF reserves_close
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_reserves_close_partition('default');
-
-
-
-
-
-
--- ------------------------------ reserves_open_requests 
----------------------------------------
-
-SELECT create_table_reserves_open_requests();
-
-COMMENT ON TABLE reserves_open_requests
-  IS 'requests to keep a reserve open';
-COMMENT ON COLUMN reserves_open_requests.reserve_payment_val
-  IS 'Funding to pay for the request from the reserve balance itself.';
-
-CREATE TABLE IF NOT EXISTS reserves_open_requests_default
-  PARTITION OF reserves_open_requests
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_reserves_open_request_partition('default');
-
-
--- ------------------------------ reserves_open_deposits 
----------------------------------------
-
-SELECT create_table_reserves_open_deposits();
-
-COMMENT ON TABLE reserves_open_deposits
-  IS 'coin contributions paying for a reserve to remain open';
-COMMENT ON COLUMN reserves_open_deposits.reserve_pub
-  IS 'Identifies the specific reserve being paid for (possibly together with 
reserve_sig).';
-
-CREATE TABLE IF NOT EXISTS reserves_open_deposits_default
-  PARTITION OF reserves_open_deposits
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_reserves_open_deposits_partition('default');
-
-
--- ------------------------------ reserves_out 
----------------------------------------
-
-SELECT create_table_reserves_out();
-
-COMMENT ON TABLE reserves_out
-  IS 'Withdraw operations performed on reserves.';
-COMMENT ON COLUMN reserves_out.h_blind_ev
-  IS 'Hash of the blinded coin, used as primary key here so that broken 
clients that use a non-random coin or blinding factor fail to withdraw 
(otherwise they would fail on deposit when the coin is not unique there).';
-COMMENT ON COLUMN reserves_out.denominations_serial
-  IS 'We do not CASCADE ON DELETE here, we may keep the denomination data 
alive';
-
-CREATE TABLE IF NOT EXISTS reserves_out_default
-  PARTITION OF reserves_out
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_reserves_out_partition('default');
-
-
-SELECT create_table_reserves_out_by_reserve();
-
-COMMENT ON TABLE reserves_out_by_reserve
-  IS 'Information in this table is strictly redundant with that of 
reserves_out, but saved by a different primary key for fast lookups by reserve 
public key/uuid.';
-
-CREATE TABLE IF NOT EXISTS reserves_out_by_reserve_default
-  PARTITION OF reserves_out_by_reserve
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-CREATE OR REPLACE FUNCTION reserves_out_by_reserve_insert_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  INSERT INTO exchange.reserves_out_by_reserve
-    (reserve_uuid
-    ,h_blind_ev)
-  VALUES
-    (NEW.reserve_uuid
-    ,NEW.h_blind_ev);
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION reserves_out_by_reserve_insert_trigger()
-  IS 'Replicate reserve_out inserts into reserve_out_by_reserve table.';
-
-CREATE TRIGGER reserves_out_on_insert
-  AFTER INSERT
-   ON reserves_out
-   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_insert_trigger();
-
-CREATE OR REPLACE FUNCTION reserves_out_by_reserve_delete_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  DELETE FROM exchange.reserves_out_by_reserve
-   WHERE reserve_uuid = OLD.reserve_uuid;
-  RETURN OLD;
-END $$;
-COMMENT ON FUNCTION reserves_out_by_reserve_delete_trigger()
-  IS 'Replicate reserve_out deletions into reserve_out_by_reserve table.';
-
-CREATE TRIGGER reserves_out_on_delete
-  AFTER DELETE
-    ON reserves_out
-   FOR EACH ROW EXECUTE FUNCTION reserves_out_by_reserve_delete_trigger();
-
-
--- ------------------------------ auditors 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS auditors
-  (auditor_uuid BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,auditor_pub BYTEA PRIMARY KEY CHECK (LENGTH(auditor_pub)=32)
-  ,auditor_name VARCHAR NOT NULL
-  ,auditor_url VARCHAR NOT NULL
-  ,is_active BOOLEAN NOT NULL
-  ,last_change INT8 NOT NULL
-  );
-COMMENT ON TABLE auditors
-  IS 'Table with auditors the exchange uses or has used in the past. Entries 
never expire as we need to remember the last_change column indefinitely.';
-COMMENT ON COLUMN auditors.auditor_pub
-  IS 'Public key of the auditor.';
-COMMENT ON COLUMN auditors.auditor_url
-  IS 'The base URL of the auditor.';
-COMMENT ON COLUMN auditors.is_active
-  IS 'true if we are currently supporting the use of this auditor.';
-COMMENT ON COLUMN auditors.last_change
-  IS 'Latest time when active status changed. Used to detect replays of old 
messages.';
-
-
--- ------------------------------ auditor_denom_sigs 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS auditor_denom_sigs
-  (auditor_denom_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,auditor_uuid INT8 NOT NULL REFERENCES auditors (auditor_uuid) ON DELETE 
CASCADE
-  ,denominations_serial INT8 NOT NULL REFERENCES denominations 
(denominations_serial) ON DELETE CASCADE
-  ,auditor_sig BYTEA CHECK (LENGTH(auditor_sig)=64)
-  ,PRIMARY KEY (denominations_serial, auditor_uuid)
-  );
-COMMENT ON TABLE auditor_denom_sigs
-  IS 'Table with auditor signatures on exchange denomination keys.';
-COMMENT ON COLUMN auditor_denom_sigs.auditor_uuid
-  IS 'Identifies the auditor.';
-COMMENT ON COLUMN auditor_denom_sigs.denominations_serial
-  IS 'Denomination the signature is for.';
-COMMENT ON COLUMN auditor_denom_sigs.auditor_sig
-  IS 'Signature of the auditor, of purpose 
TALER_SIGNATURE_AUDITOR_EXCHANGE_KEYS.';
-
-
--- ------------------------------ exchange_sign_keys 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS exchange_sign_keys
-  (esk_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,exchange_pub BYTEA PRIMARY KEY CHECK (LENGTH(exchange_pub)=32)
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,valid_from INT8 NOT NULL
-  ,expire_sign INT8 NOT NULL
-  ,expire_legal INT8 NOT NULL
-  );
-COMMENT ON TABLE exchange_sign_keys
-  IS 'Table with master public key signatures on exchange online signing 
keys.';
-COMMENT ON COLUMN exchange_sign_keys.exchange_pub
-  IS 'Public online signing key of the exchange.';
-COMMENT ON COLUMN exchange_sign_keys.master_sig
-  IS 'Signature affirming the validity of the signing key of purpose 
TALER_SIGNATURE_MASTER_SIGNING_KEY_VALIDITY.';
-COMMENT ON COLUMN exchange_sign_keys.valid_from
-  IS 'Time when this online signing key will first be used to sign messages.';
-COMMENT ON COLUMN exchange_sign_keys.expire_sign
-  IS 'Time when this online signing key will no longer be used to sign.';
-COMMENT ON COLUMN exchange_sign_keys.expire_legal
-  IS 'Time when this online signing key legally expires.';
-
-
--- ------------------------------ signkey_revocations 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS signkey_revocations
-  (signkey_revocations_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,esk_serial INT8 PRIMARY KEY REFERENCES exchange_sign_keys (esk_serial) ON 
DELETE CASCADE
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  );
-COMMENT ON TABLE signkey_revocations
-  IS 'Table storing which online signing keys have been revoked';
-
-
--- ------------------------------ extensions 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS extensions
-  (extension_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,name VARCHAR NOT NULL UNIQUE
-  ,manifest BYTEA
-  );
-COMMENT ON TABLE extensions
-  IS 'Configurations of the activated extensions';
-COMMENT ON COLUMN extensions.name
-  IS 'Name of the extension';
-COMMENT ON COLUMN extensions.manifest
-  IS 'Manifest of the extension as JSON-blob, maybe NULL.  It contains common 
meta-information and extension-specific configuration.';
-
-
--- ------------------------------ known_coins 
----------------------------------------
-
-SELECT create_table_known_coins();
-
-COMMENT ON TABLE known_coins
-  IS 'information about coins and their signatures, so we do not have to store 
the signatures more than once if a coin is involved in multiple operations';
-COMMENT ON COLUMN known_coins.denominations_serial
-  IS 'Denomination of the coin, determines the value of the original coin and 
applicable fees for coin-specific operations.';
-COMMENT ON COLUMN known_coins.coin_pub
-  IS 'EdDSA public key of the coin';
-COMMENT ON COLUMN known_coins.remaining_val
-  IS 'Value of the coin that remains to be spent';
-COMMENT ON COLUMN known_coins.age_commitment_hash
-  IS 'Optional hash of the age commitment for age restrictions as per DD 24 
(active if denom_type has the respective bit set)';
-COMMENT ON COLUMN known_coins.denom_sig
-  IS 'This is the signature of the exchange that affirms that the coin is a 
valid coin. The specific signature type depends on denom_type of the 
denomination.';
-
-CREATE TABLE IF NOT EXISTS known_coins_default
-  PARTITION OF known_coins
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_known_coins_partition('default');
-
-
--- ------------------------------ refresh_commitments 
----------------------------------------
-
-SELECT create_table_refresh_commitments();
-
-COMMENT ON TABLE refresh_commitments
-  IS 'Commitments made when melting coins and the gamma value chosen by the 
exchange.';
-COMMENT ON COLUMN refresh_commitments.noreveal_index
-  IS 'The gamma value chosen by the exchange in the cut-and-choose protocol';
-COMMENT ON COLUMN refresh_commitments.rc
-  IS 'Commitment made by the client, hash over the various client inputs in 
the cut-and-choose protocol';
-COMMENT ON COLUMN refresh_commitments.old_coin_pub
-  IS 'Coin being melted in the refresh process.';
-
-CREATE TABLE IF NOT EXISTS refresh_commitments_default
-  PARTITION OF refresh_commitments
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_refresh_commitments_partition('default');
-
-
--- ------------------------------ refresh_revealed_coins 
----------------------------------------
-
-SELECT create_table_refresh_revealed_coins();
-
-COMMENT ON TABLE refresh_revealed_coins
-  IS 'Revelations about the new coins that are to be created during a melting 
session.';
-COMMENT ON COLUMN refresh_revealed_coins.rrc_serial
-  IS 'needed for exchange-auditor replication logic';
-COMMENT ON COLUMN refresh_revealed_coins.melt_serial_id
-  IS 'Identifies the refresh commitment (rc) of the melt operation.';
-COMMENT ON COLUMN refresh_revealed_coins.freshcoin_index
-  IS 'index of the fresh coin being created (one melt operation may result in 
multiple fresh coins)';
-COMMENT ON COLUMN refresh_revealed_coins.coin_ev
-  IS 'envelope of the new coin to be signed';
-COMMENT ON COLUMN refresh_revealed_coins.ewv
-  IS 'exchange contributed values in the creation of the fresh coin (see 
/csr)';
-COMMENT ON COLUMN refresh_revealed_coins.h_coin_ev
-  IS 'hash of the envelope of the new coin to be signed (for lookups)';
-COMMENT ON COLUMN refresh_revealed_coins.ev_sig
-  IS 'exchange signature over the envelope';
-
-CREATE TABLE IF NOT EXISTS refresh_revealed_coins_default
-  PARTITION OF refresh_revealed_coins
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_refresh_revealed_coins_partition('default');
-
-
--- ------------------------------ refresh_transfer_keys 
----------------------------------------
-
-SELECT create_table_refresh_transfer_keys();
-
-COMMENT ON TABLE refresh_transfer_keys
-  IS 'Transfer keys of a refresh operation (the data revealed to the 
exchange).';
-COMMENT ON COLUMN refresh_transfer_keys.rtc_serial
-  IS 'needed for exchange-auditor replication logic';
-COMMENT ON COLUMN refresh_transfer_keys.melt_serial_id
-  IS 'Identifies the refresh commitment (rc) of the operation.';
-COMMENT ON COLUMN refresh_transfer_keys.transfer_pub
-  IS 'transfer public key for the gamma index';
-COMMENT ON COLUMN refresh_transfer_keys.transfer_privs
-  IS 'array of TALER_CNC_KAPPA - 1 transfer private keys that have been 
revealed, with the gamma entry being skipped';
-
-CREATE TABLE IF NOT EXISTS refresh_transfer_keys_default
-  PARTITION OF refresh_transfer_keys
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_refresh_transfer_keys_partition('default');
-
-
--- ------------------------------ policy_fulfillments 
-------------------------------------
-
-CREATE TABLE IF NOT EXISTS policy_fulfillments
-  (fulfillment_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE PRIMARY KEY
-  ,fulfillment_timestamp INT8 NOT NULL
-  ,fulfillment_proof VARCHAR
-  ,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))
-  );
-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';
-
--- ------------------------------ policy_details 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS policy_details
-  (policy_details_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY
-  ,policy_hash_code BYTEA PRIMARY KEY CHECK(LENGTH(policy_hash_code)=16)
-  ,policy_json VARCHAR
-  ,deadline INT8 NOT NULL
-  ,commitment_val INT8 NOT NULL
-  ,commitment_frac INT4 NOT NULL
-  ,accumulated_total_val INT8 NOT NULL
-  ,accumulated_total_frac INT4 NOT NULL
-  ,fee_val INT8 NOT NULL
-  ,fee_frac INT4 NOT NULL
-  ,transferable_val INT8 NOT NULL
-  ,transferable_frac INT8 NOT NULL
-  ,fulfillment_state smallint NOT NULL CHECK(fulfillment_state between 0 and 5)
-  ,fulfillment_id BIGINT NULL REFERENCES policy_fulfillments (fulfillment_id) 
ON DELETE CASCADE
-  );
-COMMENT ON TABLE policy_details
-  IS 'Policies that were provided with deposits via policy extensions.';
-COMMENT ON COLUMN policy_details.policy_hash_code
-  IS 'ID (GNUNET_HashCode) that identifies a policy.  Will be calculated by 
the policy extension based on the content';
-COMMENT ON COLUMN policy_details.policy_json
-  IS 'JSON object with options set that the exchange needs to consider when 
executing a deposit. Supported details depend on the policy extensions 
supported by the exchange.';
-COMMENT ON COLUMN policy_details.deadline
-  IS 'Deadline until the policy must be marked as fulfilled (maybe "forever")';
-COMMENT ON COLUMN policy_details.commitment_val
-  IS 'The amount that this policy commits to.  Invariant: commitment >= fee';
-COMMENT ON COLUMN policy_details.accumulated_total_val
-  IS 'The sum of all contributions of all deposit that reference this policy.  
Invariant: The fulfilment_state must be Insufficient as long as 
accumulated_total < commitment';
-COMMENT ON COLUMN policy_details.fee_val
-  IS 'The fee for this policy, due when the policy is fulfilled or timed out';
-COMMENT ON COLUMN policy_details.transferable_val
-  IS 'The amount that on fulfillment or timeout will be transferred to the 
payto-URI''s of the corresponding deposit''s.  The policy fees must have been 
already deducted from it.  Invariant: fee+transferable <= accumulated_total.  
The remaining amount (accumulated_total - fee - transferable) can be refreshed 
by the owner of the coins when the state is Timeout or Success.';
-COMMENT ON COLUMN policy_details.fulfillment_state
-  IS 'State of the fulfillment:
-       - 0 (Failure)
-       - 1 (Insufficient)
-       - 2 (Ready)
-       - 4 (Success)
-       - 5 (Timeout)';
-COMMENT ON COLUMN policy_details.fulfillment_id
-  IS 'Reference to the proof of the fulfillment of this policy, if it exists.  
Invariant: If not NULL, this entry''s .hash_code MUST be part of the 
corresponding policy_fulfillments.policy_hash_codes array.';
-
--- ------------------------------ deposits 
----------------------------------------
-
-SELECT create_table_deposits();
-
-COMMENT ON TABLE deposits
-  IS 'Deposits we have received and for which we need to make (aggregate) wire 
transfers (and manage refunds).';
-COMMENT ON COLUMN deposits.shard
-  IS 'Used for load sharding in the materialized indices. Should be set based 
on merchant_pub. 64-bit value because we need an *unsigned* 32-bit value.';
-COMMENT ON COLUMN deposits.known_coin_id
-  IS 'Used for garbage collection';
-COMMENT ON COLUMN deposits.wire_target_h_payto
-  IS 'Identifies the target bank account and KYC status';
-COMMENT ON COLUMN deposits.wire_salt
-  IS 'Salt used when hashing the payto://-URI to get the h_wire';
-COMMENT ON COLUMN deposits.done
-  IS 'Set to TRUE once we have included this deposit in some aggregate wire 
transfer to the merchant';
-COMMENT ON COLUMN deposits.policy_blocked
-  IS 'True if the aggregation of the deposit is currently blocked by some 
policy extension mechanism. Used to filter out deposits that must not be 
processed by the canonical deposit logic.';
-COMMENT ON COLUMN deposits.policy_details_serial_id
-  IS 'References policy extensions table, NULL if extensions are not used';
-
-CREATE TABLE IF NOT EXISTS deposits_default
-  PARTITION OF deposits
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_deposits_partition('default');
-
-
-SELECT create_table_deposits_by_ready();
-
-COMMENT ON TABLE deposits_by_ready
-  IS 'Enables fast lookups for deposits_get_ready, auto-populated via TRIGGER 
below';
-
-CREATE TABLE IF NOT EXISTS deposits_by_ready_default
-  PARTITION OF deposits_by_ready
-  DEFAULT;
-
-
-SELECT create_table_deposits_for_matching();
-
-COMMENT ON TABLE deposits_for_matching
-  IS 'Enables fast lookups for deposits_iterate_matching, auto-populated via 
TRIGGER below';
-
-CREATE TABLE IF NOT EXISTS deposits_for_matching_default
-  PARTITION OF deposits_for_matching
-  DEFAULT;
-
-
-CREATE OR REPLACE FUNCTION deposits_insert_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-DECLARE
-  is_ready BOOLEAN;
-BEGIN
-  is_ready  = NOT (NEW.done OR NEW.policy_blocked);
-
-  IF (is_ready)
-  THEN
-    INSERT INTO exchange.deposits_by_ready
-      (wire_deadline
-      ,shard
-      ,coin_pub
-      ,deposit_serial_id)
-    VALUES
-      (NEW.wire_deadline
-      ,NEW.shard
-      ,NEW.coin_pub
-      ,NEW.deposit_serial_id);
-    INSERT INTO exchange.deposits_for_matching
-      (refund_deadline
-      ,merchant_pub
-      ,coin_pub
-      ,deposit_serial_id)
-    VALUES
-      (NEW.refund_deadline
-      ,NEW.merchant_pub
-      ,NEW.coin_pub
-      ,NEW.deposit_serial_id);
-  END IF;
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION deposits_insert_trigger()
-  IS 'Replicate deposit inserts into materialized indices.';
-
-CREATE TRIGGER deposits_on_insert
-  AFTER INSERT
-   ON deposits
-   FOR EACH ROW EXECUTE FUNCTION deposits_insert_trigger();
-
-CREATE OR REPLACE FUNCTION deposits_update_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-DECLARE
-  was_ready BOOLEAN;
-DECLARE
-  is_ready BOOLEAN;
-BEGIN
-  was_ready = NOT (OLD.done OR OLD.policy_blocked);
-  is_ready  = NOT (NEW.done OR NEW.policy_blocked);
-  IF (was_ready AND NOT is_ready)
-  THEN
-    DELETE FROM exchange.deposits_by_ready
-     WHERE wire_deadline = OLD.wire_deadline
-       AND shard = OLD.shard
-       AND coin_pub = OLD.coin_pub
-       AND deposit_serial_id = OLD.deposit_serial_id;
-    DELETE FROM exchange.deposits_for_matching
-     WHERE refund_deadline = OLD.refund_deadline
-       AND merchant_pub = OLD.merchant_pub
-       AND coin_pub = OLD.coin_pub
-       AND deposit_serial_id = OLD.deposit_serial_id;
-  END IF;
-  IF (is_ready AND NOT was_ready)
-  THEN
-    INSERT INTO exchange.deposits_by_ready
-      (wire_deadline
-      ,shard
-      ,coin_pub
-      ,deposit_serial_id)
-    VALUES
-      (NEW.wire_deadline
-      ,NEW.shard
-      ,NEW.coin_pub
-      ,NEW.deposit_serial_id);
-    INSERT INTO exchange.deposits_for_matching
-      (refund_deadline
-      ,merchant_pub
-      ,coin_pub
-      ,deposit_serial_id)
-    VALUES
-      (NEW.refund_deadline
-      ,NEW.merchant_pub
-      ,NEW.coin_pub
-      ,NEW.deposit_serial_id);
-  END IF;
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION deposits_update_trigger()
-  IS 'Replicate deposits changes into materialized indices.';
-
-CREATE TRIGGER deposits_on_update
-  AFTER UPDATE
-    ON deposits
-   FOR EACH ROW EXECUTE FUNCTION deposits_update_trigger();
-
-CREATE OR REPLACE FUNCTION deposits_delete_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-DECLARE
-  was_ready BOOLEAN;
-BEGIN
-  was_ready  = NOT (OLD.done OR OLD.policy_blocked);
-
-  IF (was_ready)
-  THEN
-    DELETE FROM exchange.deposits_by_ready
-     WHERE wire_deadline = OLD.wire_deadline
-       AND shard = OLD.shard
-       AND coin_pub = OLD.coin_pub
-       AND deposit_serial_id = OLD.deposit_serial_id;
-    DELETE FROM exchange.deposits_for_matching
-     WHERE refund_deadline = OLD.refund_deadline
-       AND merchant_pub = OLD.merchant_pub
-       AND coin_pub = OLD.coin_pub
-       AND deposit_serial_id = OLD.deposit_serial_id;
-  END IF;
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION deposits_delete_trigger()
-  IS 'Replicate deposit deletions into materialized indices.';
-
-CREATE TRIGGER deposits_on_delete
-  AFTER DELETE
-   ON deposits
-   FOR EACH ROW EXECUTE FUNCTION deposits_delete_trigger();
-
-
--- ------------------------------ refunds 
----------------------------------------
-
-SELECT create_table_refunds();
-
-COMMENT ON TABLE refunds
-  IS 'Data on coins that were refunded. Technically, refunds always apply 
against specific deposit operations involving a coin. The combination of 
coin_pub, merchant_pub, h_contract_terms and rtransaction_id MUST be unique, 
and we usually select by coin_pub so that one goes first.';
-COMMENT ON COLUMN refunds.deposit_serial_id
-  IS 'Identifies ONLY the merchant_pub, h_contract_terms and coin_pub. 
Multiple deposits may match a refund, this only identifies one of them.';
-COMMENT ON COLUMN refunds.rtransaction_id
-  IS 'used by the merchant to make refunds unique in case the same coin for 
the same deposit gets a subsequent (higher) refund';
-
-CREATE TABLE IF NOT EXISTS refunds_default
-  PARTITION OF refunds
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_refunds_partition('default');
-
-
--- ------------------------------ wire_out 
----------------------------------------
-
-SELECT create_table_wire_out();
-
-COMMENT ON TABLE wire_out
-  IS 'wire transfers the exchange has executed';
-COMMENT ON COLUMN wire_out.exchange_account_section
-  IS 'identifies the configuration section with the debit account of this 
payment';
-COMMENT ON COLUMN wire_out.wire_target_h_payto
-  IS 'Identifies the credited bank account and KYC status';
-
-CREATE TABLE IF NOT EXISTS wire_out_default
-  PARTITION OF wire_out
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wire_out_partition('default');
-
-CREATE OR REPLACE FUNCTION wire_out_delete_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  DELETE FROM exchange.aggregation_tracking
-   WHERE wtid_raw = OLD.wtid_raw;
-  RETURN OLD;
-END $$;
-COMMENT ON FUNCTION wire_out_delete_trigger()
-  IS 'Replicate reserve_out deletions into aggregation_tracking. This replaces 
an earlier use of an ON DELETE CASCADE that required a DEFERRABLE constraint 
and conflicted with nice partitioning.';
-
-CREATE TRIGGER wire_out_on_delete
-  AFTER DELETE
-    ON wire_out
-   FOR EACH ROW EXECUTE FUNCTION wire_out_delete_trigger();
-
-
-
--- ------------------------------ aggregation_transient 
----------------------------------------
-
-SELECT create_table_aggregation_transient();
-
-COMMENT ON TABLE aggregation_transient
-  IS 'aggregations currently happening (lacking wire_out, usually because the 
amount is too low); this table is not replicated';
-COMMENT ON COLUMN aggregation_transient.amount_val
-  IS 'Sum of all of the aggregated deposits (without deposit fees)';
-COMMENT ON COLUMN aggregation_transient.wtid_raw
-  IS 'identifier of the wire transfer';
-
-CREATE TABLE IF NOT EXISTS aggregation_transient_default
-  PARTITION OF aggregation_transient
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-
--- ------------------------------ aggregation_tracking 
----------------------------------------
-
-SELECT create_table_aggregation_tracking();
-
-COMMENT ON TABLE aggregation_tracking
-  IS 'mapping from wire transfer identifiers (WTID) to deposits (and back)';
-COMMENT ON COLUMN aggregation_tracking.wtid_raw
-  IS 'identifier of the wire transfer';
-
-CREATE TABLE IF NOT EXISTS aggregation_tracking_default
-  PARTITION OF aggregation_tracking
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_aggregation_tracking_partition('default');
-
-
--- ------------------------------ wire_fee 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS wire_fee
-  (wire_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,wire_method VARCHAR NOT NULL
-  ,start_date INT8 NOT NULL
-  ,end_date INT8 NOT NULL
-  ,wire_fee_val INT8 NOT NULL
-  ,wire_fee_frac INT4 NOT NULL
-  ,closing_fee_val INT8 NOT NULL
-  ,closing_fee_frac INT4 NOT NULL
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,PRIMARY KEY (wire_method, start_date)
-  );
-COMMENT ON TABLE wire_fee
-  IS 'list of the wire fees of this exchange, by date';
-COMMENT ON COLUMN wire_fee.wire_fee_serial
-  IS 'needed for exchange-auditor replication logic';
-
-CREATE INDEX IF NOT EXISTS wire_fee_by_end_date_index
-  ON wire_fee
-  (end_date);
-
-
--- ------------------------------ global_fee 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS global_fee
-  (global_fee_serial BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,start_date INT8 NOT NULL
-  ,end_date INT8 NOT NULL
-  ,history_fee_val INT8 NOT NULL
-  ,history_fee_frac INT4 NOT NULL
-  ,account_fee_val INT8 NOT NULL
-  ,account_fee_frac INT4 NOT NULL
-  ,purse_fee_val INT8 NOT NULL
-  ,purse_fee_frac INT4 NOT NULL
-  ,purse_timeout INT8 NOT NULL
-  ,history_expiration INT8 NOT NULL
-  ,purse_account_limit INT4 NOT NULL
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,PRIMARY KEY (start_date)
-  );
-COMMENT ON TABLE global_fee
-  IS 'list of the global fees of this exchange, by date';
-COMMENT ON COLUMN global_fee.global_fee_serial
-  IS 'needed for exchange-auditor replication logic';
-
-CREATE INDEX IF NOT EXISTS global_fee_by_end_date_index
-  ON global_fee
-  (end_date);
-
-
--- ------------------------------ recoup 
----------------------------------------
-
-SELECT create_table_recoup();
-
-COMMENT ON TABLE recoup
-  IS 'Information about recoups that were executed between a coin and a 
reserve. In this type of recoup, the amount is credited back to the reserve 
from which the coin originated.';
-COMMENT ON COLUMN recoup.coin_pub
-  IS 'Coin that is being debited in the recoup. Do not CASCADE ON DROP on the 
coin_pub, as we may keep the coin alive!';
-COMMENT ON COLUMN recoup.reserve_out_serial_id
-  IS 'Identifies the h_blind_ev of the recouped coin and provides the link to 
the credited reserve.';
-COMMENT ON COLUMN recoup.coin_sig
-  IS 'Signature by the coin affirming the recoup, of type 
TALER_SIGNATURE_WALLET_COIN_RECOUP';
-COMMENT ON COLUMN recoup.coin_blind
-  IS 'Denomination blinding key used when creating the blinded coin from the 
planchet. Secret revealed during the recoup to provide the linkage between the 
coin and the withdraw operation.';
-
-CREATE TABLE IF NOT EXISTS recoup_default
-  PARTITION OF recoup
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_recoup_partition('default');
-
-
-SELECT create_table_recoup_by_reserve();
-
-COMMENT ON TABLE recoup_by_reserve
-  IS 'Information in this table is strictly redundant with that of recoup, but 
saved by a different primary key for fast lookups by reserve_out_serial_id.';
-
-CREATE TABLE IF NOT EXISTS recoup_by_reserve_default
-  PARTITION OF recoup_by_reserve
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-CREATE OR REPLACE FUNCTION recoup_insert_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  INSERT INTO exchange.recoup_by_reserve
-    (reserve_out_serial_id
-    ,coin_pub)
-  VALUES
-    (NEW.reserve_out_serial_id
-    ,NEW.coin_pub);
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION recoup_insert_trigger()
-  IS 'Replicate recoup inserts into recoup_by_reserve table.';
-
-CREATE TRIGGER recoup_on_insert
-  AFTER INSERT
-   ON recoup
-   FOR EACH ROW EXECUTE FUNCTION recoup_insert_trigger();
-
-CREATE OR REPLACE FUNCTION recoup_delete_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  DELETE FROM exchange.recoup_by_reserve
-   WHERE reserve_out_serial_id = OLD.reserve_out_serial_id
-     AND coin_pub = OLD.coin_pub;
-  RETURN OLD;
-END $$;
-COMMENT ON FUNCTION recoup_delete_trigger()
-  IS 'Replicate recoup deletions into recoup_by_reserve table.';
-
-CREATE TRIGGER recoup_on_delete
-  AFTER DELETE
-    ON recoup
-   FOR EACH ROW EXECUTE FUNCTION recoup_delete_trigger();
-
-
--- ------------------------------ recoup_refresh 
----------------------------------------
-
-SELECT create_table_recoup_refresh();
-
-COMMENT ON TABLE recoup_refresh
-  IS 'Table of coins that originated from a refresh operation and that were 
recouped. Links the (fresh) coin to the melted operation (and thus the old 
coin). A recoup on a refreshed coin credits the old coin and debits the fresh 
coin.';
-COMMENT ON COLUMN recoup_refresh.coin_pub
-  IS 'Refreshed coin of a revoked denomination where the residual value is 
credited to the old coin. Do not CASCADE ON DROP on the coin_pub, as we may 
keep the coin alive!';
-COMMENT ON COLUMN recoup_refresh.known_coin_id
-  IS 'FIXME: (To be) used for garbage collection (in the future)';
-COMMENT ON COLUMN recoup_refresh.rrc_serial
-  IS 'Link to the refresh operation. Also identifies the h_blind_ev of the 
recouped coin (as h_coin_ev).';
-COMMENT ON COLUMN recoup_refresh.coin_blind
-  IS 'Denomination blinding key used when creating the blinded coin from the 
planchet. Secret revealed during the recoup to provide the linkage between the 
coin and the refresh operation.';
-
-CREATE TABLE IF NOT EXISTS recoup_refresh_default
-  PARTITION OF recoup_refresh
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_recoup_refresh_partition('default');
-
-
--- ------------------------------ prewire 
----------------------------------------
-
-SELECT create_table_prewire();
-
-COMMENT ON TABLE prewire
-  IS 'pre-commit data for wire transfers we are about to execute';
-COMMENT ON COLUMN prewire.failed
-  IS 'set to TRUE if the bank responded with a non-transient failure to our 
transfer request';
-COMMENT ON COLUMN prewire.finished
-  IS 'set to TRUE once bank confirmed receiving the wire transfer request';
-COMMENT ON COLUMN prewire.buf
-  IS 'serialized data to send to the bank to execute the wire transfer';
-
-CREATE TABLE IF NOT EXISTS prewire_default
-  PARTITION OF prewire
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-
--- ------------------------------ wire_accounts 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS wire_accounts
-  (payto_uri VARCHAR PRIMARY KEY
-  ,master_sig BYTEA CHECK (LENGTH(master_sig)=64)
-  ,is_active BOOLEAN NOT NULL
-  ,last_change INT8 NOT NULL
-  );
-COMMENT ON TABLE wire_accounts
-  IS 'Table with current and historic bank accounts of the exchange. Entries 
never expire as we need to remember the last_change column indefinitely.';
-COMMENT ON COLUMN wire_accounts.payto_uri
-  IS 'payto URI (RFC 8905) with the bank account of the exchange.';
-COMMENT ON COLUMN wire_accounts.master_sig
-  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS';
-COMMENT ON COLUMN wire_accounts.is_active
-  IS 'true if we are currently supporting the use of this account.';
-COMMENT ON COLUMN wire_accounts.last_change
-  IS 'Latest time when active status changed. Used to detect replays of old 
messages.';
--- "wire_accounts" has no sequence because it is a 'mutable' table
---            and is of no concern to the auditor
-
-
--- ------------------------------ cs_nonce_locks 
----------------------------------------
-
-SELECT create_table_cs_nonce_locks();
-
-COMMENT ON TABLE cs_nonce_locks
-  IS 'ensures a Clause Schnorr client nonce is locked for use with an 
operation identified by a hash';
-COMMENT ON COLUMN cs_nonce_locks.nonce
-  IS 'actual nonce submitted by the client';
-COMMENT ON COLUMN cs_nonce_locks.op_hash
-  IS 'hash (RC for refresh, blind coin hash for withdraw) the nonce may be 
used with';
-COMMENT ON COLUMN cs_nonce_locks.max_denomination_serial
-  IS 'Maximum number of a CS denomination serial the nonce could be used with, 
for GC';
-
-CREATE TABLE IF NOT EXISTS cs_nonce_locks_default
-  PARTITION OF cs_nonce_locks
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_cs_nonce_locks_partition('default');
-
-
--- ------------------------------ work_shards 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS work_shards
-  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,last_attempt INT8 NOT NULL
-  ,start_row INT8 NOT NULL
-  ,end_row INT8 NOT NULL
-  ,completed BOOLEAN NOT NULL DEFAULT FALSE
-  ,job_name VARCHAR NOT NULL
-  ,PRIMARY KEY (job_name, start_row)
-  );
-COMMENT ON TABLE work_shards
-  IS 'coordinates work between multiple processes working on the same job';
-COMMENT ON COLUMN work_shards.shard_serial_id
-  IS 'unique serial number identifying the shard';
-COMMENT ON COLUMN work_shards.last_attempt
-  IS 'last time a worker attempted to work on the shard';
-COMMENT ON COLUMN work_shards.completed
-  IS 'set to TRUE once the shard is finished by a worker';
-COMMENT ON COLUMN work_shards.start_row
-  IS 'row at which the shard scope starts, inclusive';
-COMMENT ON COLUMN work_shards.end_row
-  IS 'row at which the shard scope ends, exclusive';
-COMMENT ON COLUMN work_shards.job_name
-  IS 'unique name of the job the workers on this shard are performing';
-
-CREATE INDEX IF NOT EXISTS work_shards_by_job_name_completed_last_attempt_index
-  ON work_shards
-  (job_name
-  ,completed
-  ,last_attempt ASC
-  );
-
-
--- ------------------------------ revolving_work_shards 
----------------------------------------
-
-CREATE UNLOGGED TABLE IF NOT EXISTS revolving_work_shards
-  (shard_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,last_attempt INT8 NOT NULL
-  ,start_row INT4 NOT NULL
-  ,end_row INT4 NOT NULL
-  ,active BOOLEAN NOT NULL DEFAULT FALSE
-  ,job_name VARCHAR NOT NULL
-  ,PRIMARY KEY (job_name, start_row)
-  );
-COMMENT ON TABLE revolving_work_shards
-  IS 'coordinates work between multiple processes working on the same job with 
partitions that need to be repeatedly processed; unlogged because on system 
crashes the locks represented by this table will have to be cleared anyway, 
typically using "taler-exchange-dbinit -s"';
-COMMENT ON COLUMN revolving_work_shards.shard_serial_id
-  IS 'unique serial number identifying the shard';
-COMMENT ON COLUMN revolving_work_shards.last_attempt
-  IS 'last time a worker attempted to work on the shard';
-COMMENT ON COLUMN revolving_work_shards.active
-  IS 'set to TRUE when a worker is active on the shard';
-COMMENT ON COLUMN revolving_work_shards.start_row
-  IS 'row at which the shard scope starts, inclusive';
-COMMENT ON COLUMN revolving_work_shards.end_row
-  IS 'row at which the shard scope ends, exclusive';
-COMMENT ON COLUMN revolving_work_shards.job_name
-  IS 'unique name of the job the workers on this shard are performing';
-
-CREATE INDEX IF NOT EXISTS 
revolving_work_shards_by_job_name_active_last_attempt_index
-  ON revolving_work_shards
-  (job_name
-  ,active
-  ,last_attempt
-  );
-
---------------------------------------------------------------------------
---                        Tables for P2P payments
---------------------------------------------------------------------------
-
--- ------------------------------ partners 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS partners
-  (partner_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY UNIQUE
-  ,partner_master_pub BYTEA NOT NULL CHECK(LENGTH(partner_master_pub)=32)
-  ,start_date INT8 NOT NULL
-  ,end_date INT8 NOT NULL
-  ,next_wad INT8 NOT NULL DEFAULT (0)
-  ,wad_frequency INT8 NOT NULL
-  ,wad_fee_val INT8 NOT NULL
-  ,wad_fee_frac INT4 NOT NULL
-  ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
-  ,partner_base_url TEXT NOT NULL
-  );
-COMMENT ON TABLE partners
-  IS 'exchanges we do wad transfers to';
-COMMENT ON COLUMN partners.partner_master_pub
-  IS 'offline master public key of the partner';
-COMMENT ON COLUMN partners.start_date
-  IS 'starting date of the partnership';
-COMMENT ON COLUMN partners.end_date
-  IS 'end date of the partnership';
-COMMENT ON COLUMN partners.next_wad
-  IS 'at what time should we do the next wad transfer to this partner 
(frequently updated); set to forever after the end_date';
-COMMENT ON COLUMN partners.wad_frequency
-  IS 'how often do we promise to do wad transfers';
-COMMENT ON COLUMN partners.wad_fee_val
-  IS 'how high is the fee for a wallet to be added to a wad to this partner';
-COMMENT ON COLUMN partners.partner_base_url
-  IS 'base URL of the REST API for this partner';
-COMMENT ON COLUMN partners.master_sig
-  IS 'signature of our master public key affirming the partnership, of purpose 
TALER_SIGNATURE_MASTER_PARTNER_DETAILS';
-
-CREATE INDEX IF NOT EXISTS partner_by_wad_time
-  ON partners (next_wad ASC);
-
--- ------------------------------ purse_requests 
----------------------------------------
-
-SELECT create_table_purse_requests();
-
-COMMENT ON TABLE purse_requests
-  IS 'Requests establishing purses, associating them with a contract but 
without a target reserve';
-COMMENT ON COLUMN purse_requests.purse_pub
-  IS 'Public key of the purse';
-COMMENT ON COLUMN purse_requests.purse_creation
-  IS 'Local time when the purse was created. Determines applicable purse 
fees.';
-COMMENT ON COLUMN purse_requests.purse_expiration
-  IS 'When the purse is set to expire';
-COMMENT ON COLUMN purse_requests.h_contract_terms
-  IS 'Hash of the contract the parties are to agree to';
-COMMENT ON COLUMN purse_requests.flags
-  IS 'see the enum TALER_WalletAccountMergeFlags';
-COMMENT ON COLUMN purse_requests.in_reserve_quota
-  IS 'set to TRUE if this purse currently counts against the number of free 
purses in the respective reserve';
-COMMENT ON COLUMN purse_requests.amount_with_fee_val
-  IS 'Total amount expected to be in the purse';
-COMMENT ON COLUMN purse_requests.purse_fee_val
-  IS 'Purse fee the client agreed to pay from the reserve (accepted by the 
exchange at the time the purse was created). Zero if in_reserve_quota is TRUE.';
-COMMENT ON COLUMN purse_requests.balance_val
-  IS 'Total amount actually in the purse';
-COMMENT ON COLUMN purse_requests.purse_sig
-  IS 'Signature of the purse affirming the purse parameters, of type 
TALER_SIGNATURE_PURSE_REQUEST';
-
-CREATE TABLE IF NOT EXISTS purse_requests_default
-  PARTITION OF purse_requests
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_purse_requests_partition('default');
-
-
--- ------------------------------ purse_decisions 
----------------------------------------
-
-SELECT create_table_purse_decision();
-
-COMMENT ON TABLE purse_decision
-  IS 'Purses that were decided upon (refund or merge)';
-COMMENT ON COLUMN purse_decision.purse_pub
-  IS 'Public key of the purse';
-
-CREATE TABLE IF NOT EXISTS purse_decision_default
-  PARTITION OF purse_decision
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_purse_decision_partition('default');
-
-
--- ------------------------------ 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';
-
-CREATE TABLE IF NOT EXISTS purse_merges_default
-  PARTITION OF purse_merges
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_purse_merges_partition('default');
-
-
--- ------------------------------ account_merges 
----------------------------------------
-
-SELECT create_table_account_merges();
-
-COMMENT ON TABLE account_merges
-  IS 'Merge requests where a purse- and account-owner requested merging the 
purse into the account';
-COMMENT ON COLUMN account_merges.reserve_pub
-  IS 'public key of the target reserve';
-COMMENT ON COLUMN account_merges.purse_pub
-  IS 'public key of the purse';
-COMMENT ON COLUMN account_merges.reserve_sig
-  IS 'signature by the reserve private key affirming the merge, of type 
TALER_SIGNATURE_WALLET_ACCOUNT_MERGE';
-
-CREATE TABLE IF NOT EXISTS account_merges_default
-  PARTITION OF account_merges
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_account_merges_partition('default');
-
-
--- ------------------------------ contracts 
----------------------------------------
-
-SELECT create_table_contracts();
-
-COMMENT ON TABLE contracts
-  IS 'encrypted contracts associated with purses';
-COMMENT ON COLUMN contracts.purse_pub
-  IS 'public key of the purse that the contract is associated with';
-COMMENT ON COLUMN contracts.contract_sig
-  IS 'signature over the encrypted contract by the purse contract key';
-COMMENT ON COLUMN contracts.pub_ckey
-  IS 'Public ECDH key used to encrypt the contract, to be used with the purse 
private key for decryption';
-COMMENT ON COLUMN contracts.e_contract
-  IS 'AES-GCM encrypted contract terms (contains gzip compressed JSON after 
decryption)';
-
-CREATE TABLE IF NOT EXISTS contracts_default
-  PARTITION OF contracts
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_contracts_partition('default');
-
-
--- ------------------------------ history_requests 
----------------------------------------
-
-SELECT create_table_history_requests();
-
-COMMENT ON TABLE history_requests
-  IS 'Paid history requests issued by a client against a reserve';
-COMMENT ON COLUMN history_requests.request_timestamp
-  IS 'When was the history request made';
-COMMENT ON COLUMN history_requests.reserve_sig
-  IS 'Signature approving payment for the history request';
-COMMENT ON COLUMN history_requests.history_fee_val
-  IS 'History fee approved by the signature';
-
-CREATE TABLE IF NOT EXISTS history_requests_default
-  PARTITION OF history_requests
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
--- ------------------------------ close_requests 
----------------------------------------
-
-SELECT create_table_close_requests();
-
-COMMENT ON TABLE close_requests
-  IS 'Explicit requests by a reserve owner to close a reserve immediately';
-COMMENT ON COLUMN close_requests.close_timestamp
-  IS 'When the request was created by the client';
-COMMENT ON COLUMN close_requests.reserve_sig
-  IS 'Signature affirming that the reserve is to be closed';
-COMMENT ON COLUMN close_requests.close_val
-  IS 'Balance of the reserve at the time of closing, to be wired to the 
associated bank account (minus the closing fee)';
-COMMENT ON COLUMN close_requests.payto_uri
-  IS 'Identifies the credited bank account. Optional.';
-
-CREATE TABLE IF NOT EXISTS close_requests_default
-  PARTITION OF close_requests
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_close_requests_partition('default');
-
--- ------------------------------ purse_deposits 
----------------------------------------
-
-SELECT create_table_purse_deposits();
-
-COMMENT ON TABLE purse_deposits
-  IS 'Requests depositing coins into a purse';
-COMMENT ON COLUMN purse_deposits.partner_serial_id
-  IS 'identifies the partner exchange, NULL in case the target purse lives at 
this exchange';
-COMMENT ON COLUMN purse_deposits.purse_pub
-  IS 'Public key of the purse';
-COMMENT ON COLUMN purse_deposits.coin_pub
-  IS 'Public key of the coin being deposited';
-COMMENT ON COLUMN purse_deposits.amount_with_fee_val
-  IS 'Total amount being deposited';
-COMMENT ON COLUMN purse_deposits.coin_sig
-  IS 'Signature of the coin affirming the deposit into the purse, of type 
TALER_SIGNATURE_PURSE_DEPOSIT';
-
-CREATE TABLE IF NOT EXISTS purse_deposits_default
-  PARTITION OF purse_deposits
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_purse_deposits_partition('default');
-
-
--- ------------------------------ wads_out 
----------------------------------------
-
-SELECT create_table_wads_out();
-
-COMMENT ON TABLE wads_out
-  IS 'Wire transfers made to another exchange to transfer purse funds';
-COMMENT ON COLUMN wads_out.wad_id
-  IS 'Unique identifier of the wad, part of the wire transfer subject';
-COMMENT ON COLUMN wads_out.partner_serial_id
-  IS 'target exchange of the wad';
-COMMENT ON COLUMN wads_out.amount_val
-  IS 'Amount that was wired';
-COMMENT ON COLUMN wads_out.execution_time
-  IS 'Time when the wire transfer was scheduled';
-
-CREATE TABLE IF NOT EXISTS wads_out_default
-  PARTITION OF wads_out
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wads_out_partition('default');
-
-
--- ------------------------------ wads_out_entries 
----------------------------------------
-
-SELECT create_table_wad_out_entries();
-
-COMMENT ON TABLE wad_out_entries
-  IS 'Purses combined into a wad';
-COMMENT ON COLUMN wad_out_entries.wad_out_serial_id
-  IS 'Wad the purse was part of';
-COMMENT ON COLUMN wad_out_entries.reserve_pub
-  IS 'Target reserve for the purse';
-COMMENT ON COLUMN wad_out_entries.purse_pub
-  IS 'Public key of the purse';
-COMMENT ON COLUMN wad_out_entries.h_contract
-  IS 'Hash of the contract associated with the purse';
-COMMENT ON COLUMN wad_out_entries.purse_expiration
-  IS 'Time when the purse expires';
-COMMENT ON COLUMN wad_out_entries.merge_timestamp
-  IS 'Time when the merge was approved';
-COMMENT ON COLUMN wad_out_entries.amount_with_fee_val
-  IS 'Total amount in the purse';
-COMMENT ON COLUMN wad_out_entries.wad_fee_val
-  IS 'Wat fee charged to the purse';
-COMMENT ON COLUMN wad_out_entries.deposit_fees_val
-  IS 'Total deposit fees charged to the purse';
-COMMENT ON COLUMN wad_out_entries.reserve_sig
-  IS 'Signature by the receiving reserve, of purpose 
TALER_SIGNATURE_ACCOUNT_MERGE';
-COMMENT ON COLUMN wad_out_entries.purse_sig
-  IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE';
-
-CREATE TABLE IF NOT EXISTS wad_out_entries_default
-  PARTITION OF wad_out_entries
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wad_out_entries_partition('default');
-
--- ------------------------------ wads_in 
----------------------------------------
-
-SELECT create_table_wads_in();
-
-COMMENT ON TABLE wads_in
-  IS 'Incoming exchange-to-exchange wad wire transfers';
-COMMENT ON COLUMN wads_in.wad_id
-  IS 'Unique identifier of the wad, part of the wire transfer subject';
-COMMENT ON COLUMN wads_in.origin_exchange_url
-  IS 'Base URL of the originating URL, also part of the wire transfer subject';
-COMMENT ON COLUMN wads_in.amount_val
-  IS 'Actual amount that was received by our exchange';
-COMMENT ON COLUMN wads_in.arrival_time
-  IS 'Time when the wad was received';
-
-CREATE TABLE IF NOT EXISTS wads_in_default
-  PARTITION OF wads_in
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wads_in_partition('default');
-
-
--- ------------------------------ wads_in_entries 
----------------------------------------
-
-SELECT create_table_wad_in_entries();
-
-COMMENT ON TABLE wad_in_entries
-  IS 'list of purses aggregated in a wad according to the sending exchange';
-COMMENT ON COLUMN wad_in_entries.wad_in_serial_id
-  IS 'wad for which the given purse was included in the aggregation';
-COMMENT ON COLUMN wad_in_entries.reserve_pub
-  IS 'target account of the purse (must be at the local exchange)';
-COMMENT ON COLUMN wad_in_entries.purse_pub
-  IS 'public key of the purse that was merged';
-COMMENT ON COLUMN wad_in_entries.h_contract
-  IS 'hash of the contract terms of the purse';
-COMMENT ON COLUMN wad_in_entries.purse_expiration
-  IS 'Time when the purse was set to expire';
-COMMENT ON COLUMN wad_in_entries.merge_timestamp
-  IS 'Time when the merge was approved';
-COMMENT ON COLUMN wad_in_entries.amount_with_fee_val
-  IS 'Total amount in the purse';
-COMMENT ON COLUMN wad_in_entries.wad_fee_val
-  IS 'Total wad fees paid by the purse';
-COMMENT ON COLUMN wad_in_entries.deposit_fees_val
-  IS 'Total deposit fees paid when depositing coins into the purse';
-COMMENT ON COLUMN wad_in_entries.reserve_sig
-  IS 'Signature by the receiving reserve, of purpose 
TALER_SIGNATURE_ACCOUNT_MERGE';
-COMMENT ON COLUMN wad_in_entries.purse_sig
-  IS 'Signature by the purse of purpose TALER_SIGNATURE_PURSE_MERGE';
-
-CREATE TABLE IF NOT EXISTS wad_in_entries_default
-  PARTITION OF wad_in_entries
-  FOR VALUES WITH (MODULUS 1, REMAINDER 0);
-
-SELECT add_constraints_to_wad_in_entries_partition('default');
-
-
--- ------------------------------ partner_accounts 
----------------------------------------
-
-CREATE TABLE IF NOT EXISTS partner_accounts
-  (payto_uri VARCHAR PRIMARY KEY
-  ,partner_serial_id INT8 REFERENCES partners(partner_serial_id) ON DELETE 
CASCADE
-  ,partner_master_sig BYTEA CHECK (LENGTH(partner_master_sig)=64)
-  ,last_seen INT8 NOT NULL
-  );
-CREATE INDEX IF NOT EXISTS partner_accounts_index_by_partner_and_time
-  ON partner_accounts (partner_serial_id,last_seen);
-COMMENT ON TABLE partner_accounts
-  IS 'Table with bank accounts of the partner exchange. Entries never expire 
as we need to remember the signature for the auditor.';
-COMMENT ON COLUMN partner_accounts.payto_uri
-  IS 'payto URI (RFC 8905) with the bank account of the partner exchange.';
-COMMENT ON COLUMN partner_accounts.partner_master_sig
-  IS 'Signature of purpose TALER_SIGNATURE_MASTER_WIRE_DETAILS by the partner 
master public key';
-COMMENT ON COLUMN partner_accounts.last_seen
-  IS 'Last time we saw this account as being active at the partner exchange. 
Used to select the most recent entry, and to detect when we should check 
again.';
-
-
------------------------ router helper table (not synchronzied) 
------------------------
-
-CREATE TABLE IF NOT EXISTS purse_actions
-  (purse_pub BYTEA NOT NULL PRIMARY KEY CHECK(LENGTH(purse_pub)=32)
-  ,action_date INT8 NOT NULL
-  ,partner_serial_id INT8
-  );
-COMMENT ON TABLE purse_actions
-  IS 'purses awaiting some action by the router';
-COMMENT ON COLUMN purse_actions.purse_pub
-  IS 'public (contract) key of the purse';
-COMMENT ON COLUMN purse_actions.action_date
-  IS 'when is the purse ready for action';
-COMMENT ON COLUMN purse_actions.partner_serial_id
-  IS 'wad target of an outgoing wire transfer, 0 for local, NULL if the purse 
is unmerged and thus the target is still unknown';
-
-CREATE INDEX IF NOT EXISTS purse_action_by_target
-  ON purse_actions
-  (partner_serial_id,action_date);
-
-
-CREATE OR REPLACE FUNCTION purse_requests_insert_trigger()
-  RETURNS trigger
-  LANGUAGE plpgsql
-  AS $$
-BEGIN
-  INSERT INTO
-    purse_actions
-    (purse_pub
-    ,action_date)
-  VALUES
-    (NEW.purse_pub
-    ,NEW.purse_expiration);
-  RETURN NEW;
-END $$;
-COMMENT ON FUNCTION purse_requests_insert_trigger()
-  IS 'When a purse is created, insert it into the purse_action table to take 
action when the purse expires.';
-
-CREATE TRIGGER purse_requests_on_insert
-  AFTER INSERT
-   ON purse_requests
-   FOR EACH ROW EXECUTE FUNCTION purse_requests_insert_trigger();
-COMMENT ON TRIGGER purse_requests_on_insert
-        ON purse_requests
-  IS 'Here we install an entry for the purse expiration.';
diff --git a/src/exchangedb/exchange-0001.sql b/src/exchangedb/exchange-0001.sql
new file mode 100644
index 00000000..5ce38c28
--- /dev/null
+++ b/src/exchangedb/exchange-0001.sql
@@ -0,0 +1,297 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2022 Taler Systems SA
+--
+-- TALER is free software; you can redistribute it and/or modify it under the
+-- terms of the GNU General Public License as published by the Free Software
+-- Foundation; either version 3, or (at your option) any later version.
+--
+-- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
+-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
+-- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
+--
+-- You should have received a copy of the GNU General Public License along with
+-- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
+--
+
+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;
+
+---------------------------------------------------------------------------
+--                   General procedures for DB setup
+---------------------------------------------------------------------------
+
+CREATE TABLE exchange_tables
+  (table_serial_id BIGINT GENERATED BY DEFAULT AS IDENTITY
+  ,name VARCHAR NOT NULL
+  ,version VARCHAR NOT NULL
+  ,action VARCHAR NOT NULL
+  ,partitioned BOOL NOT NULL
+  ,by_range BOOL NOT NULL
+  ,finished BOOL NOT NULL DEFAULT(FALSE));
+COMMENT ON TABLE exchange_tables
+  IS 'Tables of the exchange and their status';
+COMMENT ON COLUMN exchange_tables.name
+  IS 'Base name of the table (without partition/shard)';
+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, 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
+  IS 'TRUE if the table is partitioned by range';
+COMMENT ON COLUMN exchange_tables.finished
+  IS 'TRUE if the respective migration has been run';
+
+
+CREATE FUNCTION create_partitioned_table(
+   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 (partition_suffix IS NULL)
+  THEN
+    -- no partitioning, disable option
+    main_table_partition_str = '';
+  ELSE
+    IF (partition_suffix::int > 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 $$;
+
+COMMENT ON FUNCTION create_partitioned_table
+  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 partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  IF ( (partition_suffix IS NOT NULL) AND
+       (partition_suffix::int > 0) )
+  THEN
+    -- sharding, add shard name
+    table_name=table_name || '_' || partition_suffix;
+  END IF;
+  EXECUTE FORMAT(
+     'COMMENT ON TABLE %s IS %s'
+    ,table_name
+    ,quote_literal(table_comment)
+  );
+END $$;
+
+COMMENT ON FUNCTION comment_partitioned_table
+  IS 'Generic function to create a comment on table that is partitioned.';
+
+
+CREATE FUNCTION comment_partitioned_column(
+   IN table_comment VARCHAR
+  ,IN column_name VARCHAR
+  ,IN table_name VARCHAR
+  ,IN partition_suffix VARCHAR DEFAULT NULL
+)
+RETURNS VOID
+LANGUAGE plpgsql
+AS $$
+BEGIN
+  IF ( (partition_suffix IS NOT NULL) AND
+       (partition_suffix::int > 0) )
+  THEN
+    -- sharding, add shard name
+    table_name=table_name || '_' || partition_suffix;
+  END IF;
+  EXECUTE FORMAT(
+     'COMMENT ON COLUMN %s.%s IS %s'
+    ,table_name
+    ,column_name
+    ,quote_literal(table_comment)
+  );
+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 do_create_tables(
+  num_partitions INTEGER
+-- NULL: no partitions, add foreign constraints
+-- 0: no partitions, no foreign constraints
+-- 1: only 1 default partition
+-- > 1: normal partitions
+)
+  RETURNS VOID
+  LANGUAGE plpgsql
+AS $$
+DECLARE
+  tc CURSOR FOR
+    SELECT table_serial_id
+          ,name
+          ,action
+          ,partitioned
+          ,by_range
+      FROM exchange.exchange_tables
+     WHERE NOT finished
+     ORDER BY table_serial_id ASC;
+BEGIN
+  FOR rec IN tc
+  LOOP
+    CASE rec.action
+    -- "create" actions apply to master and partitions
+    WHEN 'create'
+    THEN
+      IF (rec.partitioned AND
+          (num_partitions IS NOT NULL))
+      THEN
+        -- Create master table with partitioning.
+        EXECUTE FORMAT(
+          'SELECT exchange.%s_table_%s (%s)'::text
+          ,rec.action
+          ,rec.name
+          ,quote_literal('0')
+        );
+        IF (rec.by_range OR
+            (num_partitions = 0))
+        THEN
+          -- Create default partition.
+          IF (rec.by_range)
+          THEN
+            -- Range partition
+            EXECUTE FORMAT(
+              'CREATE TABLE exchange.%s_default'
+              ' PARTITION OF %s'
+              ' DEFAULT'
+             ,rec.name
+             ,rec.name
+            );
+          ELSE
+            -- Hash partition
+            EXECUTE FORMAT(
+              'CREATE TABLE exchange.%s_default'
+              ' PARTITION OF %s'
+              ' FOR VALUES WITH (MODULUS 1, REMAINDER 0)'
+             ,rec.name
+             ,rec.name
+            );
+          END IF;
+        ELSE
+          FOR i IN 1..num_partitions LOOP
+            -- Create num_partitions
+            EXECUTE FORMAT(
+               'CREATE TABLE exchange.%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(
+          'SELECT exchange.%s_table_%s ()'::text
+          ,rec.action
+          ,rec.name
+        );
+      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(
+           'SELECT exchange.%s_table_%s (NULL)'::text
+          ,rec.action
+          ,rec.name
+        );
+      ELSE
+        IF ( (num_partitions = 0) OR
+             (rec.by_range) )
+        THEN
+          -- Constrain default table
+          EXECUTE FORMAT(
+             'SELECT exchange.%s_table_%s (%s)'::text
+            ,rec.action
+            ,rec.name
+            ,quote_literal('default')
+          );
+        ELSE
+          -- Constrain each partition
+          FOR i IN 1..num_partitions LOOP
+            EXECUTE FORMAT(
+              'SELECT exchange.%s_table_%s (%s)'::text
+              ,rec.action
+              ,rec.name
+              ,quote_literal(i)
+            );
+          END LOOP;
+        END IF;
+      END IF;
+    -- Foreign actions only apply if partitioning is off
+    WHEN 'foreign'
+    THEN
+      IF (num_partitions IS NULL)
+      THEN
+        -- Add foreign constraints
+        EXECUTE FORMAT(
+          'SELECT exchange.%s_table_%s (%s)'::text
+          ,rec.action
+          ,rec.name
+          ,NULL
+        );
+      END IF;
+    WHEN 'master'
+    THEN
+      EXECUTE FORMAT(
+        'SELECT exchange.%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.exchange_tables
+       SET finished=TRUE
+     WHERE table_serial_id=rec.table_serial_id;
+  END LOOP; -- create/alter/drop actions
+END $$;
+
+COMMENT ON FUNCTION do_create_tables
+  IS 'Creates all tables for the given number of partitions that need 
creating. Does NOT support sharding.';
+
+
+COMMIT;
diff --git a/src/exchangedb/exchange-0002.sql.in 
b/src/exchangedb/exchange-0002.sql.in
index b25555ce..1d28f63a 100644
--- a/src/exchangedb/exchange-0002.sql.in
+++ b/src/exchangedb/exchange-0002.sql.in
@@ -14,17 +14,62 @@
 -- 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 "common-0002.sql"
-#include "exchange-0002-part.sql"
+#include "0002-denominations.sql"
+#include "0002-denomination_revocations.sql"
+#include "0002-wire_targets.sql"
+#include "0002-kyc_alerts.sql"
+#include "0002-wire_fee.sql"
+#include "0002-global_fee.sql"
+#include "0002-wire_accounts.sql"
+#include "0002-auditors.sql"
+#include "0002-auditor_denom_sigs.sql"
+#include "0002-exchange_sign_keys.sql"
+#include "0002-signkey_revocations.sql"
+#include "0002-extensions.sql"
+#include "0002-profit_drains.sql"
+#include "0002-legitimization_processes.sql"
+#include "0002-legitimization_requirements.sql"
+#include "0002-reserves.sql"
+#include "0002-reserves_in.sql"
+#include "0002-reserves_close.sql"
+#include "0002-close_requests.sql"
+#include "0002-reserves_open_deposits.sql"
+#include "0002-reserves_open_requests.sql"
+#include "0002-reserves_out.sql"
+#include "0002-known_coins.sql"
+#include "0002-refresh_commitments.sql"
+#include "0002-refresh_revealed_coins.sql"
+#include "0002-refresh_transfer_keys.sql"
+#include "0002-deposits.sql"
+#include "0002-refunds.sql"
+#include "0002-wire_out.sql"
+#include "0002-aggregation_transient.sql"
+#include "0002-aggregation_tracking.sql"
+#include "0002-recoup.sql"
+#include "0002-recoup_refresh.sql"
+#include "0002-prewire.sql"
+#include "0002-cs_nonce_locks.sql"
+#include "0002-purse_requests.sql"
+#include "0002-purse_merges.sql"
+#include "0002-account_merges.sql"
+#include "0002-purse_decision.sql"
+#include "0002-contracts.sql"
+#include "0002-history_requests.sql"
+#include "0002-purse_deposits.sql"
+#include "0002-wads_in.sql"
+#include "0002-wad_in_entries.sql"
+#include "0002-wads_out.sql"
+#include "0002-wad_out_entries.sql"
+#include "0002-policy_fulfillments.sql"
+#include "0002-policy_details.sql"
+#include "0002-work_shards.sql"
+#include "0002-revolving_work_shards.sql"
+#include "0002-partners.sql"
+#include "0002-partner_accounts.sql"
 
 COMMIT;
diff --git a/src/exchangedb/shard-0002-part.sql 
b/src/exchangedb/exchange-0003.sql.in
similarity index 75%
rename from src/exchangedb/shard-0002-part.sql
rename to src/exchangedb/exchange-0003.sql.in
index 439d672a..7f0a9ef9 100644
--- a/src/exchangedb/shard-0002-part.sql
+++ b/src/exchangedb/exchange-0003.sql.in
@@ -14,18 +14,12 @@
 -- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
 --
 
-CREATE OR REPLACE FUNCTION setup_shard2(
-  shard_idx INTEGER
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  shard_suffix VARCHAR;
-BEGIN
+BEGIN;
 
-  shard_suffix = shard_idx::varchar;
+SELECT _v.register_patch('exchange-0003', NULL, NULL);
+SET search_path TO exchange;
 
-  PERFORM create_table_wire_targets(shard_suffix);
-END
-$$;
+#include "0003-purse_actions.sql"
+#include "0003-purse_deletion.sql"
+
+COMMIT;
diff --git a/src/exchangedb/perf_exchangedb_reserves_in_insert.c 
b/src/exchangedb/perf_exchangedb_reserves_in_insert.c
index 9a0ec094..fc2a0008 100644
--- a/src/exchangedb/perf_exchangedb_reserves_in_insert.c
+++ b/src/exchangedb/perf_exchangedb_reserves_in_insert.c
@@ -83,21 +83,14 @@ run (void *cls)
   }
   (void) plugin->drop_tables (plugin->cls);
   if (GNUNET_OK !=
-      plugin->create_tables (plugin->cls))
+      plugin->create_tables (plugin->cls,
+                             true,
+                             num_partitions))
   {
     GNUNET_break (0);
     result = 77;
     goto cleanup;
   }
-  if (GNUNET_OK !=
-      plugin->setup_partitions (plugin->cls,
-                                num_partitions))
-  {
-    GNUNET_break (0);
-    result = 77;
-    goto cleanup;
-  }
-
   for (unsigned int i = 0; i< 8; i++)
   {
     static unsigned int batches[] = {1, 1, 0, 2, 4, 16, 64, 256};
@@ -114,23 +107,23 @@ run (void *cls)
                                            &value));
     now = GNUNET_TIME_absolute_get ();
     ts = GNUNET_TIME_timestamp_get ();
-    for (unsigned int r=0;r<10;r++)
-    {
-    plugin->start (plugin->cls,
-                   "test_by_exchange_j");
-    for (unsigned int k = 0; k<batch_size; k++)
+    for (unsigned int r = 0; r<10; r++)
     {
-      RND_BLK (&reserve_pub);
-      FAILIF (GNUNET_DB_STATUS_SUCCESS_ONE_RESULT !=
-              plugin->reserves_in_insert (plugin->cls,
-                                          &reserve_pub,
-                                          &value,
-                                          ts,
-                                          sndr,
-                                          "section",
-                                          4));
-    }
-    plugin->commit (plugin->cls);
+      plugin->start (plugin->cls,
+                     "test_by_exchange_j");
+      for (unsigned int k = 0; k<batch_size; k++)
+      {
+        RND_BLK (&reserve_pub);
+        FAILIF (GNUNET_DB_STATUS_SUCCESS_ONE_RESULT !=
+                plugin->reserves_in_insert (plugin->cls,
+                                            &reserve_pub,
+                                            &value,
+                                            ts,
+                                            sndr,
+                                            "section",
+                                            4));
+      }
+      plugin->commit (plugin->cls);
     }
     duration = GNUNET_TIME_absolute_get_duration (now);
     fprintf (stdout,
@@ -196,4 +189,5 @@ main (int argc,
   return result;
 }
 
+
 /* end of test_exchangedb_by_j.c */
diff --git a/src/exchangedb/pg_complete_shard.c 
b/src/exchangedb/pg_complete_shard.c
index 5efea7c0..8e62809c 100644
--- a/src/exchangedb/pg_complete_shard.c
+++ b/src/exchangedb/pg_complete_shard.c
@@ -27,12 +27,11 @@
 
 enum GNUNET_DB_QueryStatus
 TEH_PG_complete_shard (void *cls,
-                         const char *job_name,
-                         uint64_t start_row,
-                         uint64_t end_row)
+                       const char *job_name,
+                       uint64_t start_row,
+                       uint64_t end_row)
 {
   struct PostgresClosure *pg = cls;
-
   struct GNUNET_PQ_QueryParam params[] = {
     GNUNET_PQ_query_param_string (job_name),
     GNUNET_PQ_query_param_uint64 (&start_row),
@@ -44,8 +43,6 @@ TEH_PG_complete_shard (void *cls,
               "Completing shard %llu-%llu\n",
               (unsigned long long) start_row,
               (unsigned long long) end_row);
-
-
   PREPARE (pg,
            "complete_shard",
            "UPDATE work_shards"
diff --git a/src/exchangedb/pg_create_shard_tables.c 
b/src/exchangedb/pg_create_shard_tables.c
deleted file mode 100644
index 4fb6940f..00000000
--- a/src/exchangedb/pg_create_shard_tables.c
+++ /dev/null
@@ -1,66 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_create_shard_tables.c
- * @brief Implementation of the create_shard_tables function for Postgres
- * @author Christian Grothoff
- */
-#include "platform.h"
-#include "taler_error_codes.h"
-#include "taler_dbevents.h"
-#include "taler_pq_lib.h"
-#include "pg_create_shard_tables.h"
-#include "pg_helper.h"
-
-
-enum GNUNET_GenericReturnValue
-TEH_PG_create_shard_tables (void *cls,
-                              uint32_t idx)
-{
-  struct PostgresClosure *pg = cls;
-  struct GNUNET_PQ_Context *conn;
-  enum GNUNET_GenericReturnValue ret = GNUNET_OK;
-  struct GNUNET_PQ_QueryParam params[] = {
-    GNUNET_PQ_query_param_uint32 (&idx),
-    GNUNET_PQ_query_param_end
-  };
-  struct GNUNET_PQ_ExecuteStatement es[] = {
-    GNUNET_PQ_make_try_execute ("SET search_path TO exchange;"),
-    GNUNET_PQ_EXECUTE_STATEMENT_END
-  };
-
-  struct GNUNET_PQ_PreparedStatement ps[] = {
-    GNUNET_PQ_make_prepare ("create_shard_tables",
-                            "SELECT"
-                            " setup_shard"
-                            " ($1);"),
-    GNUNET_PQ_PREPARED_STATEMENT_END
-  };
-
-  conn = GNUNET_PQ_connect_with_cfg (pg->cfg,
-                                     "exchangedb-postgres",
-                                     "shard-",
-                                     es,
-                                     ps);
-  if (NULL == conn)
-    return GNUNET_SYSERR;
-  if (0 > GNUNET_PQ_eval_prepared_non_select (conn,
-                                              "create_shard_tables",
-                                              params))
-    ret = GNUNET_SYSERR;
-  GNUNET_PQ_disconnect (conn);
-  return ret;
-}
diff --git a/src/exchangedb/pg_create_shard_tables.h 
b/src/exchangedb/pg_create_shard_tables.h
deleted file mode 100644
index 31ab49a4..00000000
--- a/src/exchangedb/pg_create_shard_tables.h
+++ /dev/null
@@ -1,39 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_create_shard_tables.h
- * @brief implementation of the create_shard_tables function for Postgres
- * @author Christian Grothoff
- */
-#ifndef PG_CREATE_SHARD_TABLES_H
-#define PG_CREATE_SHARD_TABLES_H
-
-#include "taler_util.h"
-#include "taler_json_lib.h"
-#include "taler_exchangedb_plugin.h"
-
-/**
- * Create tables of a shard node with index idx
- *
- * @param cls the `struct PostgresClosure` with the plugin-specific state
- * @param idx the shards index, will be appended as suffix to all tables
- * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
- */
-enum GNUNET_GenericReturnValue
-TEH_PG_create_shard_tables (void *cls,
-                            uint32_t idx);
-
-#endif
diff --git a/src/exchangedb/pg_create_tables.c 
b/src/exchangedb/pg_create_tables.c
index 63211cf5..1d5728d8 100644
--- a/src/exchangedb/pg_create_tables.c
+++ b/src/exchangedb/pg_create_tables.c
@@ -27,21 +27,47 @@
 
 
 enum GNUNET_GenericReturnValue
-TEH_PG_create_tables (void *cls)
+TEH_PG_create_tables (void *cls,
+                      bool support_partitions,
+                      uint32_t num_partitions)
 {
   struct PostgresClosure *pg = cls;
   struct GNUNET_PQ_Context *conn;
-  enum GNUNET_GenericReturnValue ret;
+  enum GNUNET_GenericReturnValue ret = GNUNET_OK;
+  struct GNUNET_PQ_QueryParam params[] = {
+    support_partitions
+    ? GNUNET_PQ_query_param_uint32 (&num_partitions)
+    : GNUNET_PQ_query_param_null (),
+    GNUNET_PQ_query_param_end
+  };
+  struct GNUNET_PQ_PreparedStatement ps[] = {
+    GNUNET_PQ_make_prepare ("create_tables",
+                            "SELECT"
+                            " exchange.do_create_tables"
+                            " ($1);"),
+    GNUNET_PQ_PREPARED_STATEMENT_END
+  };
+  struct GNUNET_PQ_ExecuteStatement es[] = {
+    GNUNET_PQ_make_try_execute ("SET search_path TO exchange;"),
+    GNUNET_PQ_EXECUTE_STATEMENT_END
+  };
+
 
   conn = GNUNET_PQ_connect_with_cfg (pg->cfg,
                                      "exchangedb-postgres",
                                      "exchange-",
-                                     NULL,
-                                     NULL);
+                                     es,
+                                     ps);
   if (NULL == conn)
     return GNUNET_SYSERR;
-  ret = GNUNET_PQ_exec_sql (conn,
-                            "procedures");
+  if (0 >
+      GNUNET_PQ_eval_prepared_non_select (conn,
+                                          "create_tables",
+                                          params))
+    ret = GNUNET_SYSERR;
+  if (GNUNET_OK == ret)
+    ret = GNUNET_PQ_exec_sql (conn,
+                              "procedures");
   GNUNET_PQ_disconnect (conn);
   return ret;
 }
diff --git a/src/exchangedb/pg_create_tables.h 
b/src/exchangedb/pg_create_tables.h
index 7fb7a56f..58f5aae7 100644
--- a/src/exchangedb/pg_create_tables.h
+++ b/src/exchangedb/pg_create_tables.h
@@ -29,9 +29,16 @@
  * Create the necessary tables if they are not present
  *
  * @param cls the `struct PostgresClosure` with the plugin-specific state
+ * @param support_partitions true to enable partitioning support (disables 
foreign key constraints)
+ * @param num_partitions number of partitions to create,
+ *     (0 to not actually use partitions, 1 to only
+ *      setup a default partition, >1 for real partitions)
  * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
  */
 enum GNUNET_GenericReturnValue
-TEH_PG_create_tables (void *cls);
+TEH_PG_create_tables (void *cls,
+                      bool support_partitions,
+                      uint32_t num_partitions);
+
 
 #endif
diff --git a/src/exchangedb/pg_do_purse_deposit.c 
b/src/exchangedb/pg_do_purse_deposit.c
index 51d4a371..25496a26 100644
--- a/src/exchangedb/pg_do_purse_deposit.c
+++ b/src/exchangedb/pg_do_purse_deposit.c
@@ -42,7 +42,9 @@ TEH_PG_do_purse_deposit (
   struct GNUNET_TIME_Timestamp reserve_expiration;
   uint64_t partner_id = 0; /* FIXME #7271: WAD support... */
   struct GNUNET_PQ_QueryParam params[] = {
-    GNUNET_PQ_query_param_uint64 (&partner_id),
+    (0 == partner_id)
+    ? GNUNET_PQ_query_param_null ()
+    : GNUNET_PQ_query_param_uint64 (&partner_id),
     GNUNET_PQ_query_param_auto_from_type (purse_pub),
     TALER_PQ_query_param_amount (amount),
     GNUNET_PQ_query_param_auto_from_type (coin_pub),
diff --git a/src/exchangedb/pg_get_reserve_history.c 
b/src/exchangedb/pg_get_reserve_history.c
index 8b8e280a..6042a620 100644
--- a/src/exchangedb/pg_get_reserve_history.c
+++ b/src/exchangedb/pg_get_reserve_history.c
@@ -803,7 +803,7 @@ TEH_PG_get_reserve_history (void *cls,
            "     ON (am.purse_pub = pm.purse_pub AND"
            "         am.reserve_pub = pm.reserve_pub)"
            " WHERE pm.reserve_pub=$1"
-           "  AND pm.partner_serial_id=0" /* must be local! */
+           "  AND COALESCE(pm.partner_serial_id,0)=0" /* must be local! */
            "  AND NOT pdes.refunded;");
   PREPARE (pg,
            "history_by_reserve",
@@ -1097,7 +1097,7 @@ TEH_PG_get_reserve_status (void *cls,
            "         am.reserve_pub = pm.reserve_pub)"
            " WHERE pm.reserve_pub=$1"
            "  AND pm.merge_timestamp >= $2"
-           "  AND pm.partner_serial_id=0" /* must be local! */
+           "  AND COALESCE(pm.partner_serial_id,0)=0" /* must be local! */
            "  AND NOT pdes.refunded;");
   PREPARE (pg,
            "history_by_reserve_truncated",
diff --git a/src/exchangedb/pg_insert_purse_request.c 
b/src/exchangedb/pg_insert_purse_request.c
index 5560bfa9..f42129ec 100644
--- a/src/exchangedb/pg_insert_purse_request.c
+++ b/src/exchangedb/pg_insert_purse_request.c
@@ -63,28 +63,25 @@ TEH_PG_insert_purse_request (
   };
 
   *in_conflict = false;
-
-
-  PREPARE ( pg,
-            "insert_purse_request",
-            "INSERT INTO purse_requests"
-            "  (purse_pub"
-            "  ,merge_pub"
-            "  ,purse_creation"
-            "  ,purse_expiration"
-            "  ,h_contract_terms"
-            "  ,age_limit"
-            "  ,flags"
-            "  ,in_reserve_quota"
-            "  ,amount_with_fee_val"
-            "  ,amount_with_fee_frac"
-            "  ,purse_fee_val"
-
-            "  ,purse_fee_frac"
-            "  ,purse_sig"
-            "  ) VALUES "
-            "  ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)"
-            "  ON CONFLICT DO NOTHING;");
+  PREPARE (pg,
+           "insert_purse_request",
+           "INSERT INTO purse_requests"
+           "  (purse_pub"
+           "  ,merge_pub"
+           "  ,purse_creation"
+           "  ,purse_expiration"
+           "  ,h_contract_terms"
+           "  ,age_limit"
+           "  ,flags"
+           "  ,in_reserve_quota"
+           "  ,amount_with_fee_val"
+           "  ,amount_with_fee_frac"
+           "  ,purse_fee_val"
+           "  ,purse_fee_frac"
+           "  ,purse_sig"
+           "  ) VALUES "
+           "  ($1, $2, $3, $4, $5, $6, $7, $8, $9, $10, $11, $12, $13)"
+           "  ON CONFLICT DO NOTHING;");
   qs = GNUNET_PQ_eval_prepared_non_select (pg->conn,
                                            "insert_purse_request",
                                            params);
@@ -100,14 +97,14 @@ TEH_PG_insert_purse_request (
     struct TALER_PurseContractSignatureP purse_sig2;
 
     qs = TEH_PG_get_purse_request (pg,
-                                     purse_pub,
-                                     &merge_pub2,
-                                     &purse_expiration2,
-                                     &h_contract_terms2,
-                                     &age_limit2,
-                                     &amount2,
-                                     &balance,
-                                     &purse_sig2);
+                                   purse_pub,
+                                   &merge_pub2,
+                                   &purse_expiration2,
+                                   &h_contract_terms2,
+                                   &age_limit2,
+                                   &amount2,
+                                   &balance,
+                                   &purse_sig2);
     if (GNUNET_DB_STATUS_SUCCESS_ONE_RESULT != qs)
     {
       GNUNET_break (0);
@@ -127,8 +124,3 @@ TEH_PG_insert_purse_request (
     return GNUNET_DB_STATUS_SUCCESS_ONE_RESULT;
   }
 }
-
-
-
-
-
diff --git a/src/exchangedb/pg_setup_foreign_servers.c 
b/src/exchangedb/pg_setup_foreign_servers.c
deleted file mode 100644
index 490ae4c2..00000000
--- a/src/exchangedb/pg_setup_foreign_servers.c
+++ /dev/null
@@ -1,118 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_setup_foreign_servers.c
- * @brief Implementation of the setup_foreign_servers function for Postgres
- * @author Christian Grothoff
- */
-#include "platform.h"
-#include "taler_error_codes.h"
-#include "taler_dbevents.h"
-#include "taler_pq_lib.h"
-#include "pg_setup_foreign_servers.h"
-#include "pg_helper.h"
-
-
-
-enum GNUNET_GenericReturnValue
-TEH_PG_setup_foreign_servers (void *cls,
-                                uint32_t num)
-{
-  struct PostgresClosure *pg = cls;
-  struct GNUNET_PQ_Context *conn;
-  enum GNUNET_GenericReturnValue ret = GNUNET_OK;
-  char *shard_domain = NULL;
-  char *remote_user = NULL;
-  char *remote_user_pw = NULL;
-
-  if (GNUNET_OK !=
-      GNUNET_CONFIGURATION_get_value_string (pg->cfg,
-                                             "exchange",
-                                             "SHARD_DOMAIN",
-                                             &shard_domain))
-  {
-    GNUNET_log_config_missing (GNUNET_ERROR_TYPE_ERROR,
-                               "exchange",
-                               "SHARD_DOMAIN");
-    return GNUNET_SYSERR;
-  }
-  if (GNUNET_OK !=
-      GNUNET_CONFIGURATION_get_value_string (pg->cfg,
-                                             "exchangedb-postgres",
-                                             "SHARD_REMOTE_USER",
-                                             &remote_user))
-  {
-    GNUNET_log_config_missing (GNUNET_ERROR_TYPE_ERROR,
-                               "exchangedb-postgres",
-                               "SHARD_REMOTE_USER");
-    GNUNET_free (shard_domain);
-    return GNUNET_SYSERR;
-  }
-  if (GNUNET_OK !=
-      GNUNET_CONFIGURATION_get_value_string (pg->cfg,
-                                             "exchangedb-postgres",
-                                             "SHARD_REMOTE_USER_PW",
-                                             &remote_user_pw))
-  {
-    GNUNET_log_config_missing (GNUNET_ERROR_TYPE_ERROR,
-                               "exchangedb-postgres",
-                               "SHARD_REMOTE_USER_PW");
-    GNUNET_free (shard_domain);
-    GNUNET_free (remote_user);
-    return GNUNET_SYSERR;
-  }
-
-  struct GNUNET_PQ_QueryParam params[] = {
-    GNUNET_PQ_query_param_uint32 (&num),
-    GNUNET_PQ_query_param_string (shard_domain),
-    GNUNET_PQ_query_param_string (remote_user),
-    GNUNET_PQ_query_param_string (remote_user_pw),
-    GNUNET_PQ_query_param_end
-  };
-  struct GNUNET_PQ_ExecuteStatement es[] = {
-    GNUNET_PQ_make_try_execute ("SET search_path TO exchange;"),
-    GNUNET_PQ_EXECUTE_STATEMENT_END
-  };
-  struct GNUNET_PQ_PreparedStatement ps[] = {
-    GNUNET_PQ_make_prepare ("create_foreign_servers",
-                            "SELECT"
-                            " create_foreign_servers"
-                            " ($1, $2, $3, $4);"),
-    GNUNET_PQ_PREPARED_STATEMENT_END
-  };
-
-  conn = GNUNET_PQ_connect_with_cfg (pg->cfg,
-                                     "exchangedb-postgres",
-                                     NULL,
-                                     es,
-                                     ps);
-  if (NULL == conn)
-  {
-    ret = GNUNET_SYSERR;
-  }
-  else if (0 > GNUNET_PQ_eval_prepared_non_select (conn,
-                                                   "create_foreign_servers",
-                                                   params))
-  {
-    ret = GNUNET_SYSERR;
-  }
-  GNUNET_free (shard_domain);
-  GNUNET_free (remote_user);
-  GNUNET_free (remote_user_pw);
-  GNUNET_PQ_disconnect (conn);
-  return ret;
-}
-
diff --git a/src/exchangedb/pg_setup_foreign_servers.h 
b/src/exchangedb/pg_setup_foreign_servers.h
deleted file mode 100644
index 65ba0343..00000000
--- a/src/exchangedb/pg_setup_foreign_servers.h
+++ /dev/null
@@ -1,39 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_setup_foreign_servers.h
- * @brief implementation of the setup_foreign_servers function for Postgres
- * @author Christian Grothoff
- */
-#ifndef PG_SETUP_FOREIGN_SERVERS_H
-#define PG_SETUP_FOREIGN_SERVERS_H
-
-#include "taler_util.h"
-#include "taler_json_lib.h"
-#include "taler_exchangedb_plugin.h"
-
-
-/**
- * Setup foreign servers (shards) for already existing tables
- *
- * @param cls the `struct PostgresClosure` with the plugin-specific state
- * @param num the number of foreign servers (shards) to create for each 
partitioned table
- * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
- */
-enum GNUNET_GenericReturnValue
-TEH_PG_setup_foreign_servers (void *cls,
-                              uint32_t num);
-#endif
diff --git a/src/exchangedb/pg_setup_partitions.c 
b/src/exchangedb/pg_setup_partitions.c
deleted file mode 100644
index 6785931a..00000000
--- a/src/exchangedb/pg_setup_partitions.c
+++ /dev/null
@@ -1,73 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_setup_partitions.c
- * @brief Implementation of the setup_partitions function for Postgres
- * @author Christian Grothoff
- */
-#include "platform.h"
-#include "taler_error_codes.h"
-#include "taler_dbevents.h"
-#include "taler_pq_lib.h"
-#include "pg_setup_partitions.h"
-#include "pg_helper.h"
-
-/**
- * Setup partitions of already existing tables
- *
- * @param cls the `struct PostgresClosure` with the plugin-specific state
- * @param num the number of partitions to create for each partitioned table
- * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
- */
-enum GNUNET_GenericReturnValue
-TEH_PG_setup_partitions (void *cls,
-                           uint32_t num)
-{
-  struct PostgresClosure *pg = cls;
-  struct GNUNET_PQ_Context *conn;
-  enum GNUNET_GenericReturnValue ret = GNUNET_OK;
-  struct GNUNET_PQ_QueryParam params[] = {
-    GNUNET_PQ_query_param_uint32 (&num),
-    GNUNET_PQ_query_param_end
-  };
-  struct GNUNET_PQ_PreparedStatement ps[] = {
-    GNUNET_PQ_make_prepare ("setup_partitions",
-                            "SELECT"
-                            " create_partitions"
-                            " ($1);"),
-    GNUNET_PQ_PREPARED_STATEMENT_END
-  };
-  struct GNUNET_PQ_ExecuteStatement es[] = {
-    GNUNET_PQ_make_try_execute ("SET search_path TO exchange;"),
-    GNUNET_PQ_EXECUTE_STATEMENT_END
-  };
-
-  conn = GNUNET_PQ_connect_with_cfg (pg->cfg,
-                                     "exchangedb-postgres",
-                                     NULL,
-                                     es,
-                                     ps);
-  if (NULL == conn)
-    return GNUNET_SYSERR;
-  ret = GNUNET_OK;
-  if (0 > GNUNET_PQ_eval_prepared_non_select (conn,
-                                              "setup_partitions",
-                                              params))
-    ret = GNUNET_SYSERR;
-  GNUNET_PQ_disconnect (conn);
-  return ret;
-}
-
diff --git a/src/exchangedb/pg_setup_partitions.h 
b/src/exchangedb/pg_setup_partitions.h
deleted file mode 100644
index a3f56ff1..00000000
--- a/src/exchangedb/pg_setup_partitions.h
+++ /dev/null
@@ -1,39 +0,0 @@
-/*
-   This file is part of TALER
-   Copyright (C) 2022 Taler Systems SA
-
-   TALER is free software; you can redistribute it and/or modify it under the
-   terms of the GNU General Public License as published by the Free Software
-   Foundation; either version 3, or (at your option) any later version.
-
-   TALER is distributed in the hope that it will be useful, but WITHOUT ANY
-   WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
-   A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
-
-   You should have received a copy of the GNU General Public License along with
-   TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
- */
-/**
- * @file exchangedb/pg_setup_partitions.h
- * @brief implementation of the setup_partitions function for Postgres
- * @author Christian Grothoff
- */
-#ifndef PG_SETUP_PARTITIONS_H
-#define PG_SETUP_PARTITIONS_H
-
-#include "taler_util.h"
-#include "taler_json_lib.h"
-#include "taler_exchangedb_plugin.h"
-
-/**
- * Setup partitions of already existing tables
- *
- * @param cls the `struct PostgresClosure` with the plugin-specific state
- * @param num the number of partitions to create for each partitioned table
- * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
- */
-enum GNUNET_GenericReturnValue
-TEH_PG_setup_partitions (void *cls,
-                         uint32_t num);
-
-#endif
diff --git a/src/exchangedb/plugin_exchangedb_postgres.c 
b/src/exchangedb/plugin_exchangedb_postgres.c
index 5b59d4b0..cdb9b623 100644
--- a/src/exchangedb/plugin_exchangedb_postgres.c
+++ b/src/exchangedb/plugin_exchangedb_postgres.c
@@ -65,10 +65,8 @@
 #include "pg_iterate_active_signkeys.h"
 #include "pg_preflight.h"
 #include "pg_commit.h"
-#include "pg_create_shard_tables.h"
 #include "pg_insert_aggregation_tracking.h"
 #include "pg_drop_tables.h"
-#include "pg_setup_partitions.h"
 #include "pg_select_satisfied_kyc_processes.h"
 #include "pg_select_aggregation_amounts_for_kyc_check.h"
 #include "pg_kyc_provider_account_lookup.h"
@@ -105,7 +103,6 @@
 #include "pg_start.h"
 #include "pg_rollback.h"
 #include "pg_create_tables.h"
-#include "pg_setup_foreign_servers.h"
 #include "pg_event_listen.h"
 #include "pg_event_listen_cancel.h"
 #include "pg_event_notify.h"
@@ -384,9 +381,6 @@ TEH_PG_internal_setup (struct PostgresClosure *pg,
 }
 
 
-
-
-
 /**
  * Closure for #get_refunds_cb().
  */
@@ -456,9 +450,6 @@ get_refunds_cb (void *cls,
 }
 
 
-
-
-
 /* Get the details of a policy, referenced by its hash code
  *
  * @param cls the `struct PostgresClosure` with the plugin-specific state
@@ -1627,8 +1618,9 @@ postgres_ensure_coin_known (void *cls,
   return TALER_EXCHANGEDB_CKS_PRESENT;
 }
 
+
 enum GNUNET_DB_QueryStatus
-setup_wire_target(
+setup_wire_target (
   struct PostgresClosure *pg,
   const char *payto_uri,
   struct TALER_PaytoHashP *h_payto)
@@ -1654,6 +1646,8 @@ setup_wire_target(
                                              "insert_kyc_status",
                                              iparams);
 }
+
+
 /**
  * Insert information about deposited coin into the database.
  *
@@ -2866,7 +2860,7 @@ postgres_insert_reserve_closed (
   reserve.pub = *reserve_pub;
   if (GNUNET_DB_STATUS_SUCCESS_ONE_RESULT !=
       (qs = TEH_PG_reserves_get (cls,
-                                   &reserve)))
+                                 &reserve)))
   {
     /* Existence should have been checked before we got here... */
     GNUNET_break (GNUNET_DB_STATUS_SOFT_ERROR == qs);
@@ -2893,7 +2887,7 @@ postgres_insert_reserve_closed (
     GNUNET_break (TALER_AAR_RESULT_ZERO == ret);
   }
   return TEH_PG_reserves_update (cls,
-                          &reserve);
+                                 &reserve);
 }
 
 
@@ -5168,12 +5162,8 @@ libtaler_plugin_exchangedb_postgres_init (void *cls)
     = &TEH_PG_commit;
   plugin->preflight
     = &TEH_PG_preflight;
-  plugin->create_shard_tables
-    = &TEH_PG_create_shard_tables;
   plugin->insert_aggregation_tracking
     = &TEH_PG_insert_aggregation_tracking;
-  plugin->setup_partitions
-    = &TEH_PG_setup_partitions;
   plugin->select_aggregation_amounts_for_kyc_check
     = &TEH_PG_select_aggregation_amounts_for_kyc_check;
 
@@ -5245,11 +5235,8 @@ libtaler_plugin_exchangedb_postgres_init (void *cls)
     = &TEH_PG_start;
   plugin->rollback
     = &TEH_PG_rollback;
-
- plugin->create_tables
+  plugin->create_tables
     = &TEH_PG_create_tables;
-  plugin->setup_foreign_servers
-    = &TEH_PG_setup_foreign_servers;
   plugin->event_listen
     = &TEH_PG_event_listen;
   plugin->event_listen_cancel
@@ -5446,7 +5433,6 @@ libtaler_plugin_exchangedb_postgres_init (void *cls)
     = &TEH_PG_select_purse_by_merge_pub;
   plugin->set_purse_balance
     = &TEH_PG_set_purse_balance;
-
   plugin->batch_reserves_in_insert
     = &TEH_PG_batch_reserves_in_insert;
 
diff --git a/src/exchangedb/procedures.sql b/src/exchangedb/procedures.sql
index ff282735..ff3ddb3f 100644
--- a/src/exchangedb/procedures.sql
+++ b/src/exchangedb/procedures.sql
@@ -14,14 +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,
@@ -1523,7 +1519,7 @@ out_conflict=FALSE;
 out_balance_ok=TRUE;
 
 -- See if we can finish the merge or need to update the trigger time and 
partner.
-SELECT partner_serial_id
+SELECT COALESCE(partner_serial_id,0)
       ,reserve_pub
   INTO psi
       ,my_reserve_pub
@@ -1658,7 +1654,7 @@ BEGIN
 
 IF in_partner_url IS NULL
 THEN
-  my_partner_serial_id=0;
+  my_partner_serial_id=NULL;
 ELSE
   SELECT
     partner_serial_id
@@ -1821,7 +1817,6 @@ ELSE
 
 END IF;
 
-
 RETURN;
 
 END $$;
@@ -1855,7 +1850,7 @@ INSERT INTO exchange.purse_merges
     ,merge_sig
     ,merge_timestamp)
   VALUES
-    (0
+    (NULL
     ,in_reserve_pub
     ,in_purse_pub
     ,in_merge_sig
diff --git a/src/exchangedb/shard-0001-part.sql 
b/src/exchangedb/shard-0001-part.sql
deleted file mode 100644
index 8b6ec07f..00000000
--- a/src/exchangedb/shard-0001-part.sql
+++ /dev/null
@@ -1,134 +0,0 @@
---
--- This file is part of TALER
--- Copyright (C) 2014--2022 Taler Systems SA
---
--- TALER is free software; you can redistribute it and/or modify it under the
--- terms of the GNU General Public License as published by the Free Software
--- Foundation; either version 3, or (at your option) any later version.
---
--- TALER is distributed in the hope that it will be useful, but WITHOUT ANY
--- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS 
FOR
--- A PARTICULAR PURPOSE.  See the GNU General Public License for more details.
---
--- You should have received a copy of the GNU General Public License along with
--- TALER; see the file COPYING.  If not, see <http://www.gnu.org/licenses/>
---
-
-CREATE OR REPLACE FUNCTION setup_shard(
-  shard_idx INTEGER
-)
-RETURNS VOID
-LANGUAGE plpgsql
-AS $$
-DECLARE
-  shard_suffix VARCHAR;
-BEGIN
-
-  shard_suffix = shard_idx::varchar;
-
-  PERFORM create_table_wire_targets(shard_suffix);
-  PERFORM add_constraints_to_wire_targets_partition(shard_suffix);
-
-  PERFORM create_table_reserves(shard_suffix);
-
-  PERFORM create_table_legitimization_requirements(shard_suffix);
-  PERFORM 
add_constraints_to_legitimization_requirements_partition(shard_suffix);
-
-  PERFORM create_table_legitimization_processes(shard_suffix);
-  PERFORM add_constraints_to_legitimization_processes_partition(shard_suffix);
-
-
-  PERFORM create_table_reserves_in(shard_suffix);
-  PERFORM add_constraints_to_reserves_in_partition(shard_suffix);
-
-  PERFORM create_table_reserves_close(shard_suffix);
-  PERFORM add_constraints_to_reserves_close_partition(shard_suffix);
-
-  PERFORM create_table_reserves_open_requests(shard_suffix);
-  PERFORM add_constraints_to_reserves_open_request_partition(shard_suffix);
-
-  PERFORM create_table_reserves_open_deposits(shard_suffix);
-  PERFORM add_constraints_to_reserves_open_deposits_partition(shard_suffix);
-
-  PERFORM create_table_reserves_out(shard_suffix);
-  PERFORM add_constraints_to_reserves_out_partition(shard_suffix);
-
-  PERFORM create_table_reserves_out_by_reserve(shard_suffix);
-
-  PERFORM create_table_known_coins(shard_suffix);
-  PERFORM add_constraints_to_known_coins_partition(shard_suffix);
-
-  PERFORM create_table_refresh_commitments(shard_suffix);
-  PERFORM add_constraints_to_refresh_commitments_partition(shard_suffix);
-
-  PERFORM create_table_refresh_revealed_coins(shard_suffix);
-  PERFORM add_constraints_to_refresh_revealed_coins_partition(shard_suffix);
-
-  PERFORM create_table_refresh_transfer_keys(shard_suffix);
-  PERFORM add_constraints_to_refresh_transfer_keys_partition(shard_suffix);
-
-  PERFORM create_table_deposits(shard_suffix);
-  PERFORM add_constraints_to_deposits_partition(shard_suffix);
-
-  PERFORM create_table_deposits_by_ready(shard_suffix);
-
-  PERFORM create_table_deposits_for_matching(shard_suffix);
-
-  PERFORM create_table_refunds(shard_suffix);
-  PERFORM add_constraints_to_refunds_partition(shard_suffix);
-
-  PERFORM create_table_wire_out(shard_suffix);
-  PERFORM add_constraints_to_wire_out_partition(shard_suffix);
-
-  PERFORM create_table_aggregation_transient(shard_suffix);
-
-  PERFORM create_table_aggregation_tracking(shard_suffix);
-  PERFORM add_constraints_to_aggregation_tracking_partition(shard_suffix);
-
-  PERFORM create_table_recoup(shard_suffix);
-  PERFORM add_constraints_to_recoup_partition(shard_suffix);
-
-  PERFORM create_table_recoup_by_reserve(shard_suffix);
-
-  PERFORM create_table_recoup_refresh(shard_suffix);
-  PERFORM add_constraints_to_recoup_refresh_partition(shard_suffix);
-
-  PERFORM create_table_prewire(shard_suffix);
-
-  PERFORM create_table_cs_nonce_locks(shard_suffix);
-  PERFORM add_constraints_to_cs_nonce_locks_partition(shard_suffix);
-
-  PERFORM create_table_purse_requests(shard_suffix);
-  PERFORM add_constraints_to_purse_requests_partition(shard_suffix);
-
-  PERFORM create_table_purse_decision(shard_suffix);
-  PERFORM add_constraints_to_purse_decision_partition(shard_suffix);
-
-  PERFORM create_table_purse_merges(shard_suffix);
-  PERFORM add_constraints_to_purse_merges_partition(shard_suffix);
-
-  PERFORM create_table_account_merges(shard_suffix);
-  PERFORM add_constraints_to_account_merges_partition(shard_suffix);
-
-  PERFORM create_table_contracts(shard_suffix);
-  PERFORM add_constraints_to_contracts_partition(shard_suffix);
-
-  PERFORM create_table_history_requests(shard_suffix);
-
-  PERFORM create_table_close_requests(shard_suffix);
-  PERFORM add_constraints_to_close_requests_partition(shard_suffix);
-
-
-  PERFORM create_table_purse_deposits(shard_suffix);
-  PERFORM add_constraints_to_purse_deposits_partition(shard_suffix);
-
-  PERFORM create_table_wad_out_entries(shard_suffix);
-  PERFORM add_constraints_to_wad_out_entries_partition(shard_suffix);
-
-  PERFORM create_table_wads_in(shard_suffix);
-  PERFORM add_constraints_to_wads_in_partition(shard_suffix);
-
-  PERFORM create_table_wad_in_entries(shard_suffix);
-  PERFORM add_constraints_to_wad_in_entries_partition(shard_suffix);
-END
-$$;
diff --git a/src/exchangedb/test_exchangedb.c b/src/exchangedb/test_exchangedb.c
index 111ee936..eb258f00 100644
--- a/src/exchangedb/test_exchangedb.c
+++ b/src/exchangedb/test_exchangedb.c
@@ -1245,13 +1245,9 @@ run (void *cls)
   }
   (void) plugin->drop_tables (plugin->cls);
   if (GNUNET_OK !=
-      plugin->create_tables (plugin->cls))
-  {
-    result = 77;
-    goto cleanup;
-  }
-  if (GNUNET_OK !=
-      plugin->setup_partitions (plugin->cls, num_partitions))
+      plugin->create_tables (plugin->cls,
+                             true,
+                             num_partitions))
   {
     result = 77;
     goto cleanup;
diff --git a/src/exchangedb/test_exchangedb_by_j.c 
b/src/exchangedb/test_exchangedb_by_j.c
index b2f6ddeb..43f47167 100644
--- a/src/exchangedb/test_exchangedb_by_j.c
+++ b/src/exchangedb/test_exchangedb_by_j.c
@@ -33,7 +33,7 @@ static int result;
  */
 #define FAILIF(cond)                            \
   do {                                          \
-      if (! (cond)) {break;}                    \
+    if (! (cond)) {break;}                    \
     GNUNET_break (0);                           \
     goto drop;                                  \
   } while (0)
@@ -83,21 +83,14 @@ run (void *cls)
   }
   (void) plugin->drop_tables (plugin->cls);
   if (GNUNET_OK !=
-      plugin->create_tables (plugin->cls))
+      plugin->create_tables (plugin->cls,
+                             true,
+                             num_partitions))
   {
     GNUNET_break (0);
     result = 77;
     goto cleanup;
   }
-  if (GNUNET_OK !=
-      plugin->setup_partitions (plugin->cls,
-                                num_partitions))
-  {
-    GNUNET_break (0);
-    result = 77;
-    goto cleanup;
-  }
-
   for (unsigned int i = 0; i< 7; i++)
   {
     static unsigned int batches[] = {1, 1, 2, 4, 16, 64, 256};
@@ -114,28 +107,28 @@ run (void *cls)
                                            &value));
     now = GNUNET_TIME_absolute_get ();
     ts = GNUNET_TIME_timestamp_get ();
-    for (unsigned int r=0;r<10;r++)
+    for (unsigned int r = 0; r<10; r++)
     {
-    plugin->start_read_committed (plugin->cls,
-                                  "test_by_j");
-
-    for (unsigned int k = 0; k<batch_size; k++)
-    {
-      RND_BLK (&reserves[k].reserve_pub);
-      reserves[k].balance = value;
-      reserves[k].execution_time = ts;
-      reserves[k].sender_account_details = sndr;
-      reserves[k].exchange_account_name = "name";
-      reserves[k].wire_reference = k;
-
-    }
-    FAILIF (batch_size !=
-            plugin->batch_reserves_in_insert (plugin->cls,
-                                              reserves,
-                                              batch_size,
-                                              results));
-
-    plugin->commit (plugin->cls);
+      plugin->start_read_committed (plugin->cls,
+                                    "test_by_j");
+
+      for (unsigned int k = 0; k<batch_size; k++)
+      {
+        RND_BLK (&reserves[k].reserve_pub);
+        reserves[k].balance = value;
+        reserves[k].execution_time = ts;
+        reserves[k].sender_account_details = sndr;
+        reserves[k].exchange_account_name = "name";
+        reserves[k].wire_reference = k;
+
+      }
+      FAILIF (batch_size !=
+              plugin->batch_reserves_in_insert (plugin->cls,
+                                                reserves,
+                                                batch_size,
+                                                results));
+
+      plugin->commit (plugin->cls);
     }
     duration = GNUNET_TIME_absolute_get_duration (now);
     fprintf (stdout,
@@ -201,4 +194,5 @@ main (int argc,
   return result;
 }
 
+
 /* end of test_exchangedb_by_j.c */
diff --git a/src/include/taler_exchangedb_plugin.h 
b/src/include/taler_exchangedb_plugin.h
index 6f5dedd0..a2e3237f 100644
--- a/src/include/taler_exchangedb_plugin.h
+++ b/src/include/taler_exchangedb_plugin.h
@@ -3132,49 +3132,17 @@ struct TALER_EXCHANGEDB_Plugin
    * Create the necessary tables if they are not present
    *
    * @param cls the @e cls of this struct with the plugin-specific state
+   * @param support_partitions true to enable partitioning support (disables 
foreign key constraints)
+   * @param num_partitions number of partitions to create,
+   *     (0 to not actually use partitions, 1 to only
+   *      setup a default partition, >1 for real partitions)
    * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
    */
   enum GNUNET_GenericReturnValue
-  (*create_tables)(void *cls);
+  (*create_tables)(void *cls,
+                   bool support_partitions,
+                   uint32_t num_partitions);
 
-  /**
-   * Initialize the database of a shard node
-   *
-   * @param cls the @e cls of this struct with the plugin-specific state
-   * @param idx the current shard index, will be appended to tables as suffix
-   * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
-   */
-  enum GNUNET_GenericReturnValue
-  (*create_shard_tables)(void *cls,
-                         uint32_t idx);
-
-  /**
-   * Change already present tables of the database to num partitions
-   * Only has an effect if there are default partitions only
-   *
-   * @param cls the @e cls of this struct with the plugin-specific state
-   * @param num the number of partitions to create for each partitioned table
-   * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
-   */
-  enum GNUNET_GenericReturnValue
-  (*setup_partitions)(void *cls,
-                      uint32_t num);
-
-  /**
-   * Change already present tables of the database to num foreign tables on
-   * num foreign servers (shards).
-   * Only has an effect if there are default partitions only
-   *
-   * @param cls the @e cls of this struct with the plugin-specific state
-   * @param num the number of shard servers to create. The shard servers
-   *            must follow the numbering of [1-N], have the same user as
-   *            the master and have tables named $TABLE_$N where $N is the same
-   *            as the servers index of N.
-   * @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
-   */
-  enum GNUNET_GenericReturnValue
-  (*setup_foreign_servers)(void *cls,
-                           uint32_t num);
 
   /**
    * Start a transaction.
@@ -3480,7 +3448,8 @@ struct TALER_EXCHANGEDB_Plugin
    */
   enum GNUNET_DB_QueryStatus
   (*batch_reserves_in_insert)(void *cls,
-                              const struct TALER_EXCHANGEDB_ReserveInInfo 
*reserves,
+                              const struct
+                              TALER_EXCHANGEDB_ReserveInInfo *reserves,
                               unsigned int reserves_length,
                               enum GNUNET_DB_QueryStatus *results);
 

-- 
To stop receiving notification emails like this one, please contact
gnunet@gnunet.org.



reply via email to

[Prev in Thread] Current Thread [Next in Thread]