Skip to content

Commit

Permalink
Add RegistryLock schema to Flyway deployment folder (#270)
Browse files Browse the repository at this point in the history
* Add RegistryLock schema to Flyway deployment folder

Added creation script of RegistryLock to Flyway deployment folder.

Fixed previous scripts (PremiumList- and ClaimsList-related) for
FK name change (cause by table name changes: names are quoted now).
We should consider generating foreign key names by ourselves.

Since the alpha database is empty, we dropped and recreated the schema.

Added instructions on how to submit new database incremental changes
in the README file.

Updated RegistryLock.java, removing unnecessary annotations:
- For most fields, the 'name=' property is no longer necessary not that
  the naming strategy is in place. The exceptions are the two used in
  the unique index.
- The @column annotation is implicit.
  • Loading branch information
weiminyu committed Sep 16, 2019
1 parent 668ed7c commit 1db5fba
Show file tree
Hide file tree
Showing 6 changed files with 147 additions and 27 deletions.
23 changes: 13 additions & 10 deletions core/src/main/java/google/registry/schema/domain/RegistryLock.java
Original file line number Diff line number Diff line change
Expand Up @@ -50,8 +50,13 @@
*/
@Entity
@Table(
// Unique constraint to get around Hibernate's failure to handle
// auto-increment field in composite primary key.
/**
* Unique constraint to get around Hibernate's failure to handle auto-increment field in
* composite primary key.
*
* <p>Note: because of this index, physical columns must be declared in the {@link Column}
* annotations for {@link RegistryLock#revisionId} and {@link RegistryLock#repoId} fields.
*/
indexes =
@Index(
name = "idx_registry_lock_repo_id_revision_id",
Expand All @@ -75,51 +80,49 @@ public enum Action {
private String repoId;

// TODO (b/140568328): remove this when everything is in Cloud SQL and we can join on "domain"
@Column(name = "domain_name", nullable = false)
@Column(nullable = false)
private String domainName;

/**
* The ID of the registrar that performed the action -- this may be the admin ID if this action
* was performed by a superuser.
*/
@Column(name = "registrar_id", nullable = false)
@Column(nullable = false)
private String registrarId;

/** The POC that performed the action, or null if it was a superuser. */
@Column(name = "registrar_poc_id")
private String registrarPocId;

/**
* Lock action is immutable and describes whether the action performed was a lock or an unlock.
*/
@Enumerated(EnumType.STRING)
@Column(name = "action", nullable = false)
@Column(nullable = false)
private Action action;

/** Creation timestamp is when the lock/unlock is first requested. */
@Column(name = "creation_timestamp", nullable = false)
@Column(nullable = false)
private ZonedDateTime creationTimestamp;

/**
* Completion timestamp is when the user has verified the lock/unlock, when this object de facto
* becomes immutable. If this field is null, it means that the lock has not been verified yet (and
* thus not been put into effect).
*/
@Column(name = "completion_timestamp")
private ZonedDateTime completionTimestamp;

/**
* The user must provide the random verification code in order to complete the lock and move the
* status from PENDING to COMPLETED.
*/
@Column(name = "verification_code", nullable = false)
@Column(nullable = false)
private String verificationCode;

/**
* True iff this action was taken by a superuser, in response to something like a URS request. In
* this case, the action was performed by a registry admin rather than a registrar.
*/
@Column(name = "is_superuser", nullable = false)
@Column(nullable = false)
private boolean isSuperuser;

public String getRepoId() {
Expand Down
49 changes: 38 additions & 11 deletions db/README.md
Original file line number Diff line number Diff line change
@@ -1,21 +1,48 @@
## Summary

This project contains Nomulus's Cloud SQL schema and schema deployment utilities.
This project contains Nomulus's Cloud SQL schema and schema-deployment
utilities.

### Schema Creation DDL
### Schema DDL Scripts

Currently we use Flywaydb for schema deployment. Versioned migration scripts
are organized in the src/main/resources/sql/flyway folder. Scripts must follow
the V{id}__{description text}.sql naming pattern (Note the double underscore).
Currently we use Flyway for schema deployment. Versioned incremental update
scripts are organized in the src/main/resources/sql/flyway folder. A Flyway
'migration' task examines the target database instance, and makes sure that only
changes not yet deployed are pushed.

The 'nomulus.golden.sql' file in src/main/resources/sql/schema folder is
mainly informational. It is generated by Hibernate and should not be
reformatted. We will use it in validation tests later.
Below are the steps to submit a schema change:

* Define the incremental DDL script that would update the existing schema to
the new one.
* Add the script to the src/main/resource/flyway folder. Its name should
follow the V{id}__{description text}.sql, where {id} is a number that is
higher than all existing scripts in that folder. Also note that it is a
**double** underscore in the naming pattern.
* Run :db:tests from the Gradle root project. The SchemaTest will fail because
the new schema does not match the gold file.
* Copy db/build/resources/test/testcontainer/mount/dump.txt to the golden file
(db/src/main/resources/sql/schema/nomulus.golden.sql). Diff it against the
old version and verify that all changes are expected.
* Retrun :db:tests. This time all tests should pass.

Relevant files (under db/src/main/resources/sql/schema/):

* nomulus.golden.sql is the schema dump (pg_dump for postgres) of the final
schema pushed by Flyway. This is mostly for informational, although it may
be used in tests.
* db-schema.sql.generated is the schema generated from ORM classes by the
GenerateSqlSchema command in Nomulus tool. This reflects the ORM-layer's
view of the schema.

The generated schema and the golden one may diverge during schema changes. For
example, when adding a new column to a table, we would deploy the change before
adding it to the relevant ORM class. Therefore, for a short time the golden file
will contain the new column while the generated one does not.

### Non-production Schema Push

To manage schema in a non-production environment, use the 'flywayMigration' task.
You will need Cloud SDK and login once.
To manage schema in a non-production environment, use the 'flywayMigration'
task. You will need Cloud SDK and login once.

```shell
# One time login
Expand Down Expand Up @@ -44,4 +71,4 @@ gradlew :db:flywayMigrate -PdbServer=192.168.9.2:5432 -PdbUser=postgres \

### Production Schema Deployment

Schema deployment to production and sandbox is under development.
Schema deployment to production and sandbox is under development.
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,6 @@
);

alter table if exists "ClaimsEntry"
add constraint FKlugn0q07ayrtar87dqi3vs3c8
add constraint FK6sc6at5hedffc0nhdcab6ivuq
foreign key (revision_id)
references "ClaimsList";
Original file line number Diff line number Diff line change
Expand Up @@ -27,6 +27,6 @@
);

alter table if exists "PremiumEntry"
add constraint FKqebdja3jkx9c9cnqnrw9g9ocu
add constraint FKo0gw90lpo1tuee56l0nb6y6g5
foreign key (revision_id)
references "PremiumList";
30 changes: 30 additions & 0 deletions db/src/main/resources/sql/flyway/V3__create_registry_lock.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
-- Copyright 2019 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.

create table "RegistryLock" (
revision_id bigserial not null,
action text not null,
completion_timestamp timestamptz,
creation_timestamp timestamptz not null,
domain_name text not null,
is_superuser boolean not null,
registrar_id text not null,
registrar_poc_id text,
repo_id text not null,
verification_code text not null,
primary key (revision_id)
);

alter table if exists "RegistryLock"
add constraint idx_registry_lock_repo_id_revision_id unique (repo_id, revision_id);
68 changes: 64 additions & 4 deletions db/src/main/resources/sql/schema/nomulus.golden.sql
Original file line number Diff line number Diff line change
Expand Up @@ -114,6 +114,43 @@ CREATE SEQUENCE public."PremiumList_revision_id_seq"
ALTER SEQUENCE public."PremiumList_revision_id_seq" OWNED BY public."PremiumList".revision_id;


--
-- Name: RegistryLock; Type: TABLE; Schema: public; Owner: -
--

CREATE TABLE public."RegistryLock" (
revision_id bigint NOT NULL,
action text NOT NULL,
completion_timestamp timestamp with time zone,
creation_timestamp timestamp with time zone NOT NULL,
domain_name text NOT NULL,
is_superuser boolean NOT NULL,
registrar_id text NOT NULL,
registrar_poc_id text,
repo_id text NOT NULL,
verification_code text NOT NULL
);


--
-- Name: RegistryLock_revision_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--

CREATE SEQUENCE public."RegistryLock_revision_id_seq"
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;


--
-- Name: RegistryLock_revision_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--

ALTER SEQUENCE public."RegistryLock_revision_id_seq" OWNED BY public."RegistryLock".revision_id;


--
-- Name: ClaimsList revision_id; Type: DEFAULT; Schema: public; Owner: -
--
Expand All @@ -128,6 +165,13 @@ ALTER TABLE ONLY public."ClaimsList" ALTER COLUMN revision_id SET DEFAULT nextva
ALTER TABLE ONLY public."PremiumList" ALTER COLUMN revision_id SET DEFAULT nextval('public."PremiumList_revision_id_seq"'::regclass);


--
-- Name: RegistryLock revision_id; Type: DEFAULT; Schema: public; Owner: -
--

ALTER TABLE ONLY public."RegistryLock" ALTER COLUMN revision_id SET DEFAULT nextval('public."RegistryLock_revision_id_seq"'::regclass);


--
-- Name: ClaimsEntry ClaimsEntry_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--
Expand Down Expand Up @@ -161,19 +205,35 @@ ALTER TABLE ONLY public."PremiumList"


--
-- Name: ClaimsEntry fklugn0q07ayrtar87dqi3vs3c8; Type: FK CONSTRAINT; Schema: public; Owner: -
-- Name: RegistryLock RegistryLock_pkey; Type: CONSTRAINT; Schema: public; Owner: -
--

ALTER TABLE ONLY public."RegistryLock"
ADD CONSTRAINT "RegistryLock_pkey" PRIMARY KEY (revision_id);


--
-- Name: RegistryLock idx_registry_lock_repo_id_revision_id; Type: CONSTRAINT; Schema: public; Owner: -
--

ALTER TABLE ONLY public."RegistryLock"
ADD CONSTRAINT idx_registry_lock_repo_id_revision_id UNIQUE (repo_id, revision_id);


--
-- Name: ClaimsEntry fk6sc6at5hedffc0nhdcab6ivuq; Type: FK CONSTRAINT; Schema: public; Owner: -
--

ALTER TABLE ONLY public."ClaimsEntry"
ADD CONSTRAINT fklugn0q07ayrtar87dqi3vs3c8 FOREIGN KEY (revision_id) REFERENCES public."ClaimsList"(revision_id);
ADD CONSTRAINT fk6sc6at5hedffc0nhdcab6ivuq FOREIGN KEY (revision_id) REFERENCES public."ClaimsList"(revision_id);


--
-- Name: PremiumEntry fkqebdja3jkx9c9cnqnrw9g9ocu; Type: FK CONSTRAINT; Schema: public; Owner: -
-- Name: PremiumEntry fko0gw90lpo1tuee56l0nb6y6g5; Type: FK CONSTRAINT; Schema: public; Owner: -
--

ALTER TABLE ONLY public."PremiumEntry"
ADD CONSTRAINT fkqebdja3jkx9c9cnqnrw9g9ocu FOREIGN KEY (revision_id) REFERENCES public."PremiumList"(revision_id);
ADD CONSTRAINT fko0gw90lpo1tuee56l0nb6y6g5 FOREIGN KEY (revision_id) REFERENCES public."PremiumList"(revision_id);


--
Expand Down

0 comments on commit 1db5fba

Please sign in to comment.