summaryrefslogtreecommitdiff
path: root/src/auditordb
diff options
context:
space:
mode:
Diffstat (limited to 'src/auditordb')
-rw-r--r--src/auditordb/0000.sql293
-rw-r--r--src/auditordb/0001.sql237
-rw-r--r--src/auditordb/9999.sql53
-rw-r--r--src/auditordb/Makefile.am10
-rw-r--r--src/auditordb/plugin_auditordb_postgres.c58
5 files changed, 618 insertions, 33 deletions
diff --git a/src/auditordb/0000.sql b/src/auditordb/0000.sql
new file mode 100644
index 000000000..1483e2015
--- /dev/null
+++ b/src/auditordb/0000.sql
@@ -0,0 +1,293 @@
+-- LICENSE AND COPYRIGHT
+--
+-- Copyright (C) 2010 Hubert depesz Lubaczewski
+--
+-- This program is distributed under the (Revised) BSD License:
+-- L<http://www.opensource.org/licenses/bsd-license.php>
+--
+-- Redistribution and use in source and binary forms, with or without
+-- modification, are permitted provided that the following conditions
+-- are met:
+--
+-- * Redistributions of source code must retain the above copyright
+-- notice, this list of conditions and the following disclaimer.
+--
+-- * Redistributions in binary form must reproduce the above copyright
+-- notice, this list of conditions and the following disclaimer in the
+-- documentation and/or other materials provided with the distribution.
+--
+-- * Neither the name of Hubert depesz Lubaczewski's Organization
+-- nor the names of its contributors may be used to endorse or
+-- promote products derived from this software without specific
+-- prior written permission.
+--
+-- THIS SOFTWARE IS PROVIDED BY THE COPYRIGHT HOLDERS AND CONTRIBUTORS "AS IS"
+-- AND ANY EXPRESS OR IMPLIED WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE
+-- IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE ARE
+-- DISCLAIMED. IN NO EVENT SHALL THE COPYRIGHT OWNER OR CONTRIBUTORS BE LIABLE
+-- FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR CONSEQUENTIAL
+-- DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR
+-- SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER
+-- CAUSED AND ON ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY,
+-- OR TORT (INCLUDING NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE
+-- OF THIS SOFTWARE, EVEN IF ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
+--
+-- Code origin: https://gitlab.com/depesz/Versioning/blob/master/install.versioning.sql
+--
+--
+-- # NAME
+--
+-- **Versioning** - simplistic take on tracking and applying changes to databases.
+--
+-- # DESCRIPTION
+--
+-- This project strives to provide simple way to manage changes to
+-- database.
+--
+-- Instead of making changes on development server, then finding
+-- differences between production and development, deciding which ones
+-- should be installed on production, and finding a way to install them -
+-- you start with writing diffs themselves!
+--
+-- # INSTALLATION
+--
+-- To install versioning simply run install.versioning.sql in your database
+-- (all of them: production, stage, test, devel, ...).
+--
+-- # USAGE
+--
+-- In your files with patches to database, put whole logic in single
+-- transaction, and use \_v.\* functions - usually \_v.register_patch() at
+-- least to make sure everything is OK.
+--
+-- For example. Let's assume you have patch files:
+--
+-- ## 0001.sql:
+--
+-- ```
+-- create table users (id serial primary key, username text);
+-- ```
+--
+-- ## 0002.sql:
+--
+-- ```
+-- insert into users (username) values ('depesz');
+-- ```
+-- To change it to use versioning you would change the files, to this
+-- state:
+--
+-- 0000.sql:
+--
+-- ```
+-- BEGIN;
+-- select _v.register_patch('000-base', NULL, NULL);
+-- create table users (id serial primary key, username text);
+-- COMMIT;
+-- ```
+--
+-- ## 0002.sql:
+--
+-- ```
+-- BEGIN;
+-- select _v.register_patch('001-users', ARRAY['000-base'], NULL);
+-- insert into users (username) values ('depesz');
+-- COMMIT;
+-- ```
+--
+-- This will make sure that patch 001-users can only be applied after
+-- 000-base.
+--
+-- # AVAILABLE FUNCTIONS
+--
+-- ## \_v.register_patch( TEXT )
+--
+-- Registers named patch, or dies if it is already registered.
+--
+-- Returns integer which is id of patch in \_v.patches table - only if it
+-- succeeded.
+--
+-- ## \_v.register_patch( TEXT, TEXT[] )
+--
+-- Same as \_v.register_patch( TEXT ), but checks is all given patches (given as
+-- array in second argument) are already registered.
+--
+-- ## \_v.register_patch( TEXT, TEXT[], TEXT[] )
+--
+-- Same as \_v.register_patch( TEXT, TEXT[] ), but also checks if there are no conflicts with preexisting patches.
+--
+-- Third argument is array of names of patches that conflict with current one. So
+-- if any of them is installed - register_patch will error out.
+--
+-- ## \_v.unregister_patch( TEXT )
+--
+-- Removes information about given patch from the versioning data.
+--
+-- It doesn't remove objects that were created by this patch - just removes
+-- metainformation.
+--
+-- ## \_v.assert_user_is_superuser()
+--
+-- Make sure that current patch is being loaded by superuser.
+--
+-- If it's not - it will raise exception, and break transaction.
+--
+-- ## \_v.assert_user_is_not_superuser()
+--
+-- Make sure that current patch is not being loaded by superuser.
+--
+-- If it is - it will raise exception, and break transaction.
+--
+-- ## \_v.assert_user_is_one_of(TEXT, TEXT, ... )
+--
+-- Make sure that current patch is being loaded by one of listed users.
+--
+-- If ```current_user``` is not listed as one of arguments - function will raise
+-- exception and break the transaction.
+
+BEGIN;
+
+-- This file adds versioning support to database it will be loaded to.
+-- It requires that PL/pgSQL is already loaded - will raise exception otherwise.
+-- All versioning "stuff" (tables, functions) is in "_v" schema.
+
+-- All functions are defined as 'RETURNS SETOF INT4' to be able to make them to RETURN literaly nothing (0 rows).
+-- >> RETURNS VOID<< IS similar, but it still outputs "empty line" in psql when calling.
+CREATE SCHEMA IF NOT EXISTS _v;
+COMMENT ON SCHEMA _v IS 'Schema for versioning data and functionality.';
+
+CREATE TABLE IF NOT EXISTS _v.patches (
+ patch_name TEXT PRIMARY KEY,
+ applied_tsz TIMESTAMPTZ NOT NULL DEFAULT now(),
+ applied_by TEXT NOT NULL,
+ requires TEXT[],
+ conflicts TEXT[]
+);
+COMMENT ON TABLE _v.patches IS 'Contains information about what patches are currently applied on database.';
+COMMENT ON COLUMN _v.patches.patch_name IS 'Name of patch, has to be unique for every patch.';
+COMMENT ON COLUMN _v.patches.applied_tsz IS 'When the patch was applied.';
+COMMENT ON COLUMN _v.patches.applied_by IS 'Who applied this patch (PostgreSQL username)';
+COMMENT ON COLUMN _v.patches.requires IS 'List of patches that are required for given patch.';
+COMMENT ON COLUMN _v.patches.conflicts IS 'List of patches that conflict with given patch.';
+
+CREATE OR REPLACE FUNCTION _v.register_patch( IN in_patch_name TEXT, IN in_requirements TEXT[], in_conflicts TEXT[], OUT versioning INT4 ) RETURNS setof INT4 AS $$
+DECLARE
+ t_text TEXT;
+ t_text_a TEXT[];
+ i INT4;
+BEGIN
+ -- Thanks to this we know only one patch will be applied at a time
+ LOCK TABLE _v.patches IN EXCLUSIVE MODE;
+
+ SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_patch_name;
+ IF FOUND THEN
+ RAISE EXCEPTION 'Patch % is already applied!', in_patch_name;
+ END IF;
+
+ t_text_a := ARRAY( SELECT patch_name FROM _v.patches WHERE patch_name = any( in_conflicts ) );
+ IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
+ RAISE EXCEPTION 'Versioning patches conflict. Conflicting patche(s) installed: %.', array_to_string( t_text_a, ', ' );
+ END IF;
+
+ IF array_upper( in_requirements, 1 ) IS NOT NULL THEN
+ t_text_a := '{}';
+ FOR i IN array_lower( in_requirements, 1 ) .. array_upper( in_requirements, 1 ) LOOP
+ SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_requirements[i];
+ IF NOT FOUND THEN
+ t_text_a := t_text_a || in_requirements[i];
+ END IF;
+ END LOOP;
+ IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
+ RAISE EXCEPTION 'Missing prerequisite(s): %.', array_to_string( t_text_a, ', ' );
+ END IF;
+ END IF;
+
+ INSERT INTO _v.patches (patch_name, applied_tsz, applied_by, requires, conflicts ) VALUES ( in_patch_name, now(), current_user, coalesce( in_requirements, '{}' ), coalesce( in_conflicts, '{}' ) );
+ RETURN;
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.register_patch( TEXT, TEXT[], TEXT[] ) IS 'Function to register patches in database. Raises exception if there are conflicts, prerequisites are not installed or the migration has already been installed.';
+
+CREATE OR REPLACE FUNCTION _v.register_patch( TEXT, TEXT[] ) RETURNS setof INT4 AS $$
+ SELECT _v.register_patch( $1, $2, NULL );
+$$ language sql;
+COMMENT ON FUNCTION _v.register_patch( TEXT, TEXT[] ) IS 'Wrapper to allow registration of patches without conflicts.';
+CREATE OR REPLACE FUNCTION _v.register_patch( TEXT ) RETURNS setof INT4 AS $$
+ SELECT _v.register_patch( $1, NULL, NULL );
+$$ language sql;
+COMMENT ON FUNCTION _v.register_patch( TEXT ) IS 'Wrapper to allow registration of patches without requirements and conflicts.';
+
+CREATE OR REPLACE FUNCTION _v.unregister_patch( IN in_patch_name TEXT, OUT versioning INT4 ) RETURNS setof INT4 AS $$
+DECLARE
+ i INT4;
+ t_text_a TEXT[];
+BEGIN
+ -- Thanks to this we know only one patch will be applied at a time
+ LOCK TABLE _v.patches IN EXCLUSIVE MODE;
+
+ t_text_a := ARRAY( SELECT patch_name FROM _v.patches WHERE in_patch_name = ANY( requires ) );
+ IF array_upper( t_text_a, 1 ) IS NOT NULL THEN
+ RAISE EXCEPTION 'Cannot uninstall %, as it is required by: %.', in_patch_name, array_to_string( t_text_a, ', ' );
+ END IF;
+
+ DELETE FROM _v.patches WHERE patch_name = in_patch_name;
+ GET DIAGNOSTICS i = ROW_COUNT;
+ IF i < 1 THEN
+ RAISE EXCEPTION 'Patch % is not installed, so it can''t be uninstalled!', in_patch_name;
+ END IF;
+
+ RETURN;
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.unregister_patch( TEXT ) IS 'Function to unregister patches in database. Dies if the patch is not registered, or if unregistering it would break dependencies.';
+
+CREATE OR REPLACE FUNCTION _v.assert_patch_is_applied( IN in_patch_name TEXT ) RETURNS TEXT as $$
+DECLARE
+ t_text TEXT;
+BEGIN
+ SELECT patch_name INTO t_text FROM _v.patches WHERE patch_name = in_patch_name;
+ IF NOT FOUND THEN
+ RAISE EXCEPTION 'Patch % is not applied!', in_patch_name;
+ END IF;
+ RETURN format('Patch %s is applied.', in_patch_name);
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.assert_patch_is_applied( TEXT ) IS 'Function that can be used to make sure that patch has been applied.';
+
+CREATE OR REPLACE FUNCTION _v.assert_user_is_superuser() RETURNS TEXT as $$
+DECLARE
+ v_super bool;
+BEGIN
+ SELECT usesuper INTO v_super FROM pg_user WHERE usename = current_user;
+ IF v_super THEN
+ RETURN 'assert_user_is_superuser: OK';
+ END IF;
+ RAISE EXCEPTION 'Current user is not superuser - cannot continue.';
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.assert_user_is_superuser() IS 'Function that can be used to make sure that patch is being applied using superuser account.';
+
+CREATE OR REPLACE FUNCTION _v.assert_user_is_not_superuser() RETURNS TEXT as $$
+DECLARE
+ v_super bool;
+BEGIN
+ SELECT usesuper INTO v_super FROM pg_user WHERE usename = current_user;
+ IF v_super THEN
+ RAISE EXCEPTION 'Current user is superuser - cannot continue.';
+ END IF;
+ RETURN 'assert_user_is_not_superuser: OK';
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.assert_user_is_not_superuser() IS 'Function that can be used to make sure that patch is being applied using normal (not superuser) account.';
+
+CREATE OR REPLACE FUNCTION _v.assert_user_is_one_of(VARIADIC p_acceptable_users TEXT[] ) RETURNS TEXT as $$
+DECLARE
+BEGIN
+ IF current_user = any( p_acceptable_users ) THEN
+ RETURN 'assert_user_is_one_of: OK';
+ END IF;
+ RAISE EXCEPTION 'User is not one of: % - cannot continue.', p_acceptable_users;
+END;
+$$ language plpgsql;
+COMMENT ON FUNCTION _v.assert_user_is_one_of(TEXT[]) IS 'Function that can be used to make sure that patch is being applied by one of defined users.';
+
+COMMIT;
diff --git a/src/auditordb/0001.sql b/src/auditordb/0001.sql
new file mode 100644
index 000000000..425436e28
--- /dev/null
+++ b/src/auditordb/0001.sql
@@ -0,0 +1,237 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2020 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/>
+--
+
+-- Everything in one big transaction
+BEGIN;
+
+-- Check patch versioning is in place.
+SELECT _v.register_patch('auditor-0001', NULL, NULL);
+
+
+CREATE TABLE IF NOT EXISTS auditor_exchanges
+ (master_pub BYTEA PRIMARY KEY CHECK (LENGTH(master_pub)=32)
+ ,exchange_url VARCHAR NOT NULL
+ );
+-- Table with list of signing keys of exchanges we are auditing
+CREATE TABLE IF NOT EXISTS auditor_exchange_signkeys
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,ep_start INT8 NOT NULL
+ ,ep_expire INT8 NOT NULL
+ ,ep_end INT8 NOT NULL
+ ,exchange_pub BYTEA NOT NULL CHECK (LENGTH(exchange_pub)=32)
+ ,master_sig BYTEA NOT NULL CHECK (LENGTH(master_sig)=64)
+ );
+-- Table with all of the denomination keys that the auditor
+-- is aware of.
+CREATE TABLE IF NOT EXISTS auditor_denominations
+ (denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64)
+ ,master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,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
+ );
+-- Table indicating up to which transactions the auditor has
+-- processed the exchange database. Used for SELECTing the
+-- statements to process. The indices below include the last
+-- serial ID from the respective tables that we have
+-- processed. Thus, we need to select those table entries that are
+-- strictly larger (and process in monotonically increasing
+-- order).
+CREATE TABLE IF NOT EXISTS auditor_progress_reserve
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,last_reserve_in_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_reserve_out_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_reserve_payback_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_reserve_close_serial_id INT8 NOT NULL DEFAULT 0
+ );
+CREATE TABLE IF NOT EXISTS auditor_progress_aggregation
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,last_wire_out_serial_id INT8 NOT NULL DEFAULT 0
+ );
+CREATE TABLE IF NOT EXISTS auditor_progress_deposit_confirmation
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,last_deposit_confirmation_serial_id INT8 NOT NULL DEFAULT 0
+ );
+CREATE TABLE IF NOT EXISTS auditor_progress_coin
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,last_withdraw_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_deposit_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_melt_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_refund_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_payback_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_payback_refresh_serial_id INT8 NOT NULL DEFAULT 0
+ );
+CREATE TABLE IF NOT EXISTS wire_auditor_account_progress
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,account_name TEXT NOT NULL
+ ,last_wire_reserve_in_serial_id INT8 NOT NULL DEFAULT 0
+ ,last_wire_wire_out_serial_id INT8 NOT NULL DEFAULT 0
+ ,wire_in_off INT8
+ ,wire_out_off INT8
+ );
+CREATE TABLE IF NOT EXISTS wire_auditor_progress
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,last_timestamp INT8 NOT NULL
+ ,last_reserve_close_uuid INT8 NOT NULL
+ );
+-- Table with all of the customer reserves and their respective
+-- balances that the auditor is aware of.
+-- last_reserve_out_serial_id marks the last withdrawal from
+-- reserves_out about this reserve that the auditor is aware of,
+-- and last_reserve_in_serial_id is the last reserve_in
+-- operation about this reserve that the auditor is aware of.
+CREATE TABLE IF NOT EXISTS auditor_reserves
+ (reserve_pub BYTEA NOT NULL CHECK(LENGTH(reserve_pub)=32)
+ ,master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,reserve_balance_val INT8 NOT NULL
+ ,reserve_balance_frac INT4 NOT NULL
+ ,withdraw_fee_balance_val INT8 NOT NULL
+ ,withdraw_fee_balance_frac INT4 NOT NULL
+ ,expiration_date INT8 NOT NULL
+ ,auditor_reserves_rowid BIGSERIAL UNIQUE
+ ,origin_account TEXT
+ );
+CREATE INDEX auditor_reserves_by_reserve_pub
+ ON auditor_reserves
+ (reserve_pub);
+-- Table with the sum of the balances of all customer reserves
+-- (by exchange's master public key)
+CREATE TABLE IF NOT EXISTS auditor_reserve_balance
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,reserve_balance_val INT8 NOT NULL
+ ,reserve_balance_frac INT4 NOT NULL
+ ,withdraw_fee_balance_val INT8 NOT NULL
+ ,withdraw_fee_balance_frac INT4 NOT NULL
+ );
+-- Table with the sum of the balances of all wire fees
+-- (by exchange's master public key)
+CREATE TABLE IF NOT EXISTS auditor_wire_fee_balance
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,wire_fee_balance_val INT8 NOT NULL
+ ,wire_fee_balance_frac INT4 NOT NULL
+ );
+-- Table with all of the outstanding denomination coins that the
+-- exchange is aware of and what the respective balances are
+-- (outstanding as well as issued overall which implies the
+-- maximum value at risk). We also count the number of coins
+-- issued (withdraw, refresh-reveal) and the number of coins seen
+-- at the exchange (refresh-commit, deposit), not just the amounts. */GNUNET_PQ_make_execute (
+CREATE TABLE IF NOT EXISTS auditor_denomination_pending
+ (denom_pub_hash BYTEA PRIMARY KEY REFERENCES auditor_denominations (denom_pub_hash) ON DELETE CASCADE
+ ,denom_balance_val INT8 NOT NULL
+ ,denom_balance_frac INT4 NOT NULL
+ ,denom_loss_val INT8 NOT NULL
+ ,denom_loss_frac INT4 NOT NULL
+ ,num_issued INT8 NOT NULL
+ ,denom_risk_val INT8 NOT NULL
+ ,denom_risk_frac INT4 NOT NULL
+ ,payback_loss_val INT8 NOT NULL
+ ,payback_loss_frac INT4 NOT NULL
+ );
+-- Table with the sum of the outstanding coins from
+-- auditor_denomination_pending (denom_pubs must belong to the
+-- respective's exchange's master public key); it represents the
+-- auditor_balance_summary of the exchange at this point (modulo
+-- unexpected historic_loss-style events where denomination keys are
+-- compromised)
+CREATE TABLE IF NOT EXISTS auditor_balance_summary
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,denom_balance_val INT8 NOT NULL
+ ,denom_balance_frac INT4 NOT NULL
+ ,deposit_fee_balance_val INT8 NOT NULL
+ ,deposit_fee_balance_frac INT4 NOT NULL
+ ,melt_fee_balance_val INT8 NOT NULL
+ ,melt_fee_balance_frac INT4 NOT NULL
+ ,refund_fee_balance_val INT8 NOT NULL
+ ,refund_fee_balance_frac INT4 NOT NULL
+ ,risk_val INT8 NOT NULL
+ ,risk_frac INT4 NOT NULL
+ ,loss_val INT8 NOT NULL
+ ,loss_frac INT4 NOT NULL
+ );
+-- Table with historic profits; basically, when a denom_pub has
+-- expired and everything associated with it is garbage collected,
+-- the final profits end up in here; note that the denom_pub here
+-- is not a foreign key, we just keep it as a reference point.
+-- revenue_balance is the sum of all of the profits we made on the
+-- coin except for withdraw fees (which are in
+-- historic_reserve_revenue); the deposit, melt and refund fees are given
+-- individually; the delta to the revenue_balance is from coins that
+-- were withdrawn but never deposited prior to expiration.
+CREATE TABLE IF NOT EXISTS auditor_historic_denomination_revenue
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,denom_pub_hash BYTEA PRIMARY KEY CHECK (LENGTH(denom_pub_hash)=64)
+ ,revenue_timestamp INT8 NOT NULL
+ ,revenue_balance_val INT8 NOT NULL
+ ,revenue_balance_frac INT4 NOT NULL
+ ,loss_balance_val INT8 NOT NULL
+ ,loss_balance_frac INT4 NOT NULL
+ );
+-- Table with historic profits from reserves; we eventually
+-- GC auditor_historic_reserve_revenue, and then store the totals
+-- in here (by time intervals).
+CREATE TABLE IF NOT EXISTS auditor_historic_reserve_summary
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,start_date INT8 NOT NULL
+ ,end_date INT8 NOT NULL
+ ,reserve_profits_val INT8 NOT NULL
+ ,reserve_profits_frac INT4 NOT NULL
+ );
+CREATE INDEX auditor_historic_reserve_summary_by_master_pub_start_date
+ ON auditor_historic_reserve_summary
+ (master_pub
+ ,start_date);
+-- Table with deposit confirmation sent to us by merchants;
+-- we must check that the exchange reported these properly.
+CREATE TABLE IF NOT EXISTS deposit_confirmations
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,serial_id BIGSERIAL UNIQUE
+ ,h_contract_terms BYTEA CHECK (LENGTH(h_contract_terms)=64)
+ ,h_wire BYTEA CHECK (LENGTH(h_wire)=64)
+ ,timestamp INT8 NOT NULL
+ ,refund_deadline INT8 NOT NULL
+ ,amount_without_fee_val INT8 NOT NULL
+ ,amount_without_fee_frac INT4 NOT NULL
+ ,coin_pub BYTEA CHECK (LENGTH(coin_pub)=32)
+ ,merchant_pub BYTEA CHECK (LENGTH(merchant_pub)=32)
+ ,exchange_sig BYTEA CHECK (LENGTH(exchange_sig)=64)
+ ,exchange_pub BYTEA CHECK (LENGTH(exchange_pub)=32)
+ ,master_sig BYTEA CHECK (LENGTH(master_sig)=64)
+ ,PRIMARY KEY (h_contract_terms,h_wire,coin_pub,merchant_pub,exchange_sig,exchange_pub,master_sig)
+ );
+-- Table with the sum of the ledger, auditor_historic_revenue and
+-- the auditor_reserve_balance. This is the
+-- final amount that the exchange should have in its bank account
+-- right now.
+CREATE TABLE IF NOT EXISTS auditor_predicted_result
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,balance_val INT8 NOT NULL
+ ,balance_frac INT4 NOT NULL
+ );
+
+-- Finally, commit everything
+COMMIT;
diff --git a/src/auditordb/9999.sql b/src/auditordb/9999.sql
new file mode 100644
index 000000000..d6add4b20
--- /dev/null
+++ b/src/auditordb/9999.sql
@@ -0,0 +1,53 @@
+--
+-- This file is part of TALER
+-- Copyright (C) 2014--2020 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/>
+--
+
+-- Everything in one big transaction
+BEGIN;
+
+NOTE: This code is not yet ready / in use. It was archived here
+as we might want this kind of table in the future. It is NOT
+to be installed in a production system (hence in EXTRA_DIST and
+not in the SQL target!)
+
+-- Check patch versioning is in place.
+SELECT _v.register_patch('auditor-9999', NULL, NULL);
+
+
+-- Table with historic business ledger; basically, when the exchange
+-- operator decides to use operating costs for anything but wire
+-- transfers to merchants, it goes in here. This happens when the
+-- operator users transaction fees for business expenses. purpose
+-- is free-form but should be a human-readable wire transfer
+-- identifier. This is NOT yet used and outside of the scope of
+-- the core auditing logic. However, once we do take fees to use
+-- operating costs, and if we still want auditor_predicted_result to match
+-- the tables overall, we'll need a command-line tool to insert rows
+-- into this table and update auditor_predicted_result accordingly.
+-- (So this table for now just exists as a reminder of what we'll
+-- need in the long term.)
+CREATE TABLE IF NOT EXISTS auditor_historic_ledger
+ (master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE
+ ,purpose VARCHAR NOT NULL
+ ,timestamp INT8 NOT NULL
+ ,balance_val INT8 NOT NULL
+ ,balance_frac INT4 NOT NULL
+ );
+CREATE INDEX history_ledger_by_master_pub_and_time
+ ON auditor_historic_ledger
+ (master_pub
+ ,timestamp);
+
+COMMIT;
diff --git a/src/auditordb/Makefile.am b/src/auditordb/Makefile.am
index 640f95f25..58aec5a84 100644
--- a/src/auditordb/Makefile.am
+++ b/src/auditordb/Makefile.am
@@ -11,9 +11,17 @@ pkgcfgdir = $(prefix)/share/taler/config.d/
pkgcfg_DATA = \
auditordb-postgres.conf
+sqldir = $(prefix)/share/taler/sql/auditor/
+
+sql_DATA = \
+ 0000.sql \
+ 0001.sql
+
EXTRA_DIST = \
auditordb-postgres.conf \
- test-auditor-db-postgres.conf
+ test-auditor-db-postgres.conf \
+ $(sql_DATA) \
+ 9999.sql
plugindir = $(libdir)/taler
diff --git a/src/auditordb/plugin_auditordb_postgres.c b/src/auditordb/plugin_auditordb_postgres.c
index fb2d77312..25734facc 100644
--- a/src/auditordb/plugin_auditordb_postgres.c
+++ b/src/auditordb/plugin_auditordb_postgres.c
@@ -13,7 +13,6 @@
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 plugin_auditordb_postgres.c
* @brief Low-level (statement-level) Postgres database access for the auditor
@@ -94,10 +93,14 @@ struct PostgresClosure
/**
- * Drop all Taler tables. This should only be used by testcases.
+ * Drop all auditor tables OR deletes recoverable auditor state.
+ * This should only be used by testcases or when restarting the
+ * auditor from scratch.
*
* @param cls the `struct PostgresClosure` with the plugin-specific state
- * @param drop_exchangelist should we also drop the exchange and deposit_confirmations table?
+ * @param drop_exchangelist drop all tables, including schema versioning
+ * and the exchange and deposit_confirmations table; NOT to be
+ * used when restarting the auditor
* @return #GNUNET_OK upon success; #GNUNET_SYSERR upon failure
*/
static int
@@ -106,8 +109,26 @@ postgres_drop_tables (void *cls,
{
struct PostgresClosure *pc = cls;
struct GNUNET_PQ_ExecuteStatement es[] = {
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_predicted_result;"),
+ GNUNET_PQ_make_execute (
+ "DELETE FROM auditor_historic_denomination_revenue;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_balance_summary;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_denomination_pending;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_reserve_balance;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_wire_fee_balance;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_reserves;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_progress_reserve;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_progress_aggregation;"),
+ GNUNET_PQ_make_execute (
+ "DELETE FROM auditor_progress_deposit_confirmation;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_progress_coin;"),
+ GNUNET_PQ_make_execute ("DELETE FROM wire_auditor_progress;"),
+ GNUNET_PQ_make_execute ("DELETE FROM wire_auditor_account_progress;"),
+ GNUNET_PQ_make_execute ("DELETE FROM auditor_historic_reserve_summary;"),
+ GNUNET_PQ_EXECUTE_STATEMENT_END
+ };
+ struct GNUNET_PQ_ExecuteStatement esx[] = {
GNUNET_PQ_make_execute ("DROP TABLE IF EXISTS auditor_predicted_result;"),
- GNUNET_PQ_make_execute ("DROP TABLE IF EXISTS auditor_historic_ledger;"),
GNUNET_PQ_make_execute (
"DROP TABLE IF EXISTS auditor_historic_denomination_revenue;"),
GNUNET_PQ_make_execute ("DROP TABLE IF EXISTS auditor_balance_summary;"),
@@ -127,14 +148,12 @@ postgres_drop_tables (void *cls,
"DROP TABLE IF EXISTS wire_auditor_account_progress;"),
GNUNET_PQ_make_execute (
"DROP TABLE IF EXISTS auditor_historic_reserve_summary CASCADE;"),
- GNUNET_PQ_EXECUTE_STATEMENT_END
- };
- struct GNUNET_PQ_ExecuteStatement esx[] = {
GNUNET_PQ_make_execute (
"DROP TABLE IF EXISTS auditor_denominations CASCADE;"),
GNUNET_PQ_make_execute (
"DROP TABLE IF EXISTS deposit_confirmations CASCADE;"),
GNUNET_PQ_make_execute ("DROP TABLE IF EXISTS auditor_exchanges CASCADE;"),
+ GNUNET_PQ_make_execute ("DROP SCHEMA IF EXISTS _v CASCADE;"),
GNUNET_PQ_EXECUTE_STATEMENT_END
};
struct GNUNET_PQ_Context *conn;
@@ -149,10 +168,6 @@ postgres_drop_tables (void *cls,
if (drop_exchangelist)
ret = GNUNET_PQ_exec_statements (conn,
esx);
- /* TODO: we probably need a bit more fine-grained control
- over drops for the '-r' option of taler-auditor; also,
- for the testcase, we currently fail to drop the
- auditor_denominations table... */
GNUNET_PQ_disconnect (conn);
return ret;
}
@@ -377,27 +392,6 @@ postgres_create_tables (void *cls)
",PRIMARY KEY (h_contract_terms, h_wire, coin_pub, "
" merchant_pub, exchange_sig, exchange_pub, master_sig)"
")"),
- /* Table with historic business ledger; basically, when the exchange
- operator decides to use operating costs for anything but wire
- transfers to merchants, it goes in here. This happens when the
- operator users transaction fees for business expenses. "purpose"
- is free-form but should be a human-readable wire transfer
- identifier. This is NOT yet used and outside of the scope of
- the core auditing logic. However, once we do take fees to use
- operating costs, and if we still want "auditor_predicted_result" to match
- the tables overall, we'll need a command-line tool to insert rows
- into this table and update "auditor_predicted_result" accordingly.
- (So this table for now just exists as a reminder of what we'll
- need in the long term.) */GNUNET_PQ_make_execute ("CREATE TABLE IF NOT EXISTS auditor_historic_ledger"
- "(master_pub BYTEA CONSTRAINT master_pub_ref REFERENCES auditor_exchanges(master_pub) ON DELETE CASCADE"
- ",purpose VARCHAR NOT NULL"
- ",timestamp INT8 NOT NULL"
- ",balance_val INT8 NOT NULL"
- ",balance_frac INT4 NOT NULL"
- ")"),
- GNUNET_PQ_make_try_execute (
- "CREATE INDEX history_ledger_by_master_pub_and_time "
- "ON auditor_historic_ledger(master_pub,timestamp)"),
/* Table with the sum of the ledger, auditor_historic_revenue and
the auditor_reserve_balance. This is the
final amount that the exchange should have in its bank account