diff --git a/db/build.gradle b/db/build.gradle index c7e9f9ea4..0a90411da 100644 --- a/db/build.gradle +++ b/db/build.gradle @@ -87,10 +87,20 @@ flyway { } dependencies { - runtimeOnly 'org.flywaydb:flyway-core:5.2.4' + def deps = rootProject.dependencyMap - runtimeOnly 'com.google.cloud.sql:postgres-socket-factory:1.0.12' - runtimeOnly 'org.postgresql:postgresql:42.2.5' + compile deps['org.flywaydb:flyway-core'] + + runtimeOnly deps['com.google.cloud.sql:postgres-socket-factory'] + runtimeOnly deps['org.postgresql:postgresql'] + + testCompile deps['com.google.flogger:flogger'] + testRuntime deps['com.google.flogger:flogger-system-backend'] + testCompile deps['com.google.truth:truth'] + testCompile deps['io.github.java-diff-utils:java-diff-utils'] + testCompile deps['org.testcontainers:postgresql'] + testCompile deps['junit:junit'] + testCompile project(':third_party') } // Ensure that resources are rebuilt before running Flyway tasks diff --git a/db/src/main/resources/sql/flyway/V1__new_claims_list_and_entry.sql b/db/src/main/resources/sql/flyway/V1__create_claims_list_and_entry.sql similarity index 96% rename from db/src/main/resources/sql/flyway/V1__new_claims_list_and_entry.sql rename to db/src/main/resources/sql/flyway/V1__create_claims_list_and_entry.sql index 87c69723f..f4132bbdf 100644 --- a/db/src/main/resources/sql/flyway/V1__new_claims_list_and_entry.sql +++ b/db/src/main/resources/sql/flyway/V1__create_claims_list_and_entry.sql @@ -25,7 +25,7 @@ primary key (revision_id) ); - alter table "ClaimsEntry" + alter table if exists "ClaimsEntry" add constraint FKlugn0q07ayrtar87dqi3vs3c8 foreign key (revision_id) references "ClaimsList"; diff --git a/db/src/main/resources/sql/schema/claims_list.sql b/db/src/main/resources/sql/flyway/V2__create_premium_list_and_entry.sql similarity index 52% rename from db/src/main/resources/sql/schema/claims_list.sql rename to db/src/main/resources/sql/flyway/V2__create_premium_list_and_entry.sql index 85e3504ee..e911d7201 100644 --- a/db/src/main/resources/sql/schema/claims_list.sql +++ b/db/src/main/resources/sql/flyway/V2__create_premium_list_and_entry.sql @@ -12,16 +12,21 @@ -- See the License for the specific language governing permissions and -- limitations under the License. -CREATE TABLE `ClaimsList` ( - revision_id BIGSERIAL NOT NULL, - creation_timestamp TIMESTAMPTZ NOT NULL, - PRIMARY KEY (revision_id) -); + create table "PremiumEntry" ( + revision_id int8 not null, + price numeric(19, 2) not null, + domain_label text not null, + primary key (revision_id, domain_label) + ); -CREATE TABLE `ClaimsEntry` ( - revision_id int8 NOT NULL, - claim_key TEXT NOT NULL, - domain_label TEXT NOT NULL, - PRIMARY KEY (revision_id, domain_label), - FOREIGN KEY (revision_id) REFERENCES `ClaimsList`(revision_id) -); + create table "PremiumList" ( + revision_id bigserial not null, + creation_timestamp timestamptz not null, + currency bytea not null, + primary key (revision_id) + ); + + alter table if exists "PremiumEntry" + add constraint FKqebdja3jkx9c9cnqnrw9g9ocu + foreign key (revision_id) + references "PremiumList"; diff --git a/db/src/main/resources/sql/schema/nomulus.golden.sql b/db/src/main/resources/sql/schema/nomulus.golden.sql index 5ec31dd06..6a3fcff30 100644 --- a/db/src/main/resources/sql/schema/nomulus.golden.sql +++ b/db/src/main/resources/sql/schema/nomulus.golden.sql @@ -1,18 +1,182 @@ +-- +-- PostgreSQL database dump +-- - create table "ClaimsEntry" ( - revision_id int8 not null, - claim_key text not null, - domain_label text not null, - primary key (revision_id, domain_label) - ); +-- Dumped from database version 9.6.12 +-- Dumped by pg_dump version 9.6.12 - create table "ClaimsList" ( - revision_id bigserial not null, - creation_timestamp timestamptz not null, - primary key (revision_id) - ); +SET statement_timeout = 0; +SET lock_timeout = 0; +SET idle_in_transaction_session_timeout = 0; +SET client_encoding = 'UTF8'; +SET standard_conforming_strings = on; +SELECT pg_catalog.set_config('search_path', '', false); +SET check_function_bodies = false; +SET client_min_messages = warning; +SET row_security = off; + +-- +-- Name: plpgsql; Type: EXTENSION; Schema: -; Owner: - +-- + +CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog; + + +-- +-- Name: EXTENSION plpgsql; Type: COMMENT; Schema: -; Owner: - +-- + +COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language'; + + +SET default_tablespace = ''; + +SET default_with_oids = false; + +-- +-- Name: ClaimsEntry; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public."ClaimsEntry" ( + revision_id bigint NOT NULL, + claim_key text NOT NULL, + domain_label text NOT NULL +); + + +-- +-- Name: ClaimsList; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public."ClaimsList" ( + revision_id bigint NOT NULL, + creation_timestamp timestamp with time zone NOT NULL +); + + +-- +-- Name: ClaimsList_revision_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + +CREATE SEQUENCE public."ClaimsList_revision_id_seq" + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +-- +-- Name: ClaimsList_revision_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - +-- + +ALTER SEQUENCE public."ClaimsList_revision_id_seq" OWNED BY public."ClaimsList".revision_id; + + +-- +-- Name: PremiumEntry; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public."PremiumEntry" ( + revision_id bigint NOT NULL, + price numeric(19,2) NOT NULL, + domain_label text NOT NULL +); + + +-- +-- Name: PremiumList; Type: TABLE; Schema: public; Owner: - +-- + +CREATE TABLE public."PremiumList" ( + revision_id bigint NOT NULL, + creation_timestamp timestamp with time zone NOT NULL, + currency bytea NOT NULL +); + + +-- +-- Name: PremiumList_revision_id_seq; Type: SEQUENCE; Schema: public; Owner: - +-- + +CREATE SEQUENCE public."PremiumList_revision_id_seq" + START WITH 1 + INCREMENT BY 1 + NO MINVALUE + NO MAXVALUE + CACHE 1; + + +-- +-- Name: PremiumList_revision_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: - +-- + +ALTER SEQUENCE public."PremiumList_revision_id_seq" OWNED BY public."PremiumList".revision_id; + + +-- +-- Name: ClaimsList revision_id; Type: DEFAULT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."ClaimsList" ALTER COLUMN revision_id SET DEFAULT nextval('public."ClaimsList_revision_id_seq"'::regclass); + + +-- +-- Name: PremiumList revision_id; Type: DEFAULT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."PremiumList" ALTER COLUMN revision_id SET DEFAULT nextval('public."PremiumList_revision_id_seq"'::regclass); + + +-- +-- Name: ClaimsEntry ClaimsEntry_pkey; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."ClaimsEntry" + ADD CONSTRAINT "ClaimsEntry_pkey" PRIMARY KEY (revision_id, domain_label); + + +-- +-- Name: ClaimsList ClaimsList_pkey; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."ClaimsList" + ADD CONSTRAINT "ClaimsList_pkey" PRIMARY KEY (revision_id); + + +-- +-- Name: PremiumEntry PremiumEntry_pkey; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."PremiumEntry" + ADD CONSTRAINT "PremiumEntry_pkey" PRIMARY KEY (revision_id, domain_label); + + +-- +-- Name: PremiumList PremiumList_pkey; Type: CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."PremiumList" + ADD CONSTRAINT "PremiumList_pkey" PRIMARY KEY (revision_id); + + +-- +-- Name: ClaimsEntry fklugn0q07ayrtar87dqi3vs3c8; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."ClaimsEntry" + ADD CONSTRAINT fklugn0q07ayrtar87dqi3vs3c8 FOREIGN KEY (revision_id) REFERENCES public."ClaimsList"(revision_id); + + +-- +-- Name: PremiumEntry fkqebdja3jkx9c9cnqnrw9g9ocu; Type: FK CONSTRAINT; Schema: public; Owner: - +-- + +ALTER TABLE ONLY public."PremiumEntry" + ADD CONSTRAINT fkqebdja3jkx9c9cnqnrw9g9ocu FOREIGN KEY (revision_id) REFERENCES public."PremiumList"(revision_id); + + +-- +-- PostgreSQL database dump complete +-- - alter table "ClaimsEntry" - add constraint FKlugn0q07ayrtar87dqi3vs3c8 - foreign key (revision_id) - references "ClaimsList"; diff --git a/db/src/main/resources/sql/schema/premium_list.sql b/db/src/main/resources/sql/schema/premium_list.sql deleted file mode 100644 index 2cc1b7862..000000000 --- a/db/src/main/resources/sql/schema/premium_list.sql +++ /dev/null @@ -1,28 +0,0 @@ --- 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 "PremiumList" ( - revision_id BIGSERIAL NOT NULL, - creation_timestamp TIMESTAMPTZ NOT NULL, - currency TEXT NOT NULL, - PRIMARY KEY (revision_id) -); - -CREATE TABLE "PremiumEntry" ( - revision_id BIGSERIAL NOT NULL, - price NUMERIC(12, 2) NOT NULL, - domain_label TEXT NOT NULL, - primary key (revision_id, domain_label), - FOREIGN KEY (revision_id) REFERENCES "PremiumList"(revision_id) -); diff --git a/db/src/test/java/google/registry/sql/flyway/SchemaTest.java b/db/src/test/java/google/registry/sql/flyway/SchemaTest.java new file mode 100644 index 000000000..c0c4bd08b --- /dev/null +++ b/db/src/test/java/google/registry/sql/flyway/SchemaTest.java @@ -0,0 +1,108 @@ +// 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. + +package google.registry.sql.flyway; + +import static com.google.common.truth.Truth.assertThat; +import static google.registry.testing.TextDiffSubject.assertThat; + +import com.google.common.base.Joiner; +import com.google.common.io.Resources; +import java.io.File; +import java.net.URL; +import java.nio.charset.StandardCharsets; +import java.nio.file.Paths; +import org.flywaydb.core.Flyway; +import org.junit.Rule; +import org.junit.Test; +import org.junit.runner.RunWith; +import org.junit.runners.JUnit4; +import org.testcontainers.containers.BindMode; +import org.testcontainers.containers.Container; +import org.testcontainers.containers.PostgreSQLContainer; + +/** Unit tests about Cloud SQL schema. */ +@RunWith(JUnit4.class) +public class SchemaTest { + + // Resource path that is mapped to the testcontainer instance. + private static final String MOUNTED_RESOURCE_PATH = "testcontainer/mount"; + // The mount point in the container. + private static final String CONTAINER_MOUNT_POINT = "/tmp/pg_dump_out"; + // pg_dump output file name. + private static final String DUMP_OUTPUT_FILE = "dump.txt"; + + /** + * The target database for schema deployment. + * + *
A resource path is mapped to this container in READ_WRITE mode to retrieve the deployed + * schema generated by the 'pg_dump' command. We do not communicate over stdout because + * testcontainer adds spurious newlines. See this link for more + * information. + */ + @Rule + public PostgreSQLContainer sqlContainer = + new PostgreSQLContainer<>("postgres:9.6.12") + .withClasspathResourceMapping( + MOUNTED_RESOURCE_PATH, CONTAINER_MOUNT_POINT, BindMode.READ_WRITE); + + @Test + public void deploySchema_success() throws Exception { + Flyway flyway = + Flyway.configure() + .locations("sql/flyway") + .dataSource( + sqlContainer.getJdbcUrl(), sqlContainer.getUsername(), sqlContainer.getPassword()) + .load(); + + // flyway.migrate() returns the number of newly pushed scripts. This is a variable + // number as our schema evolves. + assertThat(flyway.migrate()).isGreaterThan(0); + flyway.validate(); + + Container.ExecResult execResult = + sqlContainer.execInContainer( + StandardCharsets.UTF_8, + getSchemaDumpCommand(sqlContainer.getUsername(), sqlContainer.getDatabaseName())); + if (execResult.getExitCode() != 0) { + throw new RuntimeException(execResult.toString()); + } + + URL dumpedSchema = + Resources.getResource( + Joiner.on(File.separatorChar).join(MOUNTED_RESOURCE_PATH, DUMP_OUTPUT_FILE)); + + assertThat(dumpedSchema) + .hasSameContentAs(Resources.getResource("sql/schema/nomulus.golden.sql")); + } + + private static String[] getSchemaDumpCommand(String username, String dbName) { + return new String[] { + "pg_dump", + "-h", + "localhost", + "-U", + username, + "-f", + Paths.get(CONTAINER_MOUNT_POINT, DUMP_OUTPUT_FILE).toString(), + "--schema-only", + "--no-owner", + "--no-privileges", + "--exclude-table", + "flyway_schema_history", + dbName + }; + } +} diff --git a/db/src/test/java/google/registry/testing/TextDiffSubject.java b/db/src/test/java/google/registry/testing/TextDiffSubject.java new file mode 100644 index 000000000..8d90b79b2 --- /dev/null +++ b/db/src/test/java/google/registry/testing/TextDiffSubject.java @@ -0,0 +1,201 @@ +// 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. + +package google.registry.testing; + +import static com.google.common.base.Preconditions.checkNotNull; +import static com.google.common.truth.Truth.assertAbout; +import static java.nio.charset.StandardCharsets.UTF_8; + +import com.github.difflib.DiffUtils; +import com.github.difflib.UnifiedDiffUtils; +import com.github.difflib.algorithm.DiffException; +import com.github.difflib.patch.Patch; +import com.github.difflib.text.DiffRow; +import com.github.difflib.text.DiffRowGenerator; +import com.google.common.base.Ascii; +import com.google.common.base.Joiner; +import com.google.common.base.Strings; +import com.google.common.collect.ImmutableList; +import com.google.common.io.Resources; +import com.google.common.truth.Fact; +import com.google.common.truth.FailureMetadata; +import com.google.common.truth.Subject; +import java.io.IOException; +import java.net.URL; +import java.util.Collection; +import java.util.Comparator; +import java.util.List; +import java.util.stream.Collectors; + +/** + * Compares two multi-line text blocks, and displays their diffs in readable formats. + * + *
User may choose one of the following diff formats: + * + *
Note that if one text block has one trailing newline at the end while another has none, this
+ * difference will not be shown in the generated diffs. This is the case where two texts may be
+ * reported as unequal but the diffs appear equal. Fixing this requires special treatment of the
+ * last line of text. The fix would not be useful in our environment, where all important files are
+ * covered by a style checker that ensures the presence of a trailing newline.
+ */
+// TODO(weiminyu): move this class and test to a standalone 'testing' project. Note that the util
+// project is not good since it depends back to core.
+@SuppressWarnings("unchecked") // On behalf of Raw type Subject; remove after Truth 1.0 upgrade.
+public class TextDiffSubject extends Subject {
+
+ private final ImmutableList