Compare commits

...

4 Commits

Author SHA1 Message Date
Mohamed Sohail 93d07b8ca3
fix: coalesce null value 2022-11-16 17:21:01 +03:00
Mohamed Sohail f93727925e
patch: prevent multiple rows from inner query
` UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address`
2022-11-16 17:01:44 +03:00
Mohamed Sohail e158ce28bc
add: MUN to metrics
closes #54
2022-09-29 10:59:23 +03:00
Mohamed Sohail 18020e8451
fix: sql cmr queries 2022-08-26 07:59:14 +00:00
2 changed files with 24 additions and 24 deletions

View File

@ -20,8 +20,8 @@ SELECT phone_number FROM users WHERE blockchain_address = $1;
-- name: account-latest-transactions
-- Returns the first page of a users latest transactions
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -30,8 +30,8 @@ WHERE users.phone_number = $1 ORDER BY transactions.id DESC LIMIT $2;
-- name: account-latest-transactions-next
-- Returns the next page based on a cursor
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -41,8 +41,8 @@ WHERE users.phone_number = $1 AND transactions.id < $2 ORDER BY transactions.id
-- Returns the previous page based on cursor
SELECT * FROM (
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -52,8 +52,8 @@ SELECT * FROM (
-- name: account-latest-transactions-by-token
-- Returns the first page of a users latest transactions, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -62,8 +62,8 @@ WHERE users.phone_number = $1 AND tokens.token_symbol = $2 ORDER BY transactions
-- name: account-latest-transactions-by-token-next
-- Returns the next page based on a cursor, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -73,8 +73,8 @@ WHERE users.phone_number = $1 AND tokens.token_symbol = $2 AND transactions.id <
-- Returns the previous page based on cursor, filter by token
SELECT * FROM (
SELECT transactions.id, transactions.date_block, transactions.tx_hash, tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN tokens ON transactions.token_address = tokens.token_address
@ -84,8 +84,8 @@ SELECT * FROM (
-- name: account-latest-transactions-by-archived-token
-- Returns the first page of a users latest transactions, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, archived_tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN archived_tokens ON transactions.token_address = archived_tokens.token_address
@ -94,8 +94,8 @@ WHERE users.phone_number = $1 AND archived_tokens.token_address = $2 ORDER BY tr
-- name: account-latest-transactions-by-archived-token-next
-- Returns the next page based on a cursor, filter by token
SELECT transactions.id, transactions.date_block, transactions.tx_hash, archived_tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN archived_tokens ON transactions.token_address = archived_tokens.token_address
@ -105,10 +105,10 @@ WHERE users.phone_number = $1 AND archived_tokens.token_address = $2 AND transac
-- Returns the previous page based on cursor, filter by token
SELECT * FROM (
SELECT transactions.id, transactions.date_block, transactions.tx_hash, archived_tokens.token_symbol, transactions.sender_address, transactions.recipient_address, transactions.tx_value, transactions.success,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.sender_address) as sender_identifier,
(SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address UNION ALL SELECT address_description FROM sys_accounts WHERE sys_address = transactions.recipient_address) as recipient_identifier
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.sender_address), 'SYSTEM') as sender_identifier,
COALESCE((SELECT phone_number FROM users WHERE blockchain_address = transactions.recipient_address), 'SYSTEM') as recipient_identifier
FROM transactions
INNER JOIN users ON ((transactions.sender_address = users.blockchain_address) OR (transactions.recipient_address = users.blockchain_address))
INNER JOIN archived_tokens ON transactions.token_address = archived_tokens.token_address
WHERE users.phone_number = $1 AND archived_tokens.token_address = $2 AND transactions.id > $3 ORDER BY transactions.id ASC LIMIT $4
) AS previous_page ORDER BY id DESC;
) AS previous_page ORDER BY id DESC;

View File

@ -17,7 +17,7 @@ LIMIT 730;
-- This query generates a date range and left joins the users table to include days with no registrations
-- Produces x, y results for displaying on a line chart
WITH date_range AS (
SELECT day::date FROM generate_series('08-01-2022', '08-26-2022', INTERVAL '1 day') day
SELECT day::date FROM generate_series($1, $2, INTERVAL '1 day') day
)
SELECT date_range.day AS x, COUNT(users.id) AS y
@ -47,18 +47,18 @@ GROUP BY date_range.day
ORDER BY date_range.day
LIMIT 730;
-- name: transaction-count-cmr
-- name: transactions-count-cmr
-- This is a patch to support CMR dashboard
-- This query generates a date range and left joins the transactions table to include days with no transactions
-- Produces x, y results for displaying on a line chart
WITH date_range AS (
SELECT day::date FROM generate_series('08-01-2022', '08-26-2022', 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
),
cmr_tokens AS (
SELECT token_address from tokens WHERE token_symbol IN ('MBIP')
SELECT token_address from tokens WHERE token_symbol IN ('MBIP', 'MUN')
)
SELECT date_range.day AS x, COUNT(transactions.id) AS y
FROM date_range
@ -112,4 +112,4 @@ LIMIT 730;
--name: latest-token-transactions
-- Returns latest token transactions, with curosr forward query and limit
SELECT id, block_number, date_block, tx_hash, sender_address, recipient_address, tx_value, success FROM transactions
WHERE token_address = $1 AND date_block > TIMESTAMP 'yesterday' ORDER BY id DESC;
WHERE token_address = $1 AND date_block > TIMESTAMP 'yesterday' ORDER BY id DESC;