Skip to content

Commit 39ab894

Browse files
committed
Add payer reports table
1 parent 7d1bea7 commit 39ab894

File tree

3 files changed

+106
-52
lines changed

3 files changed

+106
-52
lines changed

pkg/db/sqlc/payerReports.sql

+79-52
Original file line numberDiff line numberDiff line change
@@ -1,68 +1,95 @@
11
-- name: FindOrCreatePayer :one
22
INSERT INTO payers(address)
3-
VALUES (@address)
4-
ON CONFLICT (address)
5-
DO UPDATE SET
6-
address = @address
7-
RETURNING
8-
id;
3+
VALUES (@address) ON CONFLICT (address) DO
4+
UPDATE
5+
SET address = @address
6+
RETURNING id;
97

108
-- name: IncrementUnsettledUsage :exec
11-
INSERT INTO unsettled_usage(payer_id, originator_id, minutes_since_epoch, spend_picodollars, last_sequence_id)
12-
VALUES (@payer_id, @originator_id, @minutes_since_epoch, @spend_picodollars, @sequence_id)
13-
ON CONFLICT (payer_id, originator_id, minutes_since_epoch)
14-
DO UPDATE SET
15-
spend_picodollars = unsettled_usage.spend_picodollars + @spend_picodollars,
16-
last_sequence_id = GREATEST(unsettled_usage.last_sequence_id, @sequence_id);
9+
INSERT INTO unsettled_usage(
10+
payer_id,
11+
originator_id,
12+
minutes_since_epoch,
13+
spend_picodollars,
14+
last_sequence_id
15+
)
16+
VALUES (
17+
@payer_id,
18+
@originator_id,
19+
@minutes_since_epoch,
20+
@spend_picodollars,
21+
@sequence_id
22+
) ON CONFLICT (payer_id, originator_id, minutes_since_epoch) DO
23+
UPDATE
24+
SET spend_picodollars = unsettled_usage.spend_picodollars + @spend_picodollars,
25+
last_sequence_id = GREATEST(unsettled_usage.last_sequence_id, @sequence_id);
1726

1827
-- name: GetPayerUnsettledUsage :one
19-
SELECT
20-
COALESCE(SUM(spend_picodollars), 0)::BIGINT AS total_spend_picodollars,
28+
SELECT COALESCE(SUM(spend_picodollars), 0)::BIGINT AS total_spend_picodollars,
2129
COALESCE(MAX(last_sequence_id), 0)::BIGINT AS last_sequence_id
22-
FROM
23-
unsettled_usage
24-
WHERE
25-
payer_id = @payer_id
26-
AND (@minutes_since_epoch_gt::BIGINT = 0
27-
OR minutes_since_epoch > @minutes_since_epoch_gt::BIGINT)
28-
AND (@minutes_since_epoch_lt::BIGINT = 0
29-
OR minutes_since_epoch < @minutes_since_epoch_lt::BIGINT);
30+
FROM unsettled_usage
31+
WHERE payer_id = @payer_id
32+
AND (
33+
@minutes_since_epoch_gt::BIGINT = 0
34+
OR minutes_since_epoch > @minutes_since_epoch_gt::BIGINT
35+
)
36+
AND (
37+
@minutes_since_epoch_lt::BIGINT = 0
38+
OR minutes_since_epoch < @minutes_since_epoch_lt::BIGINT
39+
);
3040

3141
-- name: BuildPayerReport :many
32-
SELECT
33-
payers.address as payer_address,
42+
SELECT payers.address AS payer_address,
3443
SUM(spend_picodollars)::BIGINT AS total_spend_picodollars
35-
FROM
36-
unsettled_usage
37-
JOIN payers on payers.id = unsettled_usage.payer_id
38-
WHERE
39-
originator_id = @originator_id
44+
FROM unsettled_usage
45+
JOIN payers ON payers.id = unsettled_usage.payer_id
46+
WHERE originator_id = @originator_id
4047
AND minutes_since_epoch > @start_minutes_since_epoch
4148
AND minutes_since_epoch <= @end_minutes_since_epoch
42-
GROUP BY
43-
payers.address;
49+
GROUP BY payers.address;
4450

4551
-- name: GetGatewayEnvelopeByID :one
46-
SELECT * FROM gateway_envelopes
47-
WHERE originator_sequence_id = @originator_sequence_id
48-
-- Include the node ID to take advantage of the primary key index
49-
AND originator_node_id = @originator_node_id;
52+
SELECT *
53+
FROM gateway_envelopes
54+
WHERE originator_sequence_id = @originator_sequence_id -- Include the node ID to take advantage of the primary key index
55+
AND originator_node_id = @originator_node_id;
5056

