Skip to content

Commit

Permalink
added ResourceKey unique index
Browse files Browse the repository at this point in the history
  • Loading branch information
Valdis Iljuconoks committed Aug 7, 2024
1 parent 787fafc commit 50ab0e4
Show file tree
Hide file tree
Showing 2 changed files with 166 additions and 135 deletions.
62 changes: 32 additions & 30 deletions src/DbLocalizationProvider.Storage.PostgreSQL/SchemaUpdater.cs
Original file line number Diff line number Diff line change
Expand Up @@ -24,65 +24,67 @@ public void Execute(UpdateSchema.Command command)

private void EnsureDatabaseSchema()
{
using (var conn = new NpgsqlConnection(Settings.DbContextConnectionString))
{
conn.Open();
using var conn = new NpgsqlConnection(Settings.DbContextConnectionString);
conn.Open();

var cmd = new NpgsqlCommand(
"SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'public' AND TABLE_NAME = 'LocalizationResources'")
{
Connection = conn
};
var cmd = new NpgsqlCommand(
"SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'public' AND TABLE_NAME = 'LocalizationResources'")
{
Connection = conn
};

var reader = cmd.ExecuteReader();
var existsTables = reader.HasRows;
reader.Close();
var reader = cmd.ExecuteReader();
var existsTables = reader.HasRows;
reader.Close();

if (existsTables)
{
return;
}
if (existsTables)
{
return;
}

// there is no tables, let's create
cmd.CommandText = @"CREATE TABLE public.""LocalizationResources""
// there is no tables, let's create
cmd.CommandText = @"CREATE TABLE public.""LocalizationResources""
(
""Id"" bigint NOT NULL GENERATED ALWAYS AS IDENTITY ( INCREMENT 1 START 1 MINVALUE 1 MAXVALUE 9223372036854775807 CACHE 1 ),
""Author"" character varying(100) COLLATE pg_catalog.""default"" NOT NULL,
""FromCode"" boolean NOT NULL,
""IsHidden"" boolean NOT NULL,
""IsModified"" boolean NOT NULL,
""ModificationDate"" timestamp without time zone NOT NULL,
""ResourceKey"" character varying(1000) NOT NULL,
""ResourceKey"" character varying(800) NOT NULL,
""Notes"" character varying(3000) NULL,
CONSTRAINT ""PK_LocalizationResources"" PRIMARY KEY (""Id""))
";
cmd.ExecuteNonQuery();
cmd.ExecuteNonQuery();

cmd.CommandText = @"CREATE TABLE public.""LocalizationResourceTranslations""
cmd.CommandText = @"CREATE TABLE public.""LocalizationResourceTranslations""
(
""Id"" bigint NOT NULL GENERATED ALWAYS AS IDENTITY ( INCREMENT 1 START 1 MINVALUE 1 MAXVALUE 9223372036854775807 CACHE 1 ),
""Language"" character varying(10) NOT NULL,
""ResourceId"" bigint NOT NULL,
""Value"" character varying NULL,
""ModificationDate"" timestamp without time zone NOT NULL,
CONSTRAINT ""PK_LocalizationResourceTranslations"" PRIMARY KEY (""Id""))";
cmd.ExecuteNonQuery();
cmd.ExecuteNonQuery();

cmd.CommandText = @"ALTER TABLE public.""LocalizationResourceTranslations""
cmd.CommandText = @"ALTER TABLE public.""LocalizationResourceTranslations""
ADD CONSTRAINT ""FK_LocalizationResourceTranslations_LocalizationResources_ResourceId"" FOREIGN KEY (""ResourceId"")
REFERENCES public.""LocalizationResources"" (""Id"") MATCH SIMPLE
ON UPDATE NO ACTION
ON DELETE CASCADE
NOT VALID";
cmd.ExecuteNonQuery();
cmd.ExecuteNonQuery();

cmd.CommandText =
@"CREATE INDEX ""ix_FK_LocalizationResourceTranslations_LocalizationResources_ResourceId"" ON public.""LocalizationResourceTranslations""(""ResourceId"")";
cmd.ExecuteNonQuery();
cmd.CommandText =
@"CREATE INDEX ""ix_FK_LocalizationResourceTranslations_LocalizationResources_ResourceId"" ON public.""LocalizationResourceTranslations""(""ResourceId"")";
cmd.ExecuteNonQuery();

cmd.CommandText =
@"CREATE UNIQUE INDEX ""ix_UniqueTranslationForLanguage"" ON public.""LocalizationResourceTranslations"" USING btree (""Language"" ASC NULLS LAST, ""ResourceId"" ASC NULLS LAST)";
cmd.ExecuteNonQuery();
}
cmd.CommandText =
@"CREATE UNIQUE INDEX ""ix_UniqueResourceKey"" ON public.""LocalizationResources"" USING btree (""ResourceKey"" ASC NULLS LAST)";
cmd.ExecuteNonQuery();

cmd.CommandText =
@"CREATE UNIQUE INDEX ""ix_UniqueTranslationForLanguage"" ON public.""LocalizationResourceTranslations"" USING btree (""Language"" ASC NULLS LAST, ""ResourceId"" ASC NULLS LAST)";
cmd.ExecuteNonQuery();
}
}
239 changes: 134 additions & 105 deletions src/DbLocalizationProvider.Storage.SqlServer/SchemaUpdater.cs
Original file line number Diff line number Diff line change
@@ -1,7 +1,6 @@
// Copyright (c) Valdis Iljuconoks. All rights reserved.
// Licensed under Apache-2.0. See the LICENSE file in the project root for more information

