Skip to content

Commit c8e2b9f

Browse files
canton-network-daDA Automation
andauthored
Update Splice from CCI (#319)
Signed-off-by: DA Automation <splice-maintainers@digitalasset.com> Co-authored-by: DA Automation <splice-maintainers@digitalasset.com>
1 parent 06f5517 commit c8e2b9f

File tree

7 files changed

+317
-75
lines changed

7 files changed

+317
-75
lines changed

.envrc.vars

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -25,6 +25,8 @@ export POSTGRES_HOST="localhost"
2525
export POSTGRES_USER=postgres
2626
export POSTGRES_PASSWORD=postgres
2727

28+
export DEPLOYMENT_DIR="${SPLICE_ROOT}/cluster/deployment"
29+
2830
# Include all organization specific `.envrc.vars.*` files
2931
if stat --printf='' .envrc.vars.* 2>/dev/null; then
3032
for file in .envrc.vars.*; do
Lines changed: 243 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,243 @@
1+
-- This migration adds the following columns to the update_history_creates table:
2+
-- record_time, update_id, domain_id, migration_id
3+
-- This information is already present in the update_history_transactions table,
4+
-- we are denormalizing it in order to allow us to write more efficient queries.
5+
6+
-- Step 1: create a copy of update_history_creates with the new columns
7+
-- We use this approach because it is orders of magnitude faster than using ALTER TABLE + UPDATE.
8+
9+
create table update_history_creates_v2
10+
(
11+
history_id int not null,
12+
row_id bigint generated by default as identity,
13+
ingested_at timestamptz not null default now(),
14+
event_id text not null,
15+
update_row_id bigint not null,
16+
contract_id text not null,
17+
created_at bigint not null,
18+
template_id_package_id text not null,
19+
template_id_module_name text not null,
20+
template_id_entity_name text not null,
21+
package_name text not null,
22+
create_arguments jsonb not null,
23+
signatories text[] not null, -- not null contraint missing in original
24+
observers text[] not null, -- not null contraint missing in original
25+
contract_key jsonb,
26+
record_time bigint not null,
27+
update_id text not null,
28+
domain_id text not null,
29+
migration_id int not null,
30+
31+
constraint update_history_creates_v2_pkey primary key (row_id)
32+
);
33+
34+
insert into update_history_creates_v2 (
35+
history_id,
36+
row_id,
37+
ingested_at,
38+
event_id,
39+
update_row_id,
40+
contract_id,
41+
created_at,
42+
template_id_package_id,
43+
template_id_module_name,
44+
template_id_entity_name,
45+
package_name,
46+
create_arguments,
47+
signatories,
48+
observers,
49+
contract_key,
50+
record_time,
51+
update_id,
52+
domain_id,
53+
migration_id
54+
) select
55+
c.history_id,
56+
c.row_id,
57+
c.ingested_at,
58+
c.event_id,
59+
c.update_row_id,
60+
c.contract_id,
61+
c.created_at,
62+
c.template_id_package_id,
63+
c.template_id_module_name,
64+
c.template_id_entity_name,
65+
c.package_name,
66+
c.create_arguments,
67+
c.signatories,
68+
c.observers,
69+
c.contract_key,
70+
u.record_time,
71+
u.update_id,
72+
u.domain_id,
73+
u.migration_id
74+
from update_history_creates c
75+
join update_history_transactions u on c.update_row_id = u.row_id;
76+
77+
78+
-- Step 2: drop the old table and rename the new one
79+
80+
alter table acs_snapshot_data
81+
drop constraint acs_snapshot_data_create_id_fkey;
82+
drop table update_history_creates;
83+
84+
85+
alter table update_history_creates_v2
86+
rename to update_history_creates;
87+
alter table update_history_creates
88+
rename constraint update_history_creates_v2_pkey to update_history_creates_pkey;
89+
90+
91+
-- Step 3: add indexes (do this before adding foreign key constraints, because the index will be used in verifying the constraint)
92+
93+
create unique index updt_hist_crea_unique
94+
on update_history_creates (update_row_id, event_id);
95+
96+
create index contract_create_lookup
97+
on update_history_creates (contract_id);
98+
99+
create index updt_hist_crea_hi_tidmn_tiden_pn_rid
100+
on update_history_creates (history_id, template_id_module_name, template_id_entity_name, package_name, row_id);
101+
102+
create index updt_hist_crea_hi_mi_rt
103+
on update_history_creates(history_id, migration_id, record_time);
104+
105+
106+
-- Step 4: restore foreign key constraints and sequences
107+
108+
alter table update_history_creates
109+
add constraint update_history_creates_history_id_fkey
110+
foreign key (history_id) references update_history_descriptors (id);
111+
112+
alter table update_history_creates
113+
add constraint update_history_creates_update_row_id_fkey
114+
foreign key (update_row_id) references update_history_transactions (row_id);
115+
116+
-- This works because we copy the values in the autogenerated row_id column
117+
alter table acs_snapshot_data
118+
add constraint acs_snapshot_data_create_id_fkey
119+
foreign key (create_id) references update_history_creates (row_id);
120+
121+
select setval(pg_get_serial_sequence('update_history_creates', 'row_id'), coalesce(max(row_id), 1))
122+
from update_history_creates;
123+
124+
125+
-- And the same for the exercise table
126+
-- Step 1: create a copy of update_history_exercises with the new columns
127+
128+
create table update_history_exercises_v2 (
129+
history_id int not null,
130+
row_id bigint generated by default as identity,
131+
ingested_at timestamptz not null default now(),
132+
event_id text not null,
133+
update_row_id bigint not null,
134+
child_event_ids text[] not null,
135+
choice text not null,
136+
template_id_package_id text not null,
137+
template_id_module_name text not null,
138+
template_id_entity_name text not null,
139+
contract_id text not null,
140+
consuming boolean not null,
141+
argument jsonb not null,
142+
result jsonb not null,
143+
package_name text not null,
144+
interface_id_package_id text,
145+
interface_id_module_name text,
146+
interface_id_entity_name text,
147+
acting_parties text[] not null,
148+
record_time bigint not null,
149+
update_id text not null,
150+
domain_id text not null,
151+
migration_id int not null,
152+
153+
constraint update_history_exercises_v2_pkey primary key (row_id)
154+
);
155+
156+
insert into update_history_exercises_v2 (
157+
history_id,
158+
row_id,
159+
ingested_at,
160+
event_id,
161+
update_row_id,
162+
child_event_ids,
163+
choice,
164+
template_id_package_id,
165+
template_id_module_name,
166+
template_id_entity_name,
167+
contract_id,
168+
consuming,
169+
argument,
170+
result,
171+
package_name,
172+
interface_id_package_id,
173+
interface_id_module_name,
174+
interface_id_entity_name,
175+
acting_parties,
176+
record_time,
177+
update_id,
178+
domain_id,
179+
migration_id
180+
)
181+
select
182+
e.history_id,
183+
e.row_id,
184+
e.ingested_at,
185+
e.event_id,
186+
e.update_row_id,
187+
e.child_event_ids,
188+
e.choice,
189+
e.template_id_package_id,
190+
e.template_id_module_name,
191+
e.template_id_entity_name,
192+
e.contract_id,
193+
e.consuming,
194+
e.argument,
195+
e.result,
196+
e.package_name,
197+
e.interface_id_package_id,
198+
e.interface_id_module_name,
199+
e.interface_id_entity_name,
200+
e.acting_parties,
201+
u.record_time,
202+
u.update_id,
203+
u.domain_id,
204+
u.migration_id
205+
from update_history_exercises e
206+
join update_history_transactions u on e.update_row_id = u.row_id;
207+
208+
209+
-- Step 2: drop the old table and rename the new one
210+
211+
drop table update_history_exercises;
212+
213+
alter table update_history_exercises_v2
214+
rename to update_history_exercises;
215+
alter table update_history_exercises
216+
rename constraint update_history_exercises_v2_pkey to update_history_exercises_pkey;
217+
218+
219+
-- Step 3: add indexes (do this before adding foreign key constraints, because the index will be used in verifying the constraint)
220+
221+
create index updt_hist_exer_hi_mi_rt_co on update_history_exercises(history_id, migration_id, record_time, consuming);
222+
223+
create unique index updt_hist_exer_unique on update_history_exercises (update_row_id, event_id);
224+
225+
226+
-- Step 4: restore foreign key constraints and sequences
227+
228+
alter table update_history_exercises
229+
add constraint update_history_exercises_history_id_fkey
230+
foreign key (history_id) references update_history_descriptors (id);
231+
232+
alter table update_history_exercises
233+
add constraint update_history_exercises_update_row_id_fkey
234+
foreign key (update_row_id) references update_history_transactions (row_id);
235+
236+
select setval(pg_get_serial_sequence('update_history_exercises', 'row_id'), coalesce(max(row_id), 1))
237+
from update_history_exercises;
238+
239+
240+
-- From V016__append_only_autovacumm.sql:
241+
242+
alter table update_history_exercises set (autovacuum_analyze_scale_factor = 0, autovacuum_analyze_threshold = 20000);
243+
alter table update_history_creates set (autovacuum_analyze_scale_factor = 0, autovacuum_analyze_threshold = 20000);

apps/common/src/main/scala/org/lfdecentralizedtrust/splice/store/UpdateHistory.scala

Lines changed: 24 additions & 28 deletions
Original file line numberDiff line numberDiff line change
@@ -451,9 +451,9 @@ class UpdateHistory(
451451
DBIOAction.seq[Effect.Write](
452452
tree.getEventsById.values().asScala.toSeq.map {
453453
case created: CreatedEvent =>
454-
insertCreateEventRow(created, updateRowId)
454+
insertCreateEventRow(created, tree, migrationId, updateRowId)
455455
case exercised: ExercisedEvent =>
456-
insertExerciseEventRow(exercised, updateRowId)
456+
insertExerciseEventRow(exercised, tree, migrationId, updateRowId)
457457
case _ =>
458458
throw new RuntimeException("Unsupported event type")
459459
}*
@@ -491,6 +491,8 @@ class UpdateHistory(
491491

492492
private def insertCreateEventRow(
493493
event: CreatedEvent,
494+
tree: TransactionTree,
495+
migrationId: Long,
494496
updateRowId: Long,
495497
): DBIOAction[?, NoStream, Effect.Write] = {
496498
val safeEventId = lengthLimited(event.getEventId)
@@ -507,27 +509,34 @@ class UpdateHistory(
507509
val safeCreatedAt = CantonTimestamp.assertFromInstant(event.createdAt)
508510
val safeSignatories = event.getSignatories.asScala.toSeq.map(lengthLimited)
509511
val safeObservers = event.getObservers.asScala.toSeq.map(lengthLimited)
512+
val recordTime = CantonTimestamp.assertFromInstant(tree.getRecordTime)
513+
val safeUpdateId = lengthLimited(tree.getUpdateId)
514+
val safeDomainId = lengthLimited(tree.getDomainId)
510515

511516
sqlu"""
512517
insert into update_history_creates(
513518
history_id, event_id, update_row_id,
514519
contract_id, created_at,
515520
template_id_package_id, template_id_module_name, template_id_entity_name,
516521
package_name, create_arguments, signatories, observers,
517-
contract_key
522+
contract_key,
523+
record_time, update_id, domain_id, migration_id
518524
)
519525
values (
520526
$historyId, $safeEventId, $updateRowId,
521527
$safeContractId, $safeCreatedAt,
522528
$templateIdPackageId, $templateIdModuleName, $templateIdEntityName,
523529
$safePackageName, $createArguments::jsonb, $safeSignatories, $safeObservers,
524-
$contractKey::jsonb
530+
$contractKey::jsonb,
531+
$recordTime, $safeUpdateId, $safeDomainId, $migrationId
525532
)
526533
"""
527534
}
528535

529536
private def insertExerciseEventRow(
530537
event: ExercisedEvent,
538+
tree: TransactionTree,
539+
migrationId: Long,
531540
updateRowId: Long,
532541
): DBIOAction[?, NoStream, Effect.Write] = {
533542
val safeEventId = lengthLimited(event.getEventId)
@@ -550,6 +559,9 @@ class UpdateHistory(
550559
event.getInterfaceId.toScala.map(i => lengthLimited(i.getEntityName))
551560
val interfaceIdPackageId =
552561
event.getInterfaceId.toScala.map(i => lengthLimited(i.getPackageId))
562+
val recordTime = CantonTimestamp.assertFromInstant(tree.getRecordTime)
563+
val safeUpdateId = lengthLimited(tree.getUpdateId)
564+
val safeDomainId = lengthLimited(tree.getDomainId)
553565

554566
sqlu"""
555567
insert into update_history_exercises(
@@ -559,7 +571,8 @@ class UpdateHistory(
559571
contract_id, consuming,
560572
package_name, argument, result,
561573
acting_parties,
562-
interface_id_package_id, interface_id_module_name, interface_id_entity_name
574+
interface_id_package_id, interface_id_module_name, interface_id_entity_name,
575+
record_time, update_id, domain_id, migration_id
563576
)
564577
values (
565578
$historyId, $safeEventId, $updateRowId,
@@ -568,7 +581,8 @@ class UpdateHistory(
568581
$safeContractId, ${event.isConsuming},
569582
$safePackageName, $choiceArguments::jsonb, $exerciseResult::jsonb,
570583
$safeActingParties,
571-
$interfaceIdPackageId, $interfaceIdModuleName, $interfaceIdEntityName
584+
$interfaceIdPackageId, $interfaceIdModuleName, $interfaceIdEntityName,
585+
$recordTime, $safeUpdateId, $safeDomainId, $migrationId
572586
)
573587
"""
574588
}
@@ -602,23 +616,11 @@ class UpdateHistory(
602616
Seq(
603617
sqlu"""
604618
delete from update_history_creates
605-
where update_row_id in (
606-
select row_id
607-
from update_history_transactions
608-
where history_id = $historyId and migration_id = $migrationId and record_time > $recordTime
609-
-- order clause forces the query planner to use the updt_hist_tran_hi_mi_rt_di index
610-
order by record_time
611-
)
619+
where history_id = $historyId and migration_id = $migrationId and record_time > $recordTime
612620
""",
613621
sqlu"""
614622
delete from update_history_exercises
615-
where update_row_id in (
616-
select row_id
617-
from update_history_transactions
618-
where history_id = $historyId and migration_id = $migrationId and record_time > $recordTime
619-
-- order clause forces the query planner to use the updt_hist_tran_hi_mi_rt_di index
620-
order by record_time
621-
)
623+
where history_id = $historyId and migration_id = $migrationId and record_time > $recordTime
622624
""",
623625
sqlu"""
624626
delete from update_history_transactions
@@ -713,16 +715,10 @@ class UpdateHistory(
713715

714716
val deleteAction = for {
715717
numCreates <- (
716-
sql"delete from update_history_creates where update_row_id in (" ++
717-
sql"select row_id from update_history_transactions where " ++ filterCondition ++
718-
// order clause forces the query planner to use the updt_hist_tran_hi_mi_rt_di index
719-
sql" order by record_time)"
718+
sql"delete from update_history_creates where " ++ filterCondition
720719
).toActionBuilder.asUpdate
721720
numExercises <- (
722-
sql"delete from update_history_exercises where update_row_id in (" ++
723-
sql"select row_id from update_history_transactions where " ++ filterCondition ++
724-
// order clause forces the query planner to use the updt_hist_tran_hi_mi_rt_di index
725-
sql" order by record_time)"
721+
sql"delete from update_history_exercises where " ++ filterCondition
726722
).toActionBuilder.asUpdate
727723
numTransactions <- (
728724
sql"delete from update_history_transactions where " ++ filterCondition

0 commit comments

Comments
 (0)