5157
-- name: GetSecondNewestMinute :one
52-
WITH second_newest_minute
53-
AS
54-
(
55-
SELECT minutes_since_epoch
56-
FROM unsettled_usage
57-
WHERE originator_id = @originator_id
58-
AND unsettled_usage.minutes_since_epoch > @minimum_minutes_since_epoch
59-
GROUP BY unsettled_usage.minutes_since_epoch
60-
ORDER BY unsettled_usage.minutes_since_epoch DESC
61-
LIMIT 1
62-
OFFSET 1)
63-
SELECT coalesce(max(last_sequence_id), 0)::BIGINT as max_sequence_id,
64-
coalesce(max(unsettled_usage.minutes_since_epoch), 0)::INT as minutes_since_epoch
65-
FROM unsettled_usage
66-
JOIN second_newest_minute
67-
ON second_newest_minute.minutes_since_epoch = unsettled_usage.minutes_since_epoch
68-
WHERE unsettled_usage.originator_id = @originator_id;
58+
WITH second_newest_minute AS (
59+
SELECT minutes_since_epoch
60+
FROM unsettled_usage
61+
WHERE originator_id = @originator_id
62+
AND unsettled_usage.minutes_since_epoch > @minimum_minutes_since_epoch
63+
GROUP BY unsettled_usage.minutes_since_epoch
64+
ORDER BY unsettled_usage.minutes_since_epoch DESC
65+
LIMIT 1 OFFSET 1
66+
)
67+
SELECT coalesce(max(last_sequence_id), 0)::BIGINT AS max_sequence_id,
68+
coalesce(max(unsettled_usage.minutes_since_epoch), 0)::INT AS minutes_since_epoch
69+
FROM unsettled_usage
70+
JOIN second_newest_minute ON second_newest_minute.minutes_since_epoch = unsettled_usage.minutes_since_epoch
71+
WHERE unsettled_usage.originator_id = @originator_id;
72+
73+
-- name: InsertOrIgnorePayerReport :exec
74+
INSERT INTO payer_reports (
75+
id,
76+
start_sequence_id,
77+
end_sequence_id,
78+
payers_merkle_root,
79+
payers_leaf_count,
80+
nodes_merkle_root,
81+
nodes_leaf_count
82+
)
83+
VALUES (
84+
@id,
85+
@start_sequence_id,
86+
@end_sequence_id,
87+
@payers_merkle_root,
88+
@payers_leaf_count,
89+
@nodes_merkle_root,
90+
@nodes_leaf_count
91+
) ON CONFLICT (id) DO NOTHING;
92+
93+
-- name: InsertPayerReportAttestation :exec
94+
INSERT INTO payer_report_attestations (payer_report_id, node_id, signature)
95+
VALUES (@payer_report_id, @node_id, @signature) ON CONFLICT (payer_report_id, node_id) DO NOTHING;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
DROP TABLE IF EXISTS payer_reports;
2+
3+
DROP TABLE IF EXISTS payer_report_attestations;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,24 @@
1+
CREATE TABLE payer_reports (
2+
id BYTEA PRIMARY KEY,
3+
start_sequence_id BIGINT NOT NULL,
4+
end_sequence_id BIGINT NOT NULL,
5+
payers_merkle_root BYTEA NOT NULL,
6+
payers_leaf_count BIGINT NOT NULL,
7+
nodes_merkle_root BYTEA NOT NULL,
8+
nodes_leaf_count BIGINT NOT NULL,
9+
-- 0 = pending, 1 = submitted, 2 = settled
10+
submission_status SMALLINT NOT NULL DEFAULT 0,
11+
created_at TIMESTAMP DEFAULT NOW()
12+
);
13+
14+
CREATE INDEX ON payer_reports (submission_status);
15+
16+
CREATE TABLE payer_report_attestations (
17+
payer_report_id BYTEA NOT NULL REFERENCES payer_reports(id) ON DELETE CASCADE,
18+
node_id BIGINT NOT NULL,
19+
signature BYTEA NOT NULL,
20+
created_at TIMESTAMP DEFAULT NOW(),
21+
PRIMARY KEY (payer_report_id, node_id)
22+
);
23+
24+
CREATE INDEX ON payer_report_attestations (payer_report_id);

0 commit comments

Comments
 (0)