using System;
using DbLocalizationProvider.Abstractions;
using DbLocalizationProvider.Sync;
using Microsoft.Data.SqlClient;
Expand Down Expand Up @@ -31,24 +30,127 @@ public void Execute(UpdateSchema.Command command)

private void EnsureDatabaseSchema()
{
using (var conn = new SqlConnection(Settings.DbContextConnectionString))
using var conn = new SqlConnection(Settings.DbContextConnectionString);
conn.Open();

var cmd = new SqlCommand(
"SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'dbo' AND TABLE_NAME = 'LocalizationResources'")
{
Connection = conn
};

var reader = cmd.ExecuteReader();
var doesNotExistsTables = !reader.HasRows;
reader.Close();

if (doesNotExistsTables)
{
CreateSchema(cmd);
}
else
{
SyncSchema(cmd);
}
}

private void SyncSchema(SqlCommand cmd)
{
// there is something - so we need to check version and append missing stuff
// NOTE: for now assumption is that we start from previous 5.x version

// Below is list of additions on top of 5.x in chronological order.

// *** #1 addition - add LocalizationResources.Notes
cmd.CommandText = "SELECT COL_LENGTH('dbo.LocalizationResources', 'Notes')";
var result = cmd.ExecuteScalar();

if (result == DBNull.Value)
{
cmd.CommandText = "ALTER TABLE dbo.LocalizationResources ADD Notes NVARCHAR(3000) NULL";
cmd.ExecuteNonQuery();
}

// *** #2 change - LocalizationResources.Author NOT NULL
if (IsColumnNullable("LocalizationResources", "Author", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "Author", "[NVARCHAR](100)", "'migration'", cmd);
}

// *** #3 change - LocalizationResources.IsHidden NOT NULL
if (IsColumnNullable("LocalizationResources", "IsHidden", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "IsHidden", "bit", "0", cmd);
}

// *** #4 change - LocalizationResources.IsModified NOT NULL
if (IsColumnNullable("LocalizationResources", "IsModified", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "IsModified", "bit", "0", cmd);
}

// *** #5 change - LocalizationResourceTranslations.Language NOT NULL
if (IsColumnNullable("LocalizationResourceTranslations", "Language", cmd))
{
ConvertColumnNotNullable("LocalizationResourceTranslations", "Language", "[NVARCHAR](10)", "''", cmd);
}

// *** #6 change - LocalizationResourceTranslations.ResourceId + Language = UNIQUE
cmd.CommandText =
"SELECT index_id FROM sys.indexes WHERE name='ix_UniqueTranslationForLanguage' AND object_id = OBJECT_ID('dbo.LocalizationResourceTranslations')";
result = cmd.ExecuteScalar();

if (result == null)
{
cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueTranslationForLanguage] ON [dbo].[LocalizationResourceTranslations] ([Language], [ResourceId])";
cmd.ExecuteNonQuery();
}

