1
0
mirror of https://github.com/google/nomulus synced 2025-12-23 14:25:44 +00:00

Add hash indexes for common use cases (#2834)

I went through all the SQL statements generated by some sample
DomainCreateFlow and DomainDeleteFlow cases to find situations where we
were either SELECTing from, or UPDATEing, tables with a direct "field =
value" format. These are the situations that I found where we can add
hash indexes. This does two things:

1. Makes these queries slight faster, since these are usually queries on
   columns that are either unique or very close to unique, and O(1) is
   faster than O(log(n))
2. Spreads around the optimistic predicate locks on the previously-used
   btree indexes. Many of our serialization errors came from the fact
   that we were autogenerating incrementing ID values for various
   tables, meaning that SELECTs, INSERTs, and UPDATEs would all try to
   take predicate locks out on the same page of the btree index. Using a
   hash index means that the page locks will be spread out to various
   index pages, rather than conflicting with each other.

Running load tests on alpha I see significant improvements in speed and
error rates. Speed is hard to quantify due to the nature of the way the
load tests distribute tasks among the queues but it could be more than
50% improvement, and serialization errors in the logs drop by more than
90%.
This commit is contained in:
gbrodman
2025-09-29 18:16:24 -04:00
committed by GitHub
parent 5700a008d6
commit 97d0b7680f
16 changed files with 538 additions and 6 deletions

View File

@@ -261,11 +261,11 @@ td.section {
</tr>
<tr>
<td class="property_name">generated on</td>
<td class="property_value">2025-09-05 16:11:29</td>
<td class="property_value">2025-09-29 21:19:42</td>
</tr>
<tr>
<td class="property_name">last flyway file</td>
<td id="lastFlywayFile" class="property_value">V197__poc_rlock_drop_not_null.sql</td>
<td id="lastFlywayFile" class="property_value">V209__poll_message_hash.sql</td>
</tr>
</tbody>
</table>
@@ -273,7 +273,7 @@ td.section {
<p>&nbsp;</p>
<svg viewBox="0.00 0.00 4903.00 3732.00" xmlns="http://www.w3.org/2000/svg" xmlns:xlink="http://www.w3.org/1999/xlink" id="erDiagram" style="overflow: hidden; width: 100%; height: 800px">
<g id="graph0" class="graph" transform="scale(1 1) rotate(0) translate(4 3728)">
<title>SchemaCrawler_Diagram</title> <polygon fill="white" stroke="transparent" points="-4,4 -4,-3728 4899,-3728 4899,4 -4,4" /> <text text-anchor="start" x="4655" y="-29.8" font-family="Helvetica,sans-Serif" font-size="14.00">generated by</text> <text text-anchor="start" x="4738" y="-29.8" font-family="Helvetica,sans-Serif" font-size="14.00">SchemaCrawler 16.27.1</text> <text text-anchor="start" x="4654" y="-10.8" font-family="Helvetica,sans-Serif" font-size="14.00">generated on</text> <text text-anchor="start" x="4738" y="-10.8" font-family="Helvetica,sans-Serif" font-size="14.00">2025-09-05 16:11:29</text> <polygon fill="none" stroke="#888888" points="4651,-4 4651,-44 4887,-44 4887,-4 4651,-4" /> <!-- allocationtoken_a08ccbef -->
<title>SchemaCrawler_Diagram</title> <polygon fill="white" stroke="transparent" points="-4,4 -4,-3728 4899,-3728 4899,4 -4,4" /> <text text-anchor="start" x="4655" y="-29.8" font-family="Helvetica,sans-Serif" font-size="14.00">generated by</text> <text text-anchor="start" x="4738" y="-29.8" font-family="Helvetica,sans-Serif" font-size="14.00">SchemaCrawler 16.27.1</text> <text text-anchor="start" x="4654" y="-10.8" font-family="Helvetica,sans-Serif" font-size="14.00">generated on</text> <text text-anchor="start" x="4738" y="-10.8" font-family="Helvetica,sans-Serif" font-size="14.00">2025-09-29 21:19:42</text> <polygon fill="none" stroke="#888888" points="4651,-4 4651,-44 4887,-44 4887,-4 4651,-4" /> <!-- allocationtoken_a08ccbef -->
<g id="node1" class="node">
<title>allocationtoken_a08ccbef</title> <polygon fill="#e9c2f2" stroke="transparent" points="481.5,-978 481.5,-997 667.5,-997 667.5,-978 481.5,-978" /> <text text-anchor="start" x="483.5" y="-984.8" font-family="Helvetica,sans-Serif" font-weight="bold" font-style="italic" font-size="14.00">public."AllocationToken"</text> <polygon fill="#e9c2f2" stroke="transparent" points="667.5,-978 667.5,-997 741.5,-997 741.5,-978 667.5,-978" /> <text text-anchor="start" x="702.5" y="-983.8" font-family="Helvetica,sans-Serif" font-size="14.00">[table]</text> <text text-anchor="start" x="483.5" y="-965.8" font-family="Helvetica,sans-Serif" font-weight="bold" font-style="italic" font-size="14.00">token</text> <text text-anchor="start" x="661.5" y="-964.8" font-family="Helvetica,sans-Serif" font-size="14.00"> </text> <text text-anchor="start" x="669.5" y="-964.8" font-family="Helvetica,sans-Serif" font-size="14.00">text not null</text> <text text-anchor="start" x="483.5" y="-945.8" font-family="Helvetica,sans-Serif" font-size="14.00">domain_name</text> <text text-anchor="start" x="661.5" y="-945.8" font-family="Helvetica,sans-Serif" font-size="14.00"> </text> <text text-anchor="start" x="669.5" y="-945.8" font-family="Helvetica,sans-Serif" font-size="14.00">text</text> <text text-anchor="start" x="483.5" y="-926.8" font-family="Helvetica,sans-Serif" font-size="14.00">redemption_domain_repo_id</text> <text text-anchor="start" x="661.5" y="-926.8" font-family="Helvetica,sans-Serif" font-size="14.00"> </text> <text text-anchor="start" x="669.5" y="-926.8" font-family="Helvetica,sans-Serif" font-size="14.00">text</text> <text text-anchor="start" x="483.5" y="-907.8" font-family="Helvetica,sans-Serif" font-size="14.00">token_type</text> <text text-anchor="start" x="661.5" y="-907.8" font-family="Helvetica,sans-Serif" font-size="14.00"> </text> <text text-anchor="start" x="669.5" y="-907.8" font-family="Helvetica,sans-Serif" font-size="14.00">text</text> <polygon fill="none" stroke="#888888" points="480.5,-901.5 480.5,-998.5 742.5,-998.5 742.5,-901.5 480.5,-901.5" />
</g>

File diff suppressed because one or more lines are too long

View File

@@ -195,3 +195,15 @@ V194__password_reset_request_registrar.sql
V195__registrar_poc_id.sql
V196__tld_expiry_access_period_enabled.sql
V197__poc_rlock_drop_not_null.sql
V198__billing_cancellation_hash.sql
V199__billing_event_hash.sql
V200__billing_recurrence_hash.sql
V201__domain_hash.sql
V202__delegation_signer_data_hash.sql
V203__domain_history_hash.sql
V204__domain_host_hash.sql
V205__domain_transaction_record_hash.sql
V206__grace_period_hash.sql
V207__grace_period_history_hash.sql
V208__host_hash.sql
V209__poll_message_hash.sql

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS billingcancellation_billing_cancellation_id_hash ON "BillingCancellation" USING hash (billing_cancellation_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS billingevent_billing_event_id_hash ON "BillingEvent" USING hash (billing_event_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS billingrecurrence_billing_recurrence_id_hash ON "BillingRecurrence" USING hash (billing_recurrence_id);

View File

@@ -0,0 +1,17 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS domain_domain_name_hash ON "Domain" USING hash (domain_name);
CREATE INDEX CONCURRENTLY IF NOT EXISTS domain_domain_repo_id_hash ON "Domain" USING hash (repo_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS delegationsignerdata_domain_repo_id_hash ON "DelegationSignerData" USING hash (domain_repo_id);

View File

@@ -0,0 +1,17 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS domainhistory_domain_repo_id_hash ON "DomainHistory" USING hash (domain_repo_id);
CREATE INDEX CONCURRENTLY IF NOT EXISTS domainhistory_history_revision_id_hash ON "DomainHistory" USING hash (history_revision_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS domainhost_domain_repo_id_hash ON "DomainHost" USING hash (domain_repo_id);

View File

@@ -0,0 +1,17 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS domaintransactionrecord_id_hash ON "DomainTransactionRecord" USING hash (id);
CREATE INDEX CONCURRENTLY IF NOT EXISTS domaintransactionrecord_domain_history_revision_id_hash ON "DomainTransactionRecord" USING hash (history_revision_id);

View File

@@ -0,0 +1,17 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS graceperiod_grace_period_id_hash ON "GracePeriod" USING hash (grace_period_id);
CREATE INDEX CONCURRENTLY IF NOT EXISTS graceperiod_domain_repo_id_hash ON "GracePeriod" USING hash (domain_repo_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS graceperiodhistory_grace_period_history_revision_id_hash ON "GracePeriodHistory" USING hash (grace_period_history_revision_id);

View File

@@ -0,0 +1,17 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS host_host_name_hash ON "Host" USING hash (host_name);
CREATE INDEX CONCURRENTLY IF NOT EXISTS host_repo_id_hash ON "Host" USING hash (repo_id);

View File

@@ -0,0 +1,16 @@
-- Copyright 2025 The Nomulus Authors. All Rights Reserved.
--
-- Licensed under the Apache License, Version 2.0 (the "License");
-- you may not use this file except in compliance with the License.
-- You may obtain a copy of the License at
--
-- http://www.apache.org/licenses/LICENSE-2.0
--
-- Unless required by applicable law or agreed to in writing, software
-- distributed under the License is distributed on an "AS IS" BASIS,
-- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
-- See the License for the specific language governing permissions and
-- limitations under the License.
-- Add hash indexes on columns that are commonly queried with a direct equals
CREATE INDEX CONCURRENTLY IF NOT EXISTS pollmessage_poll_message_id_hash ON "PollMessage" USING hash (poll_message_id);

View File

@@ -1924,6 +1924,48 @@ ALTER TABLE ONLY public."User"
CREATE INDEX allocation_token_domain_name_idx ON public."AllocationToken" USING btree (domain_name);
--
-- Name: billingcancellation_billing_cancellation_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX billingcancellation_billing_cancellation_id_hash ON public."BillingCancellation" USING hash (billing_cancellation_id);
--
-- Name: billingevent_billing_event_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX billingevent_billing_event_id_hash ON public."BillingEvent" USING hash (billing_event_id);
--
-- Name: billingrecurrence_billing_recurrence_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX billingrecurrence_billing_recurrence_id_hash ON public."BillingRecurrence" USING hash (billing_recurrence_id);
--
-- Name: delegationsignerdata_domain_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX delegationsignerdata_domain_repo_id_hash ON public."DelegationSignerData" USING hash (domain_repo_id);
--
-- Name: domain_domain_name_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domain_domain_name_hash ON public."Domain" USING hash (domain_name);
--
-- Name: domain_domain_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domain_domain_repo_id_hash ON public."Domain" USING hash (repo_id);
--
-- Name: domain_history_to_ds_data_history_idx; Type: INDEX; Schema: public; Owner: -
--
@@ -1938,6 +1980,76 @@ CREATE INDEX domain_history_to_ds_data_history_idx ON public."DomainDsDataHistor
CREATE INDEX domain_history_to_transaction_record_idx ON public."DomainTransactionRecord" USING btree (domain_repo_id, history_revision_id);
--
-- Name: domainhistory_domain_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domainhistory_domain_repo_id_hash ON public."DomainHistory" USING hash (domain_repo_id);
--
-- Name: domainhistory_history_revision_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domainhistory_history_revision_id_hash ON public."DomainHistory" USING hash (history_revision_id);
--
-- Name: domainhost_domain_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domainhost_domain_repo_id_hash ON public."DomainHost" USING hash (domain_repo_id);
--
-- Name: domaintransactionrecord_domain_history_revision_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domaintransactionrecord_domain_history_revision_id_hash ON public."DomainTransactionRecord" USING hash (history_revision_id);
--
-- Name: domaintransactionrecord_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX domaintransactionrecord_id_hash ON public."DomainTransactionRecord" USING hash (id);
--
-- Name: graceperiod_domain_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX graceperiod_domain_repo_id_hash ON public."GracePeriod" USING hash (domain_repo_id);
--
-- Name: graceperiod_grace_period_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX graceperiod_grace_period_id_hash ON public."GracePeriod" USING hash (grace_period_id);
--
-- Name: graceperiodhistory_grace_period_history_revision_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX graceperiodhistory_grace_period_history_revision_id_hash ON public."GracePeriodHistory" USING hash (grace_period_history_revision_id);
--
-- Name: host_host_name_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX host_host_name_hash ON public."Host" USING hash (host_name);
--
-- Name: host_repo_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX host_repo_id_hash ON public."Host" USING hash (repo_id);
--
-- Name: idx1dyqmqb61xbnj7mt7bk27ds25; Type: INDEX; Schema: public; Owner: -
--
@@ -2617,6 +2729,13 @@ CREATE INDEX idxtmlqd31dpvvd2g1h9i7erw6aj ON public."AllocationToken" USING btre
CREATE INDEX idxy98mebut8ix1v07fjxxdkqcx ON public."Host" USING btree (creation_time);
--
-- Name: pollmessage_poll_message_id_hash; Type: INDEX; Schema: public; Owner: -
--
CREATE INDEX pollmessage_poll_message_id_hash ON public."PollMessage" USING hash (poll_message_id);
--
-- Name: premiumlist_name_idx; Type: INDEX; Schema: public; Owner: -
--