mirror of
https://github.com/GrassrootsEconomics/cic-dw.git
synced 2025-01-22 22:37:33 +01:00
fix: (sql) exclude system accounts from metrics
This commit is contained in:
parent
642ccdddaa
commit
f00e97cc94
19
migrations/003_exclude-sys.sql
Normal file
19
migrations/003_exclude-sys.sql
Normal file
@ -0,0 +1,19 @@
|
|||||||
|
CREATE TABLE IF NOT EXISTS sys_accounts (
|
||||||
|
id INT GENERATED ALWAYS AS IDENTITY PRIMARY KEY,
|
||||||
|
sys_address VARCHAR(40) NOT NULL,
|
||||||
|
address_description VARCHAR(100)
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX IF NOT EXISTS sys_address_idx ON sys_accounts USING hash(sys_address);
|
||||||
|
|
||||||
|
INSERT INTO sys_accounts(sys_address, address_description) VALUES
|
||||||
|
('bbb4a93c8dcd82465b73a143f00fed4af7492a27', 'sarafu sink address'),
|
||||||
|
('cd9fd1e71f684cfb30fa34831ed7ed59f6f77469', 'sarafu faucet'),
|
||||||
|
('b8830b647c01433f9492f315ddbfdc35cb3be6a6', 'ge community fund'),
|
||||||
|
('ca5da01b6dac771c8f3625aa1a8931e7dac41832', 'ge token deployer'),
|
||||||
|
('59a5e2faf8163fe24ca006a221dd0f34c5e0cb41', 'sarafu migrator'),
|
||||||
|
('289defd53e2d96f05ba29ebbebd9806c94d04cb6', 'sohail deployer');
|
||||||
|
|
||||||
|
---- create above / drop below ----
|
||||||
|
|
||||||
|
DROP TABLE IF EXISTS sys_accounts;
|
@ -17,12 +17,15 @@ LIMIT 730;
|
|||||||
-- Produces x, y results for displaying on a line chart
|
-- Produces x, y results for displaying on a line chart
|
||||||
WITH date_range AS (
|
WITH date_range AS (
|
||||||
SELECT day::date FROM generate_series($1, $2, INTERVAL '1 day') day
|
SELECT day::date FROM generate_series($1, $2, INTERVAL '1 day') day
|
||||||
|
),
|
||||||
|
exclude AS (
|
||||||
|
SELECT sys_address FROM sys_accounts WHERE sys_address IS NOT NULL
|
||||||
)
|
)
|
||||||
|
|
||||||
SELECT date_range.day AS x, COUNT(transactions.id) AS y
|
SELECT date_range.day AS x, COUNT(transactions.id) AS y
|
||||||
FROM date_range
|
FROM date_range
|
||||||
LEFT JOIN transactions ON date_range.day = CAST(transactions.date_block AS date)
|
LEFT JOIN transactions ON date_range.day = CAST(transactions.date_block AS date)
|
||||||
|
WHERE transactions.sender_address NOT IN (SELECT sys_address FROM exclude) AND transactions.recipient_address NOT IN (SELECT sys_address FROM exclude)
|
||||||
GROUP BY date_range.day
|
GROUP BY date_range.day
|
||||||
ORDER BY date_range.day
|
ORDER BY date_range.day
|
||||||
LIMIT 730;
|
LIMIT 730;
|
||||||
|
|
||||||
|
@ -5,7 +5,7 @@ INNER JOIN tokens on transactions.token_address = tokens.token_address
|
|||||||
WHERE transactions.sender_address = $1
|
WHERE transactions.sender_address = $1
|
||||||
OR transactions.recipient_address = $1;
|
OR transactions.recipient_address = $1;
|
||||||
|
|
||||||
-- Bidirectional cursor pagianators
|
-- Bidirectional cursor paginators
|
||||||
-- name: list-tokens-fwd
|
-- name: list-tokens-fwd
|
||||||
SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens
|
SELECT tokens.id, tokens.token_address, tokens.token_name, tokens.token_symbol FROM tokens
|
||||||
WHERE tokens.id > $1 ORDER BY tokens.id ASC LIMIT $2;
|
WHERE tokens.id > $1 ORDER BY tokens.id ASC LIMIT $2;
|
||||||
|
Loading…
Reference in New Issue
Block a user