// *** #7 change - add LocalizationResourceTranslations.ModificationDate
cmd.CommandText = "SELECT COL_LENGTH('dbo.LocalizationResourceTranslations', 'ModificationDate')";
result = cmd.ExecuteScalar();

if (result == DBNull.Value)
{
cmd.CommandText =
"ALTER TABLE dbo.LocalizationResourceTranslations ADD ModificationDate [DATETIME2](7) NULL";
cmd.ExecuteNonQuery();

cmd.CommandText =
"UPDATE t SET t.ModificationDate = r.ModificationDate FROM dbo.LocalizationResourceTranslations t INNER JOIN LocalizationResources r ON r.Id = t.ResourceId";
cmd.ExecuteNonQuery();

cmd.CommandText =
"UPDATE dbo.LocalizationResourceTranslations SET ModificationDate = GETUTCDATE() WHERE ModificationDate IS NULL";
cmd.ExecuteNonQuery();

cmd.CommandText =
"ALTER TABLE dbo.LocalizationResourceTranslations ALTER COLUMN ModificationDate [DATETIME2](7) NOT NULL";
cmd.ExecuteNonQuery();
}

// *** #8 change - decrease length of ResourceKey column
cmd.CommandText =
"ALTER TABLE [dbo].[LocalizationResources] ALTER COLUMN ResourceKey NVARCHAR(800) NOT NULL";
cmd.ExecuteScalar();

// *** #9 change - index LocalizationResources.ResourceKey = UNIQUE
cmd.CommandText =
"SELECT index_id FROM sys.indexes WHERE name='ix_UniqueResourceKey' AND object_id = OBJECT_ID('dbo.LocalizationResources')";
result = cmd.ExecuteScalar();

if (result == null)
{
conn.Open();

var cmd = new SqlCommand(
"SELECT * FROM INFORMATION_SCHEMA.TABLES WHERE TABLE_SCHEMA = 'dbo' AND TABLE_NAME = 'LocalizationResources'")
{
Connection = conn
};

var reader = cmd.ExecuteReader();
var doesNotExistsTables = !reader.HasRows;
reader.Close();

if (doesNotExistsTables)
{
// there is no tables, let's create
cmd.CommandText = @"
cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueResourceKey] ON [dbo].[LocalizationResources] ([ResourceKey])";
cmd.ExecuteNonQuery();
}
}

