Conversation
…for testing objects
|
@mbt1 @dkultasev Hello, may I check when would this PR be merged ? I am currently facing this issue addressed in the PR. Would be helpful if it gets merged at the earliest. Alternatively could you please suggest a workaround to use tSQLT.FakeTable on cross database synonyms. Thanks in advance. |
|
@priyasomangali. Only god knows when. I've made several attempts to keep this PR going, however without any success. I understand, that it is kind of hard to review this PR due to a lot of changes.... |
|
Another suggestion is to use my old implementation. It actually can fake temporal tables as well: CREATE PROCEDURE tSQLt.FakeSynonymTable
@SynonymTable VARCHAR(MAX)
, @SchemaName VARCHAR(MAX) = 'dbo'
, @IsTemporal BIT = 0
AS
BEGIN
DECLARE @NewName VARCHAR(MAX) = @SynonymTable + REPLACE(CAST(NEWID() AS VARCHAR(100)), '-', '');
DECLARE @SynonymWithSchema VARCHAR(MAX) = @SchemaName + '.' + @SynonymTable;
DECLARE @RenameCmd VARCHAR(MAX) = 'EXEC sp_rename ''' + @SynonymWithSchema + ''', ''' + @NewName + ''';';
DECLARE @object_name NVARCHAR(1000)
, @database NVARCHAR(200)
, @schema NVARCHAR(200)
, @object NVARCHAR(200)
, @parts_qty INT
, @object_id INT
, @sql NVARCHAR(MAX);
DECLARE @pk_columns AS TABLE
(
column_name sys.sysname NULL
, type_name sys.sysname NOT NULL
, max_length SMALLINT NOT NULL
, scale TINYINT NOT NULL
, precision TINYINT NOT NULL
, random_name NVARCHAR(200) NOT NULL
, full_type NVARCHAR(200) NOT NULL
);
IF (@IsTemporal = 1)
BEGIN
SELECT @object_name = s.base_object_name
FROM sys.synonyms AS s
JOIN sys.schemas AS sch on sch.schema_id = s.schema_id
WHERE s.name = @SynonymTable AND sch.name = @SchemaName;
END;
IF (@object_name IS NOT NULL)
BEGIN
DECLARE @object_name_splitted AS TABLE
(
id TINYINT IDENTITY(1, 1) NOT NULL
, obj_name NVARCHAR(200) NOT NULL
);
INSERT INTO @object_name_splitted (obj_name)
SELECT REPLACE(REPLACE(ss.value, ']', ''), '[', '') AS value
FROM STRING_SPLIT(@object_name, '.') AS ss;
SET @parts_qty = @@ROWCOUNT;
SELECT @database = pvt.db_name
, @schema = pvt.schema_name
, @object = pvt.object_name
FROM ( SELECT CASE @parts_qty - id + 1
WHEN 1 THEN 'object_name'
WHEN 2 THEN 'schema_name'
WHEN 3 THEN 'db_name'
ELSE 'instance_name'
END AS obj_type
, obj_name
FROM @object_name_splitted) AS src
PIVOT ( MAX(obj_name)
FOR obj_type IN (object_name, schema_name, db_name, instance_name)) AS pvt;
DECLARE @object_id_tbl AS TABLE
(
id INT
);
SET @sql = N'
USE ' + QUOTENAME(@database)
+ N'
SELECT o.object_id
FROM sys.objects AS o
JOIN sys.schemas AS s ON s.schema_id = o.schema_id
WHERE o.name = ''' + @object + N''' AND s.name = ''' + @schema + N'''';
INSERT INTO @object_id_tbl EXEC (@sql);
SELECT @object_id = id FROM @object_id_tbl;
SET @sql = N'
USE ' + QUOTENAME(@database)
+ N'
SELECT c.name AS column_name
, tp.name AS type_name
, c.max_length
, c.scale
, c.precision
, n.name
, tp.name + CASE WHEN tp.name IN ( ''varchar'', ''char'', ''varbinary'',
''binary'' )
THEN ''('' + CASE WHEN c.max_length = -1 THEN ''MAX''
ELSE CAST(c.max_length AS VARCHAR(5))
END + '')''
WHEN tp.name IN ( ''nvarchar'', ''nchar'', ''ntext'' )
THEN ''('' + CASE WHEN c.max_length = -1 THEN ''MAX''
ELSE CAST(c.max_length / 2 AS VARCHAR(5))
END + '')''
WHEN tp.name IN ( ''datetime2'', ''time2'',
''datetimeoffset'' )
THEN ''('' + CAST(c.scale AS VARCHAR(5)) + '')''
WHEN tp.name = ''decimal''
THEN ''('' + CAST(c.[precision] AS VARCHAR(5)) + '',''
+ CAST(c.scale AS VARCHAR(5)) + '')''
ELSE ''''
END + '' NOT NULL ''
FROM sys.tables AS t
JOIN sys.indexes AS i ON i.object_id = t.object_id
JOIN sys.index_columns AS ic ON ic.index_id = i.index_id AND ic.object_id = t.object_id
JOIN sys.columns AS c ON c.object_id = ic.object_id AND c.column_id = ic.column_id
JOIN sys.types AS tp ON c.user_type_id = tp.user_type_id
CROSS APPLY (SELECT i.name + CAST(NEWID() AS VARCHAR(40)) AS name) AS n
WHERE t.object_id = ''' + CAST(@object_id AS NVARCHAR(20))
+ N''' AND t.temporal_type = 2 AND i.is_primary_key = 1;
';
INSERT INTO @pk_columns (column_name
, type_name
, max_length
, scale
, precision
, random_name
, full_type)
EXEC (@sql);
END;
EXEC tSQLt.SuppressOutput @RenameCmd;
SET @sql = N'SELECT * INTO ' + @SynonymWithSchema + N' FROM ' + @NewName + N' WHERE 1=2;';
EXEC (@sql);
EXEC tSQLt.FakeTable @TableName = @SynonymWithSchema;
IF (@object_name IS NOT NULL)
BEGIN
DECLARE @column_name NVARCHAR(200)
, @full_type NVARCHAR(200);
DECLARE @cursor CURSOR;
SET @cursor = CURSOR FOR
SELECT column_name, full_type FROM @pk_columns;
OPEN @cursor;
FETCH NEXT FROM @cursor
INTO @column_name
, @full_type;
WHILE @@FETCH_STATUS = 0
BEGIN
SET @sql = CONCAT(
'ALTER TABLE '
, @schema
, '.'
, @object
, ' ALTER COLUMN '
, @column_name
, ' '
, @full_type);
EXEC (@sql);
FETCH NEXT FROM @cursor
INTO @column_name
, @full_type;
END;
CLOSE @cursor;
DEALLOCATE @cursor;
SELECT @sql = N'ALTER TABLE ' + CONCAT(@schema + '.', @object) + N' ADD CONSTRAINT '
+ QUOTENAME(random_name) + N' PRIMARY KEY CLUSTERED ('
+ STRING_AGG(QUOTENAME(column_name), ',') + N')'
FROM @pk_columns
GROUP BY random_name;
EXEC (@sql);
SET @sql = N'ALTER TABLE ' + CONCAT(@schema + '.', @object)
+ N' ALTER COLUMN sysstart DATETIME2(7) NOT NULL';
EXEC (@sql);
SET @sql = N'ALTER TABLE ' + CONCAT(@schema + '.', @object)
+ N' ALTER COLUMN sysend DATETIME2(7) NOT NULL';
EXEC (@sql);
-- Hardcoded columns, assuming that it will never change for us.
SET @sql = N'ALTER TABLE ' + CONCAT(@schema + '.', @object)
+ N' ADD PERIOD FOR SYSTEM_TIME (sysstart, sysend)';
EXEC (@sql);
SET @sql = N'ALTER TABLE ' + CONCAT(@schema + '.', @object)
+ N' SET(SYSTEM_VERSIONING = ON (DATA_CONSISTENCY_CHECK = OFF, HISTORY_TABLE = ' + @schema
+ N'.' + @object + N'_history))';
EXEC (@sql);
END;
END;
GO |
|
@dkultasev Thank you . I tried the second suggestion and it works fine. :) |
|
I know, it was working for quite a while already, however the 2nd approach is a bit better, as it has more functionality such as indexes, foreign keys, triggers, user types, whatever is supported by FakeTable natively and it is easy enough to install. |
|
Hey all, we are trying to get PR #19 merged and published at this very moment. This PR is going to be tough to review because of the sheer number of changes. @dkultasev , do you think we could sit down with you over zoom and start the review together? Can you DM me on twitter (@lizbaron) with times you might be available in UTC? Thank you! |
| END; | ||
| SET @OrigTableFullName = @SchemaName + '.' + @NewNameOfOriginalTable; | ||
| SET @SynonymObjectId = OBJECT_ID(@OrigTableFullName, 'SN'); | ||
| IF ( @SynonymObjectId > 0) |
|
@dkultasev @mbt1 |
I accidentally closed previous PR#48 and couldn't find the way how to re-open it, so creating new one.