Skip to content

Commit 8f24408

Browse files
authored
Merge pull request #60 from input-output-hk/next-2025-04-03
Node: 10.3.1, Cli: 10.7.0.0 for pre-release
2 parents 673268b + 7238c34 commit 8f24408

File tree

18 files changed

+502
-452
lines changed

18 files changed

+502
-452
lines changed

.github/workflows/nix-jobs-test.yaml

Lines changed: 8 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -130,12 +130,14 @@ jobs:
130130
done
131131
}
132132
133-
echo "Run nix job tests with release versioning..."
134-
echo "Running legacy sequence tests..."
135-
RUN_TESTS "${JOB_SEQ_LEGACY[@]}"
136-
137-
echo "Running sequence tests..."
138-
RUN_TESTS "${JOB_SEQ[@]}"
133+
# Pause release tests on versions < node 10.3.1
134+
# Re-enable when node release is >= 10.3.1
135+
# echo "Run nix job tests with release versioning..."
136+
# echo "Running legacy sequence tests..."
137+
# RUN_TESTS "${JOB_SEQ_LEGACY[@]}"
138+
#
139+
# echo "Running sequence tests..."
140+
# RUN_TESTS "${JOB_SEQ[@]}"
139141
140142
echo "Now run nix job tests again with pre-release versioning..."
141143
set -x

NOTICE

Lines changed: 22 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
Copyright 2023 Input Output Global Inc (IOG)
1+
Copyright 2023-2025 Input Output Global Inc (IOG)
22

33
Licensed under the Apache License, Version 2.0 (the "License");
44
you may not use this file except in compliance with the License.
@@ -11,3 +11,24 @@ distributed under the License is distributed on an "AS IS" BASIS,
1111
WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
1212
See the License for the specific language governing permissions and
1313
limitations under the License.
14+
15+
Attribution Notice:
16+
17+
This project may include third-party materials. These materials will be listed
18+
below as they are incorporated.
19+
20+
# Example template for attribution when third-party files are added:
21+
#
22+
# - File originally from [Original Project Name] repository:
23+
# https://github.com/username/original-repo
24+
# Licensed under the Apache License, Version 2.0.
25+
26+
Downstream projects may include various files from this repository. These files
27+
are provided under the same license terms and may be used, copied, modified,
28+
and distributed in accordance with the Apache License, Version 2.0.
29+
30+
The specific files incorporated from this repository into downstream projects
31+
may change over time. Downstream users are encouraged to include appropriate
32+
attribution in their own NOTICE or documentation files where applicable.
33+
34+
No endorsement by the original authors is implied.

flake.lock

Lines changed: 14 additions & 14 deletions
Some generated files are not rendered by default. Learn more about customizing how changed files appear on GitHub.

flake.nix

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -88,7 +88,7 @@
8888
};
8989

9090
cardano-wallet-service = {
91-
url = "github:cardano-foundation/cardano-wallet/v2024-03-01";
91+
url = "github:cardano-foundation/cardano-wallet/v2025-03-31";
9292
flake = false;
9393
};
9494

flake/nixosModules/profile-cardano-postgres.nix