private static void CreateSchema(SqlCommand cmd)
{
// there is no tables, let's create
cmd.CommandText = @"
CREATE TABLE [dbo].[LocalizationResources]
(
[Id] [int] IDENTITY(1,1) NOT NULL,
Expand All @@ -57,12 +159,12 @@ [Author] [NVARCHAR](100) NOT NULL,
[IsHidden] [BIT] NOT NULL,
[IsModified] [BIT] NOT NULL,
[ModificationDate] [DATETIME2](7) NOT NULL,
[ResourceKey] [NVARCHAR](1000) NOT NULL,
[ResourceKey] [NVARCHAR](800) NOT NULL,
[Notes] [NVARCHAR](3000) NULL
CONSTRAINT [PK_LocalizationResources] PRIMARY KEY CLUSTERED ([Id] ASC))";
cmd.ExecuteNonQuery();
cmd.ExecuteNonQuery();

cmd.CommandText = @"
cmd.CommandText = @"
CREATE TABLE [dbo].[LocalizationResourceTranslations]
(
[Id] [INT] IDENTITY(1,1) NOT NULL,
Expand All @@ -71,95 +173,22 @@ [Language] [NVARCHAR](10) NOT NULL,
[Value] [NVARCHAR](MAX) NULL,
[ModificationDate] [DATETIME2](7) NOT NULL,
CONSTRAINT [PK_LocalizationResourceTranslations] PRIMARY KEY CLUSTERED ([Id] ASC))";
cmd.ExecuteNonQuery();
cmd.ExecuteNonQuery();

cmd.CommandText = @"
cmd.CommandText = @"
ALTER TABLE [dbo].[LocalizationResourceTranslations]
WITH CHECK ADD CONSTRAINT [FK_LocalizationResourceTranslations_LocalizationResources_ResourceId]
FOREIGN KEY([ResourceId]) REFERENCES [dbo].[LocalizationResources] ([Id])
ON DELETE CASCADE";
cmd.ExecuteNonQuery();

cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueTranslationForLanguage] ON [dbo].[LocalizationResourceTranslations] ([Language], [ResourceId])";
cmd.ExecuteNonQuery();
}
else
{
// there is something - so we need to check version and append missing stuff
// NOTE: for now assumption is that we start from previous 5.x version

// Below is list of additions on top of 5.x in chronological order.
// *** #1 addition - add LocalizationResources.Notes
cmd.CommandText = "SELECT COL_LENGTH('dbo.LocalizationResources', 'Notes')";
var result = cmd.ExecuteScalar();

if (result == DBNull.Value)
{
cmd.CommandText = "ALTER TABLE dbo.LocalizationResources ADD Notes NVARCHAR(3000) NULL";
cmd.ExecuteNonQuery();
}

// *** #2 change - LocalizationResources.Author NOT NULL
if (IsColumnNullable("LocalizationResources", "Author", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "Author", "[NVARCHAR](100)", "'migration'", cmd);
}

// *** #3 change - LocalizationResources.IsHidden NOT NULL
if (IsColumnNullable("LocalizationResources", "IsHidden", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "IsHidden", "bit", "0", cmd);
}

// *** #4 change - LocalizationResources.IsModified NOT NULL
if (IsColumnNullable("LocalizationResources", "IsModified", cmd))
{
ConvertColumnNotNullable("LocalizationResources", "IsModified", "bit", "0", cmd);
}

// *** #5 change - LocalizationResourceTranslations.Language NOT NULL
if (IsColumnNullable("LocalizationResourceTranslations", "Language", cmd))
{
ConvertColumnNotNullable("LocalizationResourceTranslations", "Language", "[NVARCHAR](10)", "''", cmd);
}

// *** #6 change - LocalizationResourceTranslations.ResourceId + Language = UNIQUE
cmd.CommandText =
"SELECT index_id FROM sys.indexes WHERE name='ix_UniqueTranslationForLanguage' AND object_id = OBJECT_ID('dbo.LocalizationResourceTranslations')";
result = cmd.ExecuteScalar();

if (result == null)
{
cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueTranslationForLanguage] ON [dbo].[LocalizationResourceTranslations] ([Language], [ResourceId])";
cmd.ExecuteNonQuery();
}

// *** #7 change - add LocalizationResourceTranslations.ModificationDate
cmd.CommandText = "SELECT COL_LENGTH('dbo.LocalizationResourceTranslations', 'ModificationDate')";
result = cmd.ExecuteScalar();

if (result == DBNull.Value)
{
cmd.CommandText =
"ALTER TABLE dbo.LocalizationResourceTranslations ADD ModificationDate [DATETIME2](7) NULL";
cmd.ExecuteNonQuery();

cmd.CommandText =
"UPDATE t SET t.ModificationDate = r.ModificationDate FROM dbo.LocalizationResourceTranslations t INNER JOIN LocalizationResources r ON r.Id = t.ResourceId";
cmd.ExecuteNonQuery();

cmd.CommandText =
"UPDATE dbo.LocalizationResourceTranslations SET ModificationDate = GETUTCDATE() WHERE ModificationDate IS NULL";
cmd.ExecuteNonQuery();

cmd.CommandText =
"ALTER TABLE dbo.LocalizationResourceTranslations ALTER COLUMN ModificationDate [DATETIME2](7) NOT NULL";
cmd.ExecuteNonQuery();
}
}
}
cmd.ExecuteNonQuery();

cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueResourceKey] ON [dbo].[LocalizationResources] ([ResourceKey])";
cmd.ExecuteNonQuery();

cmd.CommandText =
"CREATE UNIQUE INDEX [ix_UniqueTranslationForLanguage] ON [dbo].[LocalizationResourceTranslations] ([Language], [ResourceId])";
cmd.ExecuteNonQuery();
}

private void ConvertColumnNotNullable(
Expand Down

0 comments on commit 50ab0e4

Please sign in to comment.