Extract SQL to a template file.

This commit is contained in:
Chris Berkhout 2021-04-22 13:23:06 +02:00
parent 2371ceda11
commit c9e95ca322
4 changed files with 56 additions and 50 deletions

View file

@ -38,7 +38,7 @@ def cmd_fetch(args):
source = sources.by_id[args.source]() source = sources.by_id[args.source]()
output = outputs.by_type[args.output]() output = outputs.by_type[args.output]()
prices = source.fetch(args.pair, args.start, args.end) prices = source.fetch(args.pair, args.start, args.end)
print(output.format(prices)) print(output.format(prices), end="")
def build_parser(): def build_parser():

View file

@ -1,5 +1,6 @@
import hashlib import hashlib
from datetime import datetime from datetime import datetime
from importlib.resources import read_text
from pricehist import __version__ from pricehist import __version__
@ -9,7 +10,7 @@ class GnuCashSQL:
source = "pricehist" source = "pricehist"
typ = "unknown" typ = "unknown"
values = [] values_parts = []
for price in prices: for price in prices:
date = f"{price.date} 00:00:00" date = f"{price.date} 00:00:00"
m = hashlib.sha256() m = hashlib.sha256()
@ -33,54 +34,15 @@ class GnuCashSQL:
f"{value_denom}" f"{value_denom}"
")" ")"
) )
values.append(v) values_parts.append(v)
values = ",\n".join(values_parts)
comma_newline = ",\n" sql = read_text("pricehist.resources", "gnucash.sql").format(
sql = f"""\ version=__version__,
-- Created by pricehist v{__version__} at {datetime.utcnow().isoformat()}Z timestamp=datetime.utcnow().isoformat() + "Z",
base=price.base,
BEGIN; quote=price.quote,
values=values,
-- The GnuCash database must already have entries for the relevant commodities. )
-- These statements fail and later changes are skipped if that isn't the case.
CREATE TEMPORARY TABLE guids (mnemonic TEXT NOT NULL, guid TEXT NOT NULL);
INSERT INTO guids VALUES ('{price.base}', (SELECT guid FROM commodities WHERE mnemonic = '{price.base}' LIMIT 1));
INSERT INTO guids VALUES ('{price.quote}', (SELECT guid FROM commodities WHERE mnemonic = '{price.quote}' LIMIT 1));
-- Create a staging table for the new price data.
-- Doing this via a SELECT ensures the correct date type across databases.
CREATE TEMPORARY TABLE new_prices AS
SELECT p.guid, p.date, c.mnemonic AS base, c.mnemonic AS quote, p.source, p.type, p.value_num, p.value_denom
FROM prices p, commodities c
WHERE FALSE;
-- Populate the staging table.
INSERT INTO new_prices (guid, date, base, quote, source, type, value_num, value_denom) VALUES
{comma_newline.join(values)}
;
-- Get some numbers for the summary.
CREATE TEMPORARY TABLE summary (description TEXT, num INT);
INSERT INTO summary VALUES ('staged rows', (SELECT COUNT(*) FROM new_prices));
INSERT INTO summary VALUES ('existing rows', (SELECT COUNT(*) FROM new_prices tp, prices p where p.guid = tp.guid));
INSERT INTO summary VALUES ('additional rows', (SELECT COUNT(*) FROM new_prices WHERE guid NOT IN (SELECT guid FROM prices)));
-- Insert the new prices into the prices table, unless they're already there.
INSERT INTO prices (guid, commodity_guid, currency_guid, date, source, type, value_num, value_denom)
SELECT tp.guid, g1.guid, g2.guid, tp.date, tp.source, tp.type, tp.value_num, tp.value_denom
FROM new_prices tp, guids g1, guids g2
WHERE tp.base = g1.mnemonic
AND tp.quote = g2.mnemonic
AND tp.guid NOT IN (SELECT guid FROM prices)
;
-- Show the summary.
SELECT * FROM summary;
-- Show the final relevant rows of the main prices table
SELECT 'final' AS status, p.* FROM prices p WHERE p.guid IN (SELECT guid FROM new_prices) ORDER BY p.date;
COMMIT;
"""
return sql return sql

View file

View file

@ -0,0 +1,44 @@
-- Created by pricehist v{version} at {timestamp}
BEGIN;
-- The GnuCash database must already have entries for the relevant commodities.
-- These statements fail and later changes are skipped if that isn't the case.
CREATE TEMPORARY TABLE guids (mnemonic TEXT NOT NULL, guid TEXT NOT NULL);
INSERT INTO guids VALUES ('{base}', (SELECT guid FROM commodities WHERE mnemonic = '{base}' LIMIT 1));
INSERT INTO guids VALUES ('{quote}', (SELECT guid FROM commodities WHERE mnemonic = '{quote}' LIMIT 1));
-- Create a staging table for the new price data.
-- Doing this via a SELECT ensures the correct date type across databases.
CREATE TEMPORARY TABLE new_prices AS
SELECT p.guid, p.date, c.mnemonic AS base, c.mnemonic AS quote, p.source, p.type, p.value_num, p.value_denom
FROM prices p, commodities c
WHERE FALSE;
-- Populate the staging table.
INSERT INTO new_prices (guid, date, base, quote, source, type, value_num, value_denom) VALUES
{values}
;
-- Get some numbers for the summary.
CREATE TEMPORARY TABLE summary (description TEXT, num INT);
INSERT INTO summary VALUES ('staged rows', (SELECT COUNT(*) FROM new_prices));
INSERT INTO summary VALUES ('pre-existing rows', (SELECT COUNT(*) FROM new_prices tp, prices p where p.guid = tp.guid));
INSERT INTO summary VALUES ('additional rows', (SELECT COUNT(*) FROM new_prices WHERE guid NOT IN (SELECT guid FROM prices)));
-- Insert the new prices into the prices table, unless they're already there.
INSERT INTO prices (guid, commodity_guid, currency_guid, date, source, type, value_num, value_denom)
SELECT tp.guid, g1.guid, g2.guid, tp.date, tp.source, tp.type, tp.value_num, tp.value_denom
FROM new_prices tp, guids g1, guids g2
WHERE tp.base = g1.mnemonic
AND tp.quote = g2.mnemonic
AND tp.guid NOT IN (SELECT guid FROM prices)
;
-- Show the summary.
SELECT * FROM summary;
-- Show the final relevant rows of the main prices table
SELECT 'final' AS status, p.* FROM prices p WHERE p.guid IN (SELECT guid FROM new_prices) ORDER BY p.date;
COMMIT;