Lines changed: 88 additions & 17 deletions
Original file line numberDiff line numberDiff line change
@@ -91,34 +91,105 @@
9191
PREPARE show_current_forging AS
9292
WITH
9393
current_epoch AS (
94-
SELECT MAX(epoch_no) AS current_epoch FROM block),
94+
SELECT MAX(epoch_no) AS epoch_no FROM block
95+
),
96+
9597
epoch_blocks AS (
96-
SELECT COUNT(block.block_no) AS epoch_blocks, pool_hash.view AS pool_view FROM block
98+
SELECT
99+
COUNT(block.block_no) AS epoch_blocks,
100+
pool_hash.view AS pool_view
101+
FROM block
97102
INNER JOIN slot_leader ON block.slot_leader_id = slot_leader.id
98103
INNER JOIN pool_hash ON slot_leader.pool_hash_id = pool_hash.id
99-
WHERE block.epoch_no = (SELECT * FROM current_epoch)
100-
GROUP BY pool_hash.view),
104+
INNER JOIN current_epoch ON block.epoch_no = current_epoch.epoch_no
105+
GROUP BY pool_hash.view
106+
),
107+
101108
last_blocks AS (
102-
SELECT distinct on (pool_hash.view) block.block_no AS last_block, block.time AS last_block_time, pool_hash.view AS pool_view FROM block
109+
SELECT DISTINCT ON (pool_hash.view)
110+
block.block_no AS last_block,
111+
block.time AS last_block_time,
112+
pool_hash.view AS pool_view
113+
FROM block
103114
INNER JOIN slot_leader ON block.slot_leader_id = slot_leader.id
104115
INNER JOIN pool_hash ON slot_leader.pool_hash_id = pool_hash.id
105-
ORDER BY pool_hash.view ASC, block.block_no desc),
116+
ORDER BY pool_hash.view, block.block_no DESC
117+
),
118+
106119
current_epoch_stake AS (
107-
SELECT SUM(amount) AS epoch_stake FROM epoch_stake
108-
WHERE epoch_no = (SELECT * FROM current_epoch))
120+
SELECT SUM(amount) AS total_stake
121+
FROM epoch_stake
122+
INNER JOIN current_epoch ON epoch_stake.epoch_no = current_epoch.epoch_no
123+
),
124+
125+
latest_pool_update AS (
126+
SELECT DISTINCT ON (hash_id)
127+
id AS pool_update_id,
128+
hash_id,
129+
meta_id
130+
FROM pool_update
131+
ORDER BY hash_id, id DESC
132+
),
133+
134+
latest_off_chain_data AS (
135+
SELECT DISTINCT ON (pool_id)
136+
pool_id,
137+
pmr_id,
138+
ticker_name
139+
FROM off_chain_pool_data
140+
ORDER BY pool_id, pmr_id DESC
141+
),
142+
143+
latest_pool_relay AS (
144+
SELECT DISTINCT ON (update_id)
145+
update_id,
146+
dns_name
147+
FROM pool_relay
148+
WHERE dns_name IS NOT NULL
149+
ORDER BY update_id, id DESC
150+
),
151+
152+
latest_pool_metadata_ref AS (
153+
SELECT DISTINCT ON (pool_id)
154+
pool_id,
155+
url
156+
FROM pool_metadata_ref
157+
ORDER BY pool_id, id DESC
158+
)
159+
109160
SELECT
110-
(SELECT * FROM current_epoch),
161+
current_epoch.epoch_no AS current_epoch,
111162
pool_hash.view AS pool_id,
112-
SUM(amount) AS lovelace,
113-
ROUND(SUM(amount) / (SELECT * FROM current_epoch_stake) * 100, 3) AS stake_pct,
114-
(SELECT epoch_blocks FROM epoch_blocks WHERE epoch_blocks.pool_view = pool_hash.view),
115-
(SELECT last_block FROM last_blocks WHERE last_blocks.pool_view = pool_hash.view),
116-
(SELECT last_block_time FROM last_blocks WHERE last_blocks.pool_view = pool_hash.view)
163+
COALESCE(
164+
latest_off_chain_data.ticker_name,
165+
latest_pool_relay.dns_name,
166+
latest_pool_metadata_ref.url
167+
) AS ticker_or_dns_or_url,
168+
ROUND(SUM(epoch_stake.amount) / 1e12, 2) AS "M_Ada",
169+
ROUND(SUM(epoch_stake.amount) / MAX(current_epoch_stake.total_stake) * 100, 3) AS stake_pct,
170+
epoch_blocks.epoch_blocks,
171+
last_blocks.last_block,
172+
last_blocks.last_block_time
117173
FROM epoch_stake
174+
INNER JOIN current_epoch ON epoch_stake.epoch_no = current_epoch.epoch_no
118175
INNER JOIN pool_hash ON epoch_stake.pool_id = pool_hash.id
119-
WHERE epoch_no = (SELECT * FROM current_epoch)
120-
GROUP BY pool_hash.id
121-
ORDER BY lovelace DESC;
176+
LEFT JOIN latest_pool_update ON latest_pool_update.hash_id = pool_hash.id
177+
LEFT JOIN latest_off_chain_data ON latest_off_chain_data.pmr_id = latest_pool_update.meta_id
178+
LEFT JOIN latest_pool_relay ON latest_pool_relay.update_id = latest_pool_update.pool_update_id
179+
LEFT JOIN latest_pool_metadata_ref ON latest_pool_metadata_ref.pool_id = pool_hash.id
180+
LEFT JOIN epoch_blocks ON epoch_blocks.pool_view = pool_hash.view
181+
LEFT JOIN last_blocks ON last_blocks.pool_view = pool_hash.view
182+
CROSS JOIN current_epoch_stake
183+
GROUP BY
184+
current_epoch.epoch_no,
185+
pool_hash.view,
186+
latest_off_chain_data.ticker_name,
187+
latest_pool_relay.dns_name,
188+
latest_pool_metadata_ref.url,
189+
epoch_blocks.epoch_blocks,
190+
last_blocks.last_block,
191+
last_blocks.last_block_time
192+
ORDER BY "M_Ada" DESC;
122193
123194
-- Show the number of blocks made per epoch across all epochs by one pool
124195
PREPARE show_pool_block_history_by_epoch_fn (varchar) AS

0 commit comments

Comments
 (0)