SQL Saturday #469 – Brasilia


E aí pessoal !!!

O conteúdo da palesta sobre backup parcial e restauração parcial e online está disponível.

O Slide está disponível para download ou visualização abaixo

O link para o download dos scripts e da apresentação está aqui.

Quero, novamente, agradecer pela oportunidade de ter palestrado no evento e agradecer a todos que tiveram paciência de assistir minha palestra.

O link para o acesso a agenda do evento é:

https://www.sqlsaturday.com/469/schedule.aspx

A ideia é a evolução contínua, gostaria que vocês avaliassem como foi a apresentação:

Gerar DACPAC versão c#


Já faz um tempo desde a versão em powershell do gerador de DacPac,,, visto alguns bugs e limitações que alguém poderia ter em utilizá-lo resolvi montar uma versão mais adaptável do App.

Essa versão foi feita em Visual Studio 2013 e usa C#, o fonte ficará disponível no github (assim que conseguir fazer upload) e aqui junto com a versão compilada e com instalador e fonte.

Essa versão utiliza .Net Framework 4 e está o mais enxuta possível (pelo meu nível de conhecimento em programação)

O instalador gera um atalho na área de trabalho e uma entrada no “adicionar/remover programas”.

dacpac c

  • Bugs conhecidos:
  1. Ele não aceita utilizar um diretório que possua espaço no nome, pelo que consegui entender na exceção a culpa não é da forma que eu estou chamando o app para a extração mas do próprio extrator.
  2. Se clicar 2x na caixa de texto onde está a localização do SqlPackage ele vai exibir um diretório padrão onde deve estar o executável, se você não selecionar o arquivo e clicar em cancelar ou ok, a caixa de texto vai ser preenchida pelo SqlPackage.exe sem o path completo, o que vai gerar um erro na execução da extração.

Se alguém se interessar em usar, gostaria de feedbacks sobre o app.

ATUALIZAÇÃO !!!

Adicionei o projeto ao GitHub, quem quiser ajudar ou alterar o projeto pode acessar o endereço https://github.com/bigleka/SQL-Server-Gerador-de-DACPAC

 

MSDB e os Pacotes de SSIS


Esse código mostra o tamanho ocupado por cada pacote de SSIS carregado dentro do MSDB.

Algumas vezes o MSDB começa a ganhar proporções ocupadas que apenas a limpeza de rotina não dá conta e o pessoal esquece que os pacotes também ocupam espaço…


with ChildFolders
as
(
select PARENT.parentfolderid, PARENT.folderid, PARENT.foldername,
cast('' as sysname) as RootFolder,
cast(PARENT.foldername as varchar(max)) as FullPath,
0 as Lvl
from msdb.dbo.sysssispackagefolders PARENT
where PARENT.parentfolderid is null
UNION ALL
select CHILD.parentfolderid, CHILD.folderid, CHILD.foldername,
case ChildFolders.Lvl
when 0 then CHILD.foldername
else ChildFolders.RootFolder
end as RootFolder,
cast(ChildFolders.FullPath + '/' + CHILD.foldername as varchar(max))
as FullPath,
ChildFolders.Lvl + 1 as Lvl
from msdb.dbo.sysssispackagefolders CHILD
inner join ChildFolders on ChildFolders.folderid = CHILD.parentfolderid
)
select F.RootFolder, F.FullPath, P.name as PackageName,
P.description as PackageDescription, P.packageformat, P.packagetype,
P.vermajor, P.verminor, P.verbuild, P.vercomments,
cast(cast(P.packagedata as varbinary(max)) as xml) as PackageData,datalength(P.packagedata)/1024 AS SpaeceusedKB
from ChildFolders F
inner join msdb.dbo.sysssispackages P on P.folderid = F.folderid
order by F.FullPath asc, P.name asc;

Event Notification para monitorar DeadLock


A algumas semanas tivemos a necessidade de substituir a forma que usávamos para monitorar Dead Lock por alguma coisa mais usual…

Antes o Dead Lock era gravado no errorlog e depois encaminhado por email para o time,,, isso não é usual já que fica colocando muita informação desnecessária no errorlog e depois de alguns restarts perde-se algum histórico…

Com isso, cheguei a conclusão,,, vamos usar o event notification….

A vantagem é ser muito menos intrusivo que uma trigger e bem mais fácil de trabalhar que o System_Health…

Qual a ideia:

  1. O Event Notification vai enviar um email para cada vez que o evento de DeadLock acontecer, neste email vai conter informação da base que sofreu o DeadLock, horário e o DeadLock Graphic.
  2. Vai gravar em uma tabela na base de administração do DBA informações como: data e hora, base, XML com o evento.

use master
go

/*você já deve ter uma base de administração, caso não tenha, crie uma e troque o nome*/

alter database BASE_DE_ADMINISTRACAO_DO_DBA set enable_broker with rollback immediate
go

alter database BASE_DE_ADMINISTRACAO_DO_DBA set TRUSTWORTHY on
go

use BASE_DE_ADMINISTRACAO_DO_DBA
go

/**criando a tabela de controle/

create TABLE [dbo].[SQLDeadlockEvents](
[EventRowID] [bigint] primary key IDENTITY(1,1) NOT NULL,
[EventType] [nvarchar](128) NOT NULL,
[AlertTime] [datetime] NULL,
[DeadlockGraph] [xml] NULL,
[DatabaseName] [sysname] null,
[AuditDate] [smalldatetime]
) ON [FG_Data_01]
with (data_compression = PAGE) --neste caso tenho EE se você usar SE comente esta linha
GO

/**Criando a fila do Broker/

CREATE QUEUE [DeadlockGraphQueue]
GO

/*Criando o serviço para a fila do Broker*/

CREATE SERVICE [DeadlockEventsService]
AUTHORIZATION [dbo]
ON QUEUE [dbo].[DeadLockGraphQueue]
([http://schemas.microsoft.com/SQL/Notifications/PostEventNotification])
GO

/*criando rota*/

CREATE ROUTE DeadlockGraphRoute
WITH SERVICE_NAME = 'DeadlockEventsService',
ADDRESS = 'LOCAL';
GO

/* Para ficar mais fácil ele vai criar o event notification com os dados dinamicamente, se não, eu teria que explicar que o guid altera, onde tem que pegar essa informação,,, era mais SQL para uma coisa que pode ser feita de forma dinâmica */

DECLARE @AuditServiceBrokerGuid [uniqueidentifier]
,@SQL [varchar](max);

-- broker guid do CaptureDeadlockGraph
SELECT @AuditServiceBrokerGuid = [service_broker_guid]
FROM [master].[sys].[databases]
WHERE [name] = 'BASE_DE_ADMINISTRACAO_DO_DBA'

SET @SQL = 'IF EXISTS (SELECT * FROM sys.server_event_notifications
WHERE name = ''DeadlockGraphEventNotification'')

DROP EVENT NOTIFICATION DeadlockGraphEventNotification ON SERVER

CREATE EVENT NOTIFICATION DeadlockGraphEventNotification
ON SERVER --aqui é o detalhe legal... servidor e não database
WITH fan_in
FOR DEADLOCK_GRAPH
TO SERVICE ''DeadlockEventsService'', '''
+ CAST(@AuditServiceBrokerGuid AS [varchar](50)) + ''';'
EXEC (@SQL)
GO

/*Para confirmar que foi criado,,, lembra que é nível servidor,,, por isso a consulta no [sys].[server_event_notifications] */

SELECT * FROM [sys].[server_event_notifications]
WHERE [name] = 'DeadlockGraphEventNotification';
GO

/* onde a mágica acontece.... */
create PROC [dbo].[usp_sCaptureDeadlockGraph]
AS BEGIN

SET NOCOUNT ON
SET CONCAT_NULL_YIELDS_NULL ON
SET ANSI_PADDING ON
SET ANSI_WARNINGS ON

DECLARE @SQLProcedureName [varchar](64)
SET @SQLProcedureName = 'usp_sCaptureDeadlockGraph'

BEGIN TRY

DECLARE @message_body [xml]
, @EventTime [datetime]
, @EventType [varchar](128)
, @message_type_name [nvarchar](256)
, @dialog [uniqueidentifier]

-- Endless loop
WHILE (1 = 1)
BEGIN
BEGIN TRANSACTION ;

-- Receive the next available message
WAITFOR (RECEIVE TOP(1)
@message_type_name = [message_type_name],
@message_body = [message_body],
@dialog = [conversation_handle]
FROM [dbo].[DeadlockGraphQueue]), TIMEOUT 2000

-- Rollback and exit if no messages were found
IF (@@ROWCOUNT = 0)
BEGIN
ROLLBACK TRANSACTION;
BREAK;
END;

-- End conversation of end dialog message
IF (@message_type_name = 'http://schemas.microsoft.com/SQL/ServiceBroker/EndDialog')
BEGIN
PRINT 'End Dialog received for dialog # ' + CAST(@dialog as [nvarchar](40));
END CONVERSATION @dialog;
END;

ELSE
BEGIN

SET @EventTime = CAST(CAST(@message_body.query('/EVENT_INSTANCE/PostTime/text()') AS [nvarchar](max)) AS [datetime])
SET @EventType = CAST(@message_body.query('/EVENT_INSTANCE/EventType/text()') AS [nvarchar](128))

INSERT INTO [dbo].[SQLDeadlockEvents] ([EventType], [AlertTime], [DeadlockGraph])
VALUES (@EventType, @EventTime, @message_body)
END

COMMIT TRANSACTION

DECLARE @MailSubject [nvarchar](256)
,@MailBody [nvarchar](max)
,@SQLQuery [nvarchar](max)
,@AttachedFileName [nvarchar](256)
,@EventDateTime [datetime]
,@EventID [int]
,@Counter [int]
,@dbname [sysname]

IF EXISTS (SELECT * FROM [tempdb].[dbo].[sysobjects]
WHERE name = '##ListDeadlocks' AND type in (N'U'))
DROP TABLE ##ListDeadlocks

CREATE TABLE ##ListDeadlocks
([EventRowID] [int]
,[AlertTime] [datetime]
,[DeadlockGraph] [xml]
,[DeadlockXml] [xml])

INSERT INTO ##ListDeadlocks
([EventRowID]
,[AlertTime]
,[DeadlockGraph]
,[DeadlockXml])
SELECT [EventRowID]
,[AlertTime]
,[DeadlockGraph].query('./EVENT_INSTANCE/TextData/deadlock-list')
,DeadlockGraph FROM [dbo].[SQLDeadlockEvents]
WHERE [EventRowID] = @@IDENTITY

select @dbname = db_name(DeadlockGraph.value( '(/deadlock-list//@dbid)[1]', 'int' ))
--db_name(DeadlockGraph.value( '(/EVENT_INSTANCE/TextData/deadlock-list//@dbid)[1]', 'int' ) )
FROM ##ListDeadlocks
--where [EventRowID] = SCOPE_IDENTITY()

update [dbo].[SQLDeadlockEvents]
set [DatabaseName] = @dbname
where [EventRowID] = (select [EventRowID] FROM ##ListDeadlocks )

SELECT @Counter = MIN(EventRowID)
FROM ##ListDeadlocks

WHILE @Counter IS NOT NULL
BEGIN

SELECT @EventDateTime = [AlertTime]
,@EventID = [EventRowID]
FROM ##ListDeadlocks
WHERE [EventRowID] = @Counter

SELECT @MailSubject = 'Um deadlock ocorreu em ' + cast(@dbname as [varchar](256)) --+' servidor: '
--+ CONVERT([varchar](128), SERVERPROPERTY('ServerName'))
,@MailBody = 'Deadlock EventRowID: ' + CAST(@EventID AS [varchar](12))
+ char(13) + char(13) + 'O deadlock ocorreu as '
+ CONVERT([varchar](50), @EventDateTime, 120)
+ ' no Servidor: ' + CONVERT([varchar](128), SERVERPROPERTY('ServerName'))+'.'+char(13) + char(13) + 'Verifique o anexo xdl-file para mais detalhes.'
+ char(13) + char(13) +'Para mais informações ou eventos anteriores consulte: SELECT * FROM BASE_DE_ADMINISTRACAO_DO_DBA.dbo.SQLDeadlockEvents WITH (NOLOCK)'
,@SQLQuery = 'SET NOCOUNT ON; SELECT [DeadlockGraph] FROM [##ListDeadlocks] WITH (READUNCOMMITTED) WHERE EventRowID = '
+ CAST(@EventID AS [varchar](10))
,@AttachedFileName = CONVERT([varchar](128), SERVERPROPERTY('ServerName')) + '_' + CAST(@EventID AS [varchar](12)) + '.xdl'

EXEC msdb.dbo.sp_send_dbmail
@recipients = 'email@dominio.com.br' -- troque o email aqui
,@subject = @MailSubject
,@body = @MailBody
,@query = @SQLQuery
,@attach_query_result_as_file = 1 ,@query_attachment_filename = @AttachedFileName -- http://support.microsoft.com/kb/924345
,@query_result_header = 0
,@query_result_width = 32767
,@query_no_truncate = 1

DELETE FROM ##ListDeadlocks
WHERE EventRowID = @Counter

SELECT @Counter = MIN(EventRowID)
FROM ##ListDeadlocks
end
END --End of loop

END TRY

BEGIN CATCH

SELECT ERROR_NUMBER()
,ERROR_SEVERITY()
,ERROR_STATE()
,ISNULL(ERROR_PROCEDURE(), @SQLProcedureName)
,ERROR_LINE()
,ERROR_MESSAGE()

END CATCH

END
GO

/*inicia a fila para começar a capturar os DeadLocks*/
ALTER QUEUE [dbo].[DeadlockGraphQueue]
WITH STATUS = ON
,ACTIVATION (PROCEDURE_NAME = [usp_sCaptureDeadlockGraph]
,STATUS = ON
,MAX_QUEUE_READERS = 1
,EXECUTE AS OWNER)
GO

Gerar DACPAC usando Powershell v2


Para quem leu meu post anterior de Gerar DACPAC usando Powershell percebeu que é um código muito simples, passível de erros como:

  • digitar o nome do banco errado,
  • símbolos nos nomes dos bancos,
  • não escolher um local ou o nome do servidor ele gera erro no script…

coisas bem primárias…

Dessa vez fiz algumas melhorias,,, como:

  • Tela mais simpática
  • conecta no servidor de banco e lista as bases
  • multi seleção de bases
  • não deixa você continuar se não selecionar um destino e colocar o nome do servidor
  • Não fecha sozinho
  • deixa na tela do posh o código para, caso precise, você copie e execute novamente
  • coloca o mouse como ampulheta
  • abre o diretório de destino quando acaba a tarefa
  • e localiza o executável do gerador de dacpac,,, desde que esteja no C:\

Uma coisa muito importante, o código é livre para modificação, sinta-se a vontade de fazer qualquer modificação que queira,, se achar que sua versão ficou melhor, ou achou algum problema e corrigiu, mande o código, vamos melhorar,,,,

Existe um detalhe para rodar esta versão sem problemas,,, você precisa ter o Windows atualizado além do Windows Management Framework 4.0 e do .Net Frame Work 4.5.2.

gerador de dacpac v2


cls
$data = get-date -format "_yyyyMMdd"
$WindowTitle = "Gerador de DACPAC"
$LabelPath = "Caminho:"
$LabelServer = "Servidor:"

$aplicacao = (Get-ChildItem -Path "C:\Program Files (x86)\Microsoft SQL Server" -Include "SqlPackage.exe" -Recurse | % { $_.FullName } | Select-Object -First 1)

$x = @()

[void] [System.Reflection.Assembly]::LoadWithPartialName("System.Windows.Forms")
[void] [System.Reflection.Assembly]::LoadWithPartialName("System.Drawing")

$objForm = New-Object System.Windows.Forms.Form
$objForm.Text = $WindowTitle
$objForm.Size = New-Object System.Drawing.Size(290,270)
$objForm.StartPosition = "CenterScreen"
$objForm.FormBorderStyle = 'FixedSingle'

$objForm.KeyPreview = $True
$objForm.Add_KeyDown({if ($_.KeyCode -eq "Escape")
{$objForm.Close()}})

$OKButton = New-Object System.Windows.Forms.Button
$OKButton.Location = New-Object System.Drawing.Size(75,215)
$OKButton.Size = New-Object System.Drawing.Size(75,23)
$OKButton.Text = "OK"

$OKButton.Add_Click(
{$i=0
if ( $textbox2.Text -eq '' )
{

}

else
{
foreach ($objItem in $objListbox.SelectedItems)
{
#[System.Windows.Forms.Application]::UseWaitCursor=$true
$objForm.Cursor=[System.Windows.Forms.Cursors]::WaitCursor
$local = $textbox2.Text
$servidor = $textBoxServerName.Text
Write-Progress -Activity "Gerando DACPAC" -status "Gerando DACPAC para $objItem" -percentComplete ($i++ / ($objListbox.SelectedItems).Count*100)
$exec = ("'$aplicacao'" + " /a:Extract /ssn:"+$servidor +" /sdn:"+$objItem +" /tf:"+"'$local'"+"\"+$objItem+$data+".dacpac")
#$exec = (C:\"Program Files (x86)"\"Microsoft SQL Server"\110\DAC\bin\SqlPackage.exe /a:Extract /ssn:$servidor /sdn:$objItem /tf:$local\$objItem$data+.dacpac)
write-host $exec
Invoke-expression "& $exec"
#[System.Windows.Forms.Application]::UseWaitCursor=$false
$objForm.Cursor=[System.Windows.Forms.Cursors]::Default
}
#Invoke-Item "$local"
}
if ( $checkbox1.Checked -eq $true -and $textbox2.Text -ne '')
{
Invoke-Item "$local"
}

else
{

}

#$objForm.Close()
})

$objForm.Controls.Add($OKButton)

$CancelButton = New-Object System.Windows.Forms.Button
$CancelButton.Location = New-Object System.Drawing.Size(150,215)
$CancelButton.Size = New-Object System.Drawing.Size(75,23)
$CancelButton.Text = "Fechar"
$CancelButton.Add_Click({$objForm.Close()})
$objForm.Controls.Add($CancelButton)

# create your checkbox
$checkbox1 = new-object System.Windows.Forms.checkbox
$checkbox1.Location = new-object System.Drawing.Size(260,66)
$checkbox1.Size = new-object System.Drawing.Size(250,50)
$checkbox1.Checked = $true
$objForm.Controls.Add($checkbox1)

$objLabel = New-Object System.Windows.Forms.Label
$objLabel.Location = New-Object System.Drawing.Size(10,120)
$objLabel.Size = New-Object System.Drawing.Size(280,20)
$objLabel.Text = "Selecione a base que deseja extrair o DACPAC:"
$objForm.Controls.Add($objLabel)

$objListbox = New-Object System.Windows.Forms.Listbox
$objListbox.Location = New-Object System.Drawing.Size(10,140)
$objListbox.Size = New-Object System.Drawing.Size(260,20)
$objLabel2 = New-Object System.Windows.Forms.Label
$objLabel2.Location = New-Object System.Drawing.Size(10,10)
$objLabel2.Size = New-Object System.Drawing.Size(280,20)
$objLabel2.Text = "Servidor:"
$objForm.Controls.Add($objLabel2)

# Create textbox for the Server name
$textBoxServerName = New-Object System.Windows.Forms.TextBox
$textBoxServerName.DataBindings.DefaultDataSourceUpdateMode = 0
$textBoxServerName.Location = New-Object System.Drawing.Size(10,30)
$textBoxServerName.Name = "ServerName"
$textBoxServerName.Size = New-Object System.Drawing.Size(100,10)
$textBoxServerName.TabIndex = 0
$objForm.Controls.Add($textBoxServerName)
$objLabel2 = New-Object System.Windows.Forms.Label
$objLabel2.Location = New-Object System.Drawing.Size(10,60)
$objLabel2.Size = New-Object System.Drawing.Size(280,20)
$objLabel2.Text = "Destino:"
$objForm.Controls.Add($objLabel2)

# Create textbox used to file destination
$textBox2 = New-Object System.Windows.Forms.TextBox
$textBox2.DataBindings.DefaultDataSourceUpdateMode = 0
$textBox2.Location = New-Object System.Drawing.Size(10,80)
$textBox2.Name = "textBox2"
$textBox2.Size = New-Object System.Drawing.Size(150,10)
$textBox2.TabIndex = 0
$objForm.Controls.Add($textBox2)

$app = New-Object -ComObject Shell.Application
$destino_OnClick=
{
#TODO: Place custom script here

try {
$browseForFolderOptions = 0
if ($NoNewFolderButton) { $browseForFolderOptions += 512 }

$folder = $app.BrowseForFolder(0, $Message, $browseForFolderOptions, $InitialDirectory)
#if ($folder) { $selectedDirectory = $folder.Self.Path } else { $selectedDirectory = '' }
#[System.Runtime.Interopservices.Marshal]::ReleaseComObject($app) > $null
$textbox2.Text = $folder.Self.Path #$selectedDirectory #.FileName.ToString()

}
catch {
[System.Windows.Forms.MessageBox]::Show(
$_.Exception.Message,
"Error",
[System.Windows.Forms.MessageBoxButtons]::OK,
[System.Windows.Forms.MessageBoxIcon]::Error
)
}

}
$conectar_OnClick=
{
#TODO: Place custom script here

if ( $textBoxServerName.Text -eq '' )
{

}

else
{
$objForm.Cursor=[System.Windows.Forms.Cursors]::WaitCursor
$dataSource = $textBoxServerName.Text

$database = "master"
$connectionString = "Server=$dataSource;Database=$database;Integrated Security=True;"

$query = "select name from sys.databases where database_id > 4"

$connection = New-Object System.Data.SqlClient.SqlConnection
$connection.ConnectionString = $connectionString
$connection.Open()
$command = $connection.CreateCommand()
$command.CommandText = $query
$result = $command.ExecuteReader()
$table = new-object “System.Data.DataTable”
$table.Load($result)
#$table
$objListbox.datasource=$table.Item(0)
$connection.Close()
$objForm.Cursor=[System.Windows.Forms.Cursors]::Default

}

}

$conectar = New-Object System.Windows.Forms.Button
$conectar.Location = New-Object System.Drawing.Size(200,30)
$conectar.Size = New-Object System.Drawing.Size(60,20)
#$button2.TabIndex = 1
$conectar.Text = "Conectar"
$conectar.UseVisualStyleBackColor = $True
$conectar.add_Click($conectar_OnClick)
$objForm.Controls.Add($conectar)
$destino = New-Object System.Windows.Forms.Button
$destino.Location = New-Object System.Drawing.Size(200,80)
$destino.Size = New-Object System.Drawing.Size(50,20)
#$button2.TabIndex = 1
$destino.Text = "..."
$destino.UseVisualStyleBackColor = $True
$destino.add_Click($destino_OnClick)
$objForm.Controls.Add($destino)

$objListbox.SelectionMode = "MultiExtended"

$objListbox.Height = 70
$objForm.Controls.Add($objListbox)
$objForm.Topmost = $True

$objForm.Add_Shown({$objForm.Activate()})
[void] $objForm.ShowDialog()

$x

Gerar DACPAC usando PowerShell


O ciclo de vida da maioria dos bancos envolve desenvolvedores e DBA´s compartilhando scripts para atualização de objetos e atividades de manutenção.

Existem algumas formas de fazer isso:

  • gerar scripts de objetos
  • Proporcionar acesso as partes interessadas (piada… eu sei…) para gerar os scripts
  • DACPAC´s
  • Backup/Restore
  • etc..

Um pouco de contexto antes,,,

Um DAC (aplicativo da camada de dados) é uma entidade lógica de gerenciamento de banco de dados que define todos os objetos do SQL Server, como tabelas, exibições e objetos de instância, incluindo logons, associados a um banco de dados de usuário.

Todos tem seus prós e contras… não é a intenção deste post tratar isso…

Para quem gosta de gerar scripts dos objetos lembra que tem um outro post que faz isso…

A vantagem do DACPAC é que você pode usa-lo para comparação entre um projeto do TFS e esse pacote extraído da produção ou, caso você seja o DBA, você pode comparar esse pacote contra a sua base de produção ou uma base em homologação. Gerar os scripts para igualar os ambientes ou apenas conseguir ter ideia das diferenças.


Add-Type -AssemblyName System.Drawing
Add-Type -AssemblyName System.Windows.Forms

$data = get-date -format "_yyyyMMdd"
$WindowTitle = "Gerador de DACPAC"
$LabelPath = "Caminho:"
$LabelServer = "Servidor:"

# Create the Label.
$label = New-Object System.Windows.Forms.Label
$label.Location = New-Object System.Drawing.Size(10,20)
$label.Size = New-Object System.Drawing.Size(280,20)
$label.AutoSize = $true
$label.Text = $LabelPath

# Create the TextBox used to capture the user's text.
$textBox = New-Object System.Windows.Forms.TextBox
$textBox.Location = New-Object System.Drawing.Size(10,40)
$textBox.Size = New-Object System.Drawing.Size(575,200)
$textBox.AcceptsReturn = $true
$textBox.AcceptsTab = $false
$textBox.Multiline = $true
$textBox.ScrollBars = 'Both'
$textBox.Text = $DefaultText

# Create textbox used to file destination
$textBox2 = New-Object System.Windows.Forms.TextBox
$textBox2.DataBindings.DefaultDataSourceUpdateMode = 0
$textBox2.Location = New-Object System.Drawing.Size(65,20)
$textBox2.Name = "textBox2"
$textBox2.Size = New-Object System.Drawing.Size(150,10)
$textBox2.TabIndex = 0
# Create the Label.
$label2 = New-Object System.Windows.Forms.Label
$label2.Location = New-Object System.Drawing.Size(420,20)
$label2.AutoSize = $true
$label2.Text = $LabelServer

# Create textbox for the Server name
$textBoxServerName = New-Object System.Windows.Forms.TextBox
$textBoxServerName.DataBindings.DefaultDataSourceUpdateMode = 0
$textBoxServerName.Location = New-Object System.Drawing.Size(480,20)
$textBoxServerName.Name = "textBox2"
$textBoxServerName.Size = New-Object System.Drawing.Size(100,10)
$textBoxServerName.TabIndex = 0

# Create the OK button.
$okButton = New-Object System.Windows.Forms.Button
$okButton.Location = New-Object System.Drawing.Size(415,250)
$okButton.Size = New-Object System.Drawing.Size(75,25)
$okButton.Text = "OK"
$okButton.Add_Click({ $form.Tag = $textBox.Text; $form.Close() })

# Create the Cancel button.
$cancelButton = New-Object System.Windows.Forms.Button
$cancelButton.Location = New-Object System.Drawing.Size(510,250)
$cancelButton.Size = New-Object System.Drawing.Size(75,25)
$cancelButton.Text = "Cancel"
$cancelButton.Add_Click({ $form.Close() })

$app = New-Object -ComObject Shell.Application
$button2_OnClick=
{
try {

$browseForFolderOptions = 0
if ($NoNewFolderButton) { $browseForFolderOptions += 512 }
$folder = $app.BrowseForFolder(0, $Message, $browseForFolderOptions, $InitialDirectory)
$textbox2.Text = $folder.Self.Path #$selectedDirectory #.FileName.ToString()
}
catch {
[System.Windows.Forms.MessageBox]::Show(
$_.Exception.Message,
"Error",
[System.Windows.Forms.MessageBoxButtons]::OK,
[System.Windows.Forms.MessageBoxIcon]::Error
)
}

}
$button2 = New-Object System.Windows.Forms.Button
$button2.Location = New-Object System.Drawing.Size(215,20)
$button2.Size = New-Object System.Drawing.Size(50,20)
$button2.Text = "..."
$button2.UseVisualStyleBackColor = $True
$button2.add_Click($button2_OnClick)
# Create the form.
$form = New-Object System.Windows.Forms.Form
$form.Text = $WindowTitle
$form.Size = New-Object System.Drawing.Size(610,320)
$form.FormBorderStyle = 'FixedSingle'
$form.StartPosition = "CenterScreen"
$form.AutoSizeMode = 'GrowAndShrink'
$form.Topmost = $True
$form.AcceptButton = $okButton
$form.CancelButton = $cancelButton
$form.ShowInTaskbar = $true

# Add all of the controls to the form.
$form.Controls.Add($label)
$form.Controls.Add($label2)
$form.Controls.Add($textBox)
$form.Controls.Add($okButton)
$form.Controls.Add($cancelButton)
$form.Controls.Add($textBox2)
$form.Controls.Add($textBoxServerName)
$form.Controls.Add($button2)

# Initialize and show the form.
$form.Add_Shown({$form.Activate()})
$form.ShowDialog() > $null

$srv = $textBoxServerName.Text
$local = $textbox2.Text
$bases = $textBox.Text.Split("`n")|%{$_.trim()}
$i=0
foreach ($s in $bases)
{
Write-Progress -Activity "Gerando DACPAC" -status "Gerando DACPAC para $s" -percentComplete ($i++ / $bases.count*100)
$GoBigSon= (C:\"Program Files (x86)"\"Microsoft SQL Server"\110\DAC\bin\SqlPackage.exe /a:Extract /ssn:$srv /sdn:$s /tf:$local\$s$data.dacpac )
}

Como parece de praxe,,, tem uns pequenos bugs:

  • Quando clicar no “…” para mapear o caminho, se não aparecer uma janela pop-up, movimenta a janela do app um pouco para o lado, ela ficou atrás da janela inicial,,, isso é um bug que acontece de vez em quando,,,
  • se vc clicar diversas vezes no “…” ele vai ficar abrindo diversas vezes…
  • ainda não estou tratando outros tipos de entrada no campo texto,,,, você deve colocar um banco abaixo do outro,,,
  • e sim,,, ele fecha a janela quando você clica em OK,,,

Ele ficou até que bem simpático…

gerador dacpac p1

 

Com os campos preenchidos

gerador dacpac p2

 

E tem até barra de status… olha que chique…

gerador dacpac p3

 

Contar VLF


Esse script é bem simples, ele vai acessar todas as bases da instância e vai contar quantos VLF´s existem em cada base.
Nada muito complexo.
Qual a importância disso? Muitos VLF´s podem acarretar em um restore muito lento, ou uma inicialização da base muito demorada.
Isso acontece, em muitos casos, por crescimento desordenado do transaction log (crescimento em porcentagem, ou em tamanhos pequenos).
Podemos colocar da seguinte forma: Falta de planejamento e atenção.
Quer saber mais sobre VLF? esse vídeo é bem legal.
Existe alguma forma de corrigir isso? Claro… Não é bonito…
Vamos fazer um quiz, coloquem um comentário com a maior quantidade de VLF´s que vocês tem no ambiente…


CREATE TABLE #temp (
 RecoveryUnitID VARCHAR(255) --essa coluna só existe a partir do 2012, comente esta linha se for executar do 2008r2 para traz
 , FileID VARCHAR(255)
 , FileSize VARCHAR(255)
 , StartOffset VARCHAR(255)
 , FSeqNo VARCHAR(255)
 , [Status] VARCHAR(255)
 , Parity VARCHAR(255)
 , CreateLSN VARCHAR(255)
 )

CREATE TABLE #DBCCResults (
 ServerName VARCHAR(255)
 , DBName VARCHAR(255)
 , VLF bigint
 )

EXEC master.dbo.sp_MSforeachdb
 @command1 = 'USE ? INSERT INTO #temp EXECUTE (''DBCC LOGINFO'')'
 , @command2 = 'INSERT INTO #DBCCResults SELECT @@SERVERNAME, ''?'', count(1) FROM #temp'
 , @command3 = 'TRUNCATE TABLE #temp'

 SELECT DISTINCT
 ServerName
 , DBName
 , VLF
 FROM #DBCCResults
 ORDER BY 3 DESC

 DROP TABLE #temp, #DBCCResults;

Recuperar DML através do Transaction Log


Todos sabem que quando é feita uma operação no banco muita coisa passa pelo Transaction Log. Pode ser de minimamente logado ou até quase absolutamente tudo e todo mundo sabe que é possível restaurar tudo do que foi feito através dos arquivos de backup.

O script abaixo é o tipo de script que vale muito ser guardado com todo o carinho naquele pendrive cheio de outros scripts… Ele lê o transaction log e gera as operações para reverter alguma modificação na tabela que está sendo pesquisada.

Ok, eu sei que existem aplicações que fazem isso, mas elas são pagas e dependendo do cenário você não pode instalar uma aplicação dessas em um servidor.

Também existe a opção de recover do banco e voltar o transaction até um momento antes daquela operação mas pode ser que seu banco tenha alguns TB´s ou você não possa simplesmente parar toda empresa por causa de alguns registros e comprometer todas as outras operações de outras partes dos sistemas.

Antes de mais nada quer entender como o script funciona? Leia este post do Paul Randal (b| t) você vai entender como funciona o fn_dblog e o fn_dump_dblog

Agora o script…

Originalmente o script está localizado aqui.

Ele possui direitos de cópia livres para modificação/publicação/etc.

/******
(c) Walk the Way, 2014 (see accompanying license)
To use this:
1) SQL Server Management Studio must be "Run as administrator" (or using an admin account)
2) The SQL login User must have SQL sysadmin Server Role
For running DBCC PAGE: it appears that the SQL User must have SQL sysadmin Server Role
For sys.fn_dblog: the SQL User must have SELECT permission for "master" in System Databases
For SQL 2008 uncomment line 1150 (DATE not suppported in SQL 2005)

The WTW Open License

Copyright (c) 2014 Walk the Way; all rights reserved, except as follows:

Permission is hereby granted, free of charge, to any person obtaining a copy
of this software and associated documentation files (the "Software"), to deal
in the Software as follows: the unrestricted right to use, copy, modify, merge,
publish, distribute, sublicense, and to permit persons to whom the Software
is furnished to do so, subject to the following conditions:

The above copyright notice and this permission notice shall be included in all
copies or substantial portions of the Software.

THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
SOFTWARE.

modo de usar:

Recover_Modified_Data_Proc 'Nome_Da_Base', 'dbo.Tabela'

Recover_Modified_Data_Proc 'Nome_Da_Base', 'dbo.Tabela', '2014/07/16', '2014/07/18' --com periodo

******/
IF EXISTS (SELECT *
FROM sys.objects
WHERE object_id = OBJECT_ID(N'[dbo].[Recover_Modified_Data_Proc]')
AND TYPE IN ( N'FN', N'IF', N'TF', N'FS', N'FT', N'P' ))
SET NOEXEC ON

--> Based on the work of Muhammad Imran generously published at:
--> http://raresql.com/2012/02/01/how-to-recover-modified-records-from-sql-server-part-1/
-->
--> Uncomment/Comment block below for testing/development
/****************************************
SET NOEXEC OFF
IF OBJECT_ID (N'[@ResultTable]', N'U') IS NOT NULL DROP TABLE [@ResultTable]
IF OBJECT_ID('tempdb..#T1') IS NOT NULL DROP TABLE #T1
IF OBJECT_ID('tempdb..#temp_Data') IS NOT NULL DROP TABLE #temp_Data
IF OBJECT_ID('tempdb..#CTE') IS NOT NULL DROP TABLE #CTE
IF OBJECT_ID('tempdb..#TransIdUpdateList') IS NOT NULL DROP TABLE #TransIdUpdateList
IF OBJECT_ID('tempdb..#TransIdDeleteList') IS NOT NULL DROP TABLE #TransIdDeleteList
IF OBJECT_ID('tempdb..#TransIdAllList') IS NOT NULL DROP TABLE #TransIdAllList
IF OBJECT_ID('tempdb..#AllocIdList') IS NOT NULL DROP TABLE #AllocIdList
IF OBJECT_ID('tempdb..#SysFnDblog') IS NOT NULL DROP TABLE #SysFnDblog
IF OBJECT_ID('tempdb..#DelRows') IS NOT NULL DROP TABLE #DelRows
DECLARE @Database_Name NVARCHAR(MAX)
DECLARE @SchemaName_n_TableName NVARCHAR(MAX)
DECLARE @Date_From DATETIME
DECLARE @Date_To DATETIME
SET @Database_Name = 'Test'
SET @SchemaName_n_TableName = 'Student'
SET @Date_From = '2014/05/22' --'1900/01/01'
SET @Date_To = '2099/01/01' --'9999/12/31'
print @Date_From
print @Date_To
****************************************/
--> Uncomment/Comment block below to create Stored Procedure
/****************************************/
IF OBJECT_ID('Recover_Modified_Data_Proc', 'P') IS NOT NULL
DROP PROC Recover_Modified_Data_Proc
GO
Create PROCEDURE Recover_Modified_Data_Proc
@Database_Name NVARCHAR(MAX),
@SchemaName_n_TableName NVARCHAR(MAX),
@Date_From DATETIME = '1900/01/01', --> Null equivalent
@Date_To DATETIME = '9999/12/31' --> largest date
AS

--> For SQL 2005; PIVOT requires compatibility_level = 90
IF ((SELECT [compatibility_level] from sys.databases where [name] = @Database_Name) < 90) BEGIN
RETURN -1
END
/****************************************/

DECLARE @Debug INT
SET @Debug = 0
DECLARE @parms NVARCHAR(1024)
DECLARE @Fileid INT
DECLARE @hex_pageid AS VARCHAR(MAX)
DECLARE @Pageid INT
DECLARE @Slotid INT
DECLARE @TransactionName VARCHAR(MAX)
DECLARE @CurrentLSN VARCHAR(MAX)
DECLARE @BeginTime DATETIME
DECLARE @RowLogContents0 VARBINARY(8000)
DECLARE @RowLogContents1 VARBINARY(8000)
DECLARE @RowLogContents2 VARBINARY(8000)
DECLARE @RowLogContents3 VARBINARY(8000)
DECLARE @RowLogContents3_Var VARCHAR(MAX)

DECLARE @RowLogContents4 VARBINARY(8000)
DECLARE @LogRecord VARBINARY(8000)
DECLARE @LogRecord_Var VARCHAR(MAX)

DECLARE @ConsolidatedPageID VARCHAR(MAX)
DECLARE @AllocUnitID BIGINT
DECLARE @TransactionID VARCHAR(MAX)
DECLARE @Operation VARCHAR(MAX)
DECLARE @DatabaseCollation VARCHAR(MAX)

--FOR @Operation ='LOP_MODIFY_COLUMNS'
DECLARE @RowLogData_Var VARCHAR(MAX)
DECLARE @RowLogData_Hex VARBINARY(MAX)

DECLARE @TotalFixedLengthData INT
DECLARE @FixedLength_Offset INT
DECLARE @VariableLength_Offset INT
DECLARE @VariableLength_Offset_Start INT
DECLARE @VariableLengthIncrease INT
DECLARE @FixedLengthIncrease INT
DECLARE @OldFixedLengthStartPosition INT
DECLARE @FixedLength_Loc INT
DECLARE @VariableLength_Loc INT
DECLARE @FixedOldValues VARBINARY(MAX)
DECLARE @FixedNewValues VARBINARY(MAX)
DECLARE @VariableOldValues VARBINARY(MAX)
DECLARE @VariableNewValues VARBINARY(MAX)

/* Pick The actual data
*/
DECLARE @temppagedata TABLE(
[RecordID] INT IDENTITY(1,1)
,[ParentObject] sysname
,[Object] sysname
,[Field] sysname
,[Value] sysname
)

DECLARE @pagedata TABLE(
[Page Index] int
,[DBCCid] int
,[ParentObject] sysname
,[Object] sysname
,[Field] sysname
,[Value] sysname
)

DECLARE @pageindex TABLE(
[PageIndexID] INT IDENTITY(1,1)
,[ConsolidatedPageID] VARCHAR(MAX)
,[Fileid] VARCHAR(MAX)
,[hex_pageid] VARCHAR(MAX)
,[Pageid] VARCHAR(MAX)
)

IF (@Debug > 2) BEGIN
--select * from sys.fn_dblog(NULL, NULL)
--> http://db4breakfast.blogspot.com/2013/03/fndblog-function-documentation.html
--> IMPORTANT: [databasename] > Properties > Options > Recovery Model: Full
--> http://msdn.microsoft.com/en-us/library/ms189275.aspx --> Recovery Models (SQL Server)
--> http://technet.microsoft.com/en-us/library/ms189272.aspx
--> ALTER DATABASE model SET RECOVERY FULL
--> Immediately after switching from the simple recovery model to the full recovery model or bulk-logged recovery model, take a full or differential database backup to start the log chain.
--> The switch to the full or bulk-logged recovery model takes effect only after the first data backup.
SELECT name, recovery_model_desc
FROM sys.databases
WHERE name = 'model' ;

select 'Log file usage'
SELECT name AS [File Name],
physical_name AS [Physical Name],
size/128.0 AS [Total Size in MB],
size/128.0 - CAST(FILEPROPERTY(name, 'SpaceUsed') AS int)/128.0 AS [Available Space In MB],
[growth], [file_id]
,B.cntr_value as "LogFullPct"
FROM sys.database_files A
INNER JOIN sys.dm_os_performance_counters B ON RTRIM(B.instance_name)+'_log' = A.name
WHERE type_desc = 'LOG'
AND B.counter_name LIKE 'Percent Log Used%'
AND B.instance_name not in ('_Total', 'mssqlsystemresource')
--SELECT instance_name as [Database],cntr_value as "LogFullPct"
-- FROM sys.dm_os_performance_counters A
-- WHERE counter_name LIKE 'Percent Log Used%'
-- AND instance_name not in ('_Total', 'mssqlsystemresource')
-- AND cntr_value > 0;
END
IF (@Debug > 3) BEGIN
select 'sys.fn_dblog(NULL, NULL)'
--> LSN = Log Sequence Number
select [Current LSN],[Operation],[Context],[TRANSACTION ID],[Transaction Name],[Previous LSN],[AllocUnitId],[AllocUnitName],[Begin Time]
,[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4],SUSER_SNAME([Transaction SID]) AS [Transaction Account]
from sys.fn_dblog(NULL, NULL)
where [TRANSACTION ID] IN (SELECT DISTINCT [TRANSACTION ID] FROM sys.fn_dblog(NULL, NULL) WHERE [Transaction Name] IN ('UPDATE','DELETE','INSERT'))
order by [Current LSN]
--select * from sys.allocation_units
END

--> Get [TRANSACTION ID]s & [Transaction Name]s for INSERTs, DELETEs, UPDATEs in the time range
-- This includes: [Operation]s of ('LOP_MODIFY_ROW','LOP_MODIFY_COLUMNS','LOP_INSERT_ROWS','LOP_DELETE_ROWS')
/*Use this subquery to filter the date*/
SELECT DISTINCT [TRANSACTION ID],[Transaction Name],SUSER_SNAME([Transaction SID]) AS [Transaction Account]
INTO #TransIdAllList
FROM sys.fn_dblog(NULL, NULL)
WHERE [Context] IN ('LCX_NULL') AND [Operation] IN ('LOP_BEGIN_XACT')
AND [Transaction Name] IN ('UPDATE','INSERT','DELETE')
AND CONVERT(NVARCHAR(11),[Begin Time]) BETWEEN @Date_From AND @Date_To

--> Now remove all ('UPDATE','INSERT','DELETE')_transactions that are NOT ('LOP_MODIFY_ROW','LOP_MODIFY_COLUMNS','LOP_INSERT_ROWS','LOP_DELETE_ROWS')_transactions
DELETE FROM #TransIdAllList WHERE [TRANSACTION ID] IN
(SELECT DISTINCT [TRANSACTION ID]
--INTO #TransIdAllList
FROM sys.fn_dblog(NULL, NULL)
WHERE [TRANSACTION ID] IN (SELECT [TRANSACTION ID] FROM #TransIdAllList)
AND [Operation] NOT IN (NULL,'LOP_MODIFY_ROW','LOP_MODIFY_COLUMNS','LOP_INSERT_ROWS','LOP_DELETE_ROWS'))

--> Get [TRANSACTION ID]s for UPDATEs in time range; both 'LOP_MODIFY_ROW' & 'LOP_MODIFY_COLUMNS'
SELECT [TRANSACTION ID],[Transaction Name]
INTO #TransIdUpdateList
FROM #TransIdAllList
WHERE [Transaction Name] IN ('UPDATE')

--> Get [TRANSACTION ID]s for DELETEs in time range
-- WARNING: the @Date_To needs to include the DELETE for deleted UPDATEs
SELECT DISTINCT [TRANSACTION ID]
INTO #TransIdDeleteList
FROM #TransIdAllList
WHERE [Transaction Name] IN ('DELETE')

--> Get appropriate [Allocation_unit_id]s
SELECT [Allocation_unit_id]
INTO #AllocIdList
FROM sys.allocation_units allocunits
INNER JOIN sys.partitions partitions ON
(allocunits.type IN (1, 3) AND partitions.hobt_id = allocunits.container_id)
OR (allocunits.type = 2 AND partitions.partition_id = allocunits.container_id)
WHERE object_id=object_ID('' + @SchemaName_n_TableName + '')

--> Get the sys.fn_dblog record info for all transactions of concern
SELECT [Current LSN],[Operation],[Context],[PAGE ID],[AllocUnitId],[Slot ID],[TRANSACTION ID],[Transaction Name],[Begin Time],[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4],[Log Record Length],[Log Record Fixed Length],[Log Record]
INTO #SysFnDblog
FROM sys.fn_dblog(NULL, NULL)
WHERE [TRANSACTION ID] IN (SELECT [TRANSACTION ID] FROM #TransIdAllList)
--select * from #SysFnDblog

--> Get record info for deleted rows for UPDATEs that may have been deleted
SELECT [PAGE ID],[AllocUnitId],[Slot ID],[TRANSACTION ID],MAX([RowLog Contents 0]) AS [RowLog Contents 0] --> removes NULLs
INTO #DelRows
FROM #SysFnDblog
WHERE [Operation] IN ('LOP_DELETE_ROWS')
AND [AllocUnitId] IN (SELECT * FROM #AllocIdList)
AND [TRANSACTION ID] IN (SELECT * FROM #TransIdDeleteList)
GROUP BY [PAGE ID],[AllocUnitId],[Slot ID],[TRANSACTION ID]

IF (@Debug > 1) BEGIN
SELECT '#TransIdAllList'
SELECT * FROM #TransIdAllList
SELECT '#TransIdUpdateList'
SELECT * FROM #TransIdUpdateList
SELECT '#TransIdDeleteList'
SELECT * FROM #TransIdDeleteList
SELECT '#AllocIdList'
SELECT * FROM #AllocIdList
SELECT '#SysFnDblog '
SELECT * FROM #SysFnDblog
print 'select * from #DelRows'
SELECT '#DelRows'
SELECT * FROM #DelRows
END

DECLARE @ModifiedRawData TABLE(
[ID] INT IDENTITY(1,1)
,[PAGE ID] VARCHAR(MAX)
,[Slot ID] INT
,[AllocUnitId] BIGINT
,[Datum] VARCHAR(20)
,[TRANSACTION ID] VARCHAR(MAX)
,[Transaction Name] VARCHAR(MAX)
,[Current LSN] VARCHAR(MAX)
,[EntryID] INT DEFAULT -1
,[PrevEntry] INT DEFAULT -1
,[NextEntry] INT DEFAULT -1
,[ChainLevel] INT DEFAULT -1
,[Process] INT DEFAULT -1
,[Begin Time] DATETIME
,[RowLog Contents 0_var] VARCHAR(MAX)
,[RowLog Contents 0] VARBINARY(8000)
,[Slot Info] VARCHAR(MAX)
)

--> Get UPDATEd records information
INSERT INTO @ModifiedRawData ([PAGE ID],[Slot ID],[AllocUnitId],[Datum],[TRANSACTION ID],[Transaction Name],[Current LSN],[Begin Time],[RowLog Contents 0_var])
SELECT A.[PAGE ID],A.[Slot ID],A.[AllocUnitId],'Reference' AS [Datum],A.[TRANSACTION ID]
,(SELECT [Transaction Name] FROM #TransIdUpdateList WHERE [TRANSACTION ID] = A.[TRANSACTION ID]) AS [Transaction Name] --> always = 'UPDATE' here
,A.[Current LSN]
,(SELECT MAX([Begin Time]) FROM #SysFnDblog WHERE [TRANSACTION ID] = A.[TRANSACTION ID]) AS [Begin Time] --> eliminates NULL values
,NULL AS [Value] --> [RowLog Contents 0_var]
FROM #SysFnDblog A
WHERE A.[AllocUnitId] IN (SELECT * FROM #AllocIdList)
AND [Operation] IN ('LOP_MODIFY_ROW','LOP_MODIFY_COLUMNS')
AND [Context] IN ('LCX_HEAP','LCX_CLUSTERED')
AND [TRANSACTION ID] IN (SELECT [TRANSACTION ID] FROM #TransIdUpdateList)
GROUP BY A.[PAGE ID],A.[Slot ID],A.[AllocUnitId],[Begin Time],[Transaction ID],[Transaction Name],A.[Current LSN]
ORDER BY [Slot ID],[Current LSN] --> [Slot ID] is the record entry number
--SELECT * FROM @ModifiedRawData

--> Get the indexing information for DBCC PAGE
INSERT INTO @pageindex ([ConsolidatedPageID],[Fileid],[hex_pageid],[Pageid])
SELECT DISTINCT [PAGE ID],NULL,NULL,NULL FROM @ModifiedRawData
UPDATE @pageindex
SET [Fileid] = SUBSTRING([ConsolidatedPageID],0,CHARINDEX(':',[ConsolidatedPageID])) -- Seperate File ID from Page ID
, [hex_pageid] = '0x'+ SUBSTRING([ConsolidatedPageID],CHARINDEX(':',[ConsolidatedPageID])+1,LEN([ConsolidatedPageID])) -- Seperate the page ID
UPDATE @pageindex
SET [Pageid] = CONVERT(INT,CAST('' AS XML).value('xs:hexBinary(substring(sql:column("[hex_pageid]"),sql:column("t.pos")) )', 'varbinary(max)')) -- Convert Page ID from hex to integer
FROM (SELECT CASE SUBSTRING([hex_pageid], 1, 2) WHEN '0x' THEN 3 ELSE 0 END FROM @pageindex A WHERE A.[PageIndexID] = [PageIndexID]) AS t(pos)
--SELECT * FROM @pageindex

/*******************CURSOR START*********************/
--> Get DBCC PAGE data for each [ConsolidatedPageID]
DECLARE Page_Data_Cursor CURSOR FOR
SELECT [Fileid],[Pageid]
FROM @pageindex
ORDER BY [Fileid],[Pageid]
/****************************************/
OPEN Page_Data_Cursor

FETCH NEXT FROM Page_Data_Cursor INTO @Fileid,@Pageid
WHILE @@FETCH_STATUS = 0
BEGIN
DELETE @temppagedata
--> the next line requires cursor use due to augument requirements
INSERT INTO @temppagedata EXEC( 'DBCC PAGE(' + @DataBase_Name + ', ' + @Fileid + ', ' + @Pageid + ', 3) with tableresults,no_infomsgs;')
--> Concatenante all DBCC PAGE pages into one file by [ConsolidatedPageID] using index [PageIndexID]
INSERT INTO @pagedata ([Page Index],[DBCCid],[ParentObject],[Object],[Field],[Value])
SELECT B.[PageIndexID],A.[RecordID],[ParentObject],[Object],[Field],[Value]
FROM @temppagedata A
JOIN @pageindex B ON B.[Pageid] = @Pageid AND B.[Fileid] = @Fileid
FETCH NEXT FROM Page_Data_Cursor INTO @Fileid,@Pageid
END

CLOSE Page_Data_Cursor
DEALLOCATE Page_Data_Cursor
/*******************CURSOR END*********************/

--> Add the DBCC PAGE information OR DELETEd info to the UPDATEd records information
-- DBCC PAGE indexing is independent of [AllocUnitId]
UPDATE @ModifiedRawData
SET
[RowLog Contents 0_var] =
COALESCE( --> look for DBCC PAGE record set
UPPER((SELECT REPLACE(STUFF(
(SELECT REPLACE(SUBSTRING([VALUE],CHARINDEX(':',[Value])+1,48),'†','')
FROM @pagedata C
WHERE B.[Page Index] = C.[Page Index] --> EQUIVALENT to [ConsolidatedPageID]
AND A.[Slot ID] = LTRIM(RTRIM(SUBSTRING(C.[ParentObject],5,3)))
AND [Object] LIKE '%Memory Dump%'
GROUP BY [Value] FOR XML PATH('')
),1,1,'') ,' ','')
)) --> next, look for deleted record
,UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("C.[RowLog Contents 0]") )', 'varchar(max)'))
,'ERROR: '+B.[ParentObject] --> Missing [Slot ID] in "DBCC PAGE", and no corresponding DELETE found
)
,[Slot Info] = COALESCE(B.[ParentObject],'Slot '+CONVERT(VARCHAR,C.[Slot ID])+' deleted')
FROM @ModifiedRawData A
INNER JOIN @pageindex D ON D.[ConsolidatedPageID] = A.[PAGE ID]
LEFT JOIN @pagedata B ON
B.[Page Index] = D.[PageIndexID]
AND A.[Slot ID] = LTRIM(RTRIM(SUBSTRING(B.[ParentObject],5,3)))
AND B.[Object] LIKE '%Memory Dump%'
LEFT JOIN #DelRows C ON
C.[PAGE ID]=[A].[PAGE ID]
AND C.[AllocUnitId] = A.[AllocUnitId]
AND C.[Slot ID] = A.[Slot ID]

--> Convert the old data which is in string format to hex format (required).
UPDATE @ModifiedRawData SET [RowLog Contents 0] = CAST('' AS XML).value('xs:hexBinary(substring(sql:column("[RowLog Contents 0_var]"), 0) )', 'varbinary(max)')
FROM @ModifiedRawData

IF (@Debug > 0) BEGIN
select '@pageindex'
select * from @pageindex
select '@DBCC PAGE'
select * from @temppagedata
select '@pagedata'
select * from @pagedata --ORDER BY [Page ID],[AllocUnitId],[Current LSN],[DBCCid]
print 'select * from @ModifiedRawData1'
select '@ModifiedRawData1'
select * from @ModifiedRawData
END

DECLARE @PreliminaryRawData TABLE(
[ID] INT IDENTITY(1,1)
,[PAGE ID] VARCHAR(MAX)
,[Slot ID] INT
,[AllocUnitId] BIGINT
,[Datum] VARCHAR(20)
,[TRANSACTION ID] VARCHAR(MAX)
,[Transaction Name] VARCHAR(MAX)
,[Current LSN] VARCHAR(MAX)
,[Begin Time] DATETIME
,[RowLog Contents 0] VARBINARY(8000)
,[RowLog Contents 1] VARBINARY(8000)
,[RowLog Contents 2] VARBINARY(8000)
,[RowLog Contents 3] VARBINARY(8000)
,[RowLog Contents 4] VARBINARY(8000)
,[Log Record] VARBINARY(8000)
,[Operation] VARCHAR(MAX)
,[RowLog Contents 0_var] VARCHAR(MAX)
,[RowLog Contents 1_var] VARCHAR(MAX)
)

---Now we have the modifed data plus its slot ID , page ID and allocunit as well.
--After that we need to get the old values before modfication, these data are in chunks.
INSERT INTO @PreliminaryRawData
SELECT [PAGE ID],[Slot ID],[AllocUnitId],'Restoration' AS [Datum],[TRANSACTION ID]
,(SELECT [Transaction Name] FROM #TransIdAllList WHERE [TRANSACTION ID] = A.[TRANSACTION ID]) AS [Transaction Name]
,[Current LSN]
,(SELECT MAX([Begin Time]) FROM #SysFnDblog WHERE [TRANSACTION ID] = A.[TRANSACTION ID]) AS [Begin Time] --> eliminates NULL values
,[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4]
,SUBSTRING ([Log Record],[Log Record Fixed Length],([Log Record Length]+1)-([Log Record Fixed Length])) as [Log Record]
,[Operation]
,UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("[RowLog Contents 0]") )', 'varchar(max)')) AS [RowLog Contents 0_var] --> New, added for reference; integrated below
,UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("[RowLog Contents 1]") )', 'varchar(max)')) AS [RowLog Contents 1_var] --> New, added for reference; integrated below
FROM #SysFnDblog A
WHERE [AllocUnitId] IN (SELECT * FROM #AllocIdList)
AND [Operation] IN ('LOP_MODIFY_ROW','LOP_MODIFY_COLUMNS','LOP_INSERT_ROWS','LOP_DELETE_ROWS')
AND [Context] IN ('LCX_HEAP','LCX_CLUSTERED')
--AND [TRANSACTION ID] IN (SELECT [TRANSACTION ID] FROM #TransIdAllList) --> same filter for #SysFnDblog
ORDER BY [Slot ID],[Transaction ID] DESC
--SELECT * FROM @PreliminaryRawData
/*
If the [Operation] Type is 'LOP_MODIFY_ROW' then it is very simple to recover the modified data. The old data is in [RowLog Contents 0] Field and modified data is in [RowLog Contents 1] Field. Simply replace it with the modified data and get the old data.
If the [Operation] Type is 'LOP_INSERT_ROWS' or 'LOP_DELETE_ROWS' then it is very simple to recover the data. The old data is in [RowLog Contents 0] Field.
*/
INSERT INTO @ModifiedRawData ([PAGE ID],[Slot ID],[AllocUnitId],[Datum],[TRANSACTION ID],[Transaction Name],[Current LSN],[Begin Time],[RowLog Contents 0_var],[Slot Info])
SELECT A.[PAGE ID],A.[Slot ID],A.[AllocUnitId],'Restoration' AS [Datum],A.[TRANSACTION ID],A.[Transaction Name],A.[Current LSN],A.[Begin Time]
,CASE WHEN A.[Operation] IN ('LOP_INSERT_ROWS','LOP_DELETE_ROWS') THEN
(SELECT UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("A.[RowLog Contents 0]") )','varchar(max)'))) --> for INSERTs and/or DELETEs with no UPDATEs (@ModifiedRawData is empty when this update starts)
ELSE --> look for the UPDATE mate from the previous record pull
REPLACE(UPPER(B.[RowLog Contents 0_var]),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("A.[RowLog Contents 1]") )','varchar(max)')),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("A.[RowLog Contents 0]") )','varchar(max)')))
END AS [RowLog Contents 0_var]
,B.[Slot Info]
FROM @PreliminaryRawData A
LEFT JOIN @ModifiedRawData B ON B.[Current LSN]=A.[Current LSN]
WHERE A.[Operation] IN ('LOP_MODIFY_ROW','LOP_INSERT_ROWS','LOP_DELETE_ROWS')

-- Convert the old data which is in string format to hex format (required).
UPDATE @ModifiedRawData SET [RowLog Contents 0] = CAST('' AS XML).value('xs:hexBinary(substring(sql:column("[RowLog Contents 0_var]"), 0) )', 'varbinary(max)')
FROM @ModifiedRawData
WHERE [RowLog Contents 0] IS NULL

IF (@Debug > 0) BEGIN
select '@PreliminaryRawData'
select * from @PreliminaryRawData
print 'select * from @ModifiedRawData2_row_ops'
select '@ModifiedRawData2_row_ops'
select * from @ModifiedRawData
END
--> remove these records since their processing is complete
--DELETE FROM @PreliminaryRawData WHERE [Operation] IN ('LOP_MODIFY_ROW','LOP_INSERT_ROWS','LOP_DELETE_ROWS')
DELETE FROM @PreliminaryRawData WHERE [Operation] IN ('LOP_INSERT_ROWS','LOP_DELETE_ROWS')
IF (@Debug > 0) BEGIN
print 'select * from @PreliminaryRawData_remaining'
select '@PreliminaryRawData_remaining'
select * from @PreliminaryRawData
END

/*******************CURSOR START*********************/
---Now we have modifed data plus its slot ID , page ID and allocunit as well.
--After that we need to get the old values before modfication, these data are in chunks.
IF (@Debug = 0) BEGIN
DECLARE Page_Data_Cursor CURSOR FOR
SELECT [PAGE ID],[Slot ID],[AllocUnitId],[TRANSACTION ID],[Transaction Name],[Current LSN],[Begin Time],[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4],[Log Record],[Operation]
FROM @PreliminaryRawData
WHERE [Operation] IN ('LOP_MODIFY_COLUMNS')
ORDER BY [Slot ID],[TRANSACTION ID] DESC
END
ELSE
BEGIN
DECLARE Page_Data_Cursor CURSOR FOR
SELECT [PAGE ID],[Slot ID],[AllocUnitId],[TRANSACTION ID],[Transaction Name],[Current LSN],[Begin Time],[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4],[Log Record],[Operation]
FROM @PreliminaryRawData
ORDER BY [Slot ID],[TRANSACTION ID] DESC
END

/****************************************/

OPEN Page_Data_Cursor

FETCH NEXT FROM Page_Data_Cursor INTO @ConsolidatedPageID,@Slotid,@AllocUnitID,@TransactionID,@TransactionName,@CurrentLSN,@BeginTime,@RowLogContents0,@RowLogContents1,@RowLogContents2,@RowLogContents3,@RowLogContents4,@LogRecord,@Operation
WHILE @@FETCH_STATUS = 0
BEGIN
IF @Operation IN ('LOP_MODIFY_ROW','LOP_INSERT_ROWS','LOP_DELETE_ROWS')
BEGIN
-- To see the debug printout, comment out the "DELETE FROM @PreliminaryRawData..." line above
IF (@Debug > 1) BEGIN
PRINT 'ConsolidatedPageID = '+@ConsolidatedPageID
PRINT 'Slotid = '+CONVERT(nvarchar,@Slotid)
PRINT 'AllocUnitID = '+CONVERT(nvarchar,@AllocUnitID)
PRINT 'TransactionID = '+@TransactionID
PRINT 'BeginTime = '+CONVERT(nvarchar,@BeginTime,121)
PRINT 'TransactionName = '+@TransactionName
DECLARE @RowLogContents0_var VARCHAR(MAX)
DECLARE @RowLogContents1_var VARCHAR(MAX)
SET @RowLogContents0_var=(SELECT UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents0") )', 'varchar(max)')))
SET @RowLogContents1_var=(SELECT UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents1") )', 'varchar(max)')))
PRINT 'RowLogContents0 = '+@RowLogContents0_var
PRINT 'RowLogContents1 = '+@RowLogContents1_var
IF (@TransactionName='UPDATE') BEGIN
DECLARE @RowLogContents0_var1 VARCHAR(MAX)
DECLARE @RowLogContents0_var2 VARCHAR(MAX)
DECLARE @RowLogContents1_var0 VARCHAR(MAX)
DECLARE @RowLogContents0_var0 VARCHAR(MAX)
SET @RowLogContents0_var1=(SELECT [RowLog Contents 0_var]
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN AND [Datum]='Reference')
SET @RowLogContents1_var0=(SELECT UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents1") )','varchar(max)'))
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN AND [Datum]='Reference')
SET @RowLogContents0_var0=(SELECT UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents0") )','varchar(max)'))
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN AND [Datum]='Reference')
SET @RowLogContents0_var2=(SELECT REPLACE(UPPER([RowLog Contents 0_var]),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents1") )','varchar(max)')),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents0") )','varchar(max)')))
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN AND [Datum]='Reference')
PRINT 'RowLogContents0_var1 = '+@RowLogContents0_var1
PRINT 'RowLogContents1_var0 = '+@RowLogContents1_var0
PRINT 'RowLogContents0_var0 = '+@RowLogContents0_var0
PRINT 'RowLogContents0_var2 = '+@RowLogContents0_var2
PRINT 'RowLogContents0_var2a= '+REPLACE(@RowLogContents0_var1,@RowLogContents1_var0,@RowLogContents0_var0)
END
PRINT ''
--DECLARE @LSN VARCHAR(50)
--DECLARE @LSN0 VARCHAR(50)
--DECLARE @LSN1 VARCHAR(50)
--DECLARE @LSN2 VARCHAR(50)
--DECLARE @LSN_int1 INTEGER
--DECLARE @LSN_int2 INTEGER
--SET @LSN=CONVERT(VARCHAR,@CurrentLSN)
--SET @LSN_int1=CHARINDEX(':',@LSN,1)
--SET @LSN_int2=CHARINDEX(':',@LSN,@LSN_int1+1)
--SET @LSN0=SUBSTRING(@LSN,1,@LSN_int1-1)
--SET @LSN1=SUBSTRING(@LSN,@LSN_int1+1,@LSN_int2-@LSN_int1-1)
--SET @LSN2=SUBSTRING(@LSN,@LSN_int2+1,LEN(@LSN))
--PRINT 'CurrentLSN='+@LSN0+':'+@LSN1+':'+@LSN2

--> SQL2005:CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),1,8))','varbinary(max)') == SQL2008:CONVERT(VARBINARY,SUBSTRING(@CurrentLSN,1,8),2)
--DECLARE @str VARCHAR(50)
--SET @str=CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),1,8))','varbinary(max)')))+':'+
-- CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),10,8))','varbinary(max)')))+':'+
-- CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),19,4))','varbinary(max)')))
--PRINT 'CurrentLSN_base10='+@str
--DECLARE @int BIGINT
--SET @int=CONVERT(BIGINT,CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),1,8))','varbinary(max)')))+
-- RIGHT('0000000000'+CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),10,8))','varbinary(max)'))),10)+
-- RIGHT('00000'+CONVERT(VARCHAR,CONVERT(INT,CAST('' as xml).value('xs:hexBinary(substring(sql:variable("@CurrentLSN"),19,4))','varbinary(max)'))),5) )
--PRINT 'CurrentLSN_int='+CONVERT(VARCHAR,@int)
END
END

IF @Operation ='LOP_MODIFY_COLUMNS'
BEGIN

/* If the @Operation Type is 'LOP_MODIFY_ROW' then we need to follow a different procedure to recover modified
.Because this time the data is also in chunks but merge with the data log.
*/
--First, we need to get the [RowLog Contents 3] Because in [Log Record] field the modified data is available after the [RowLog Contents 3] data.
SET @RowLogContents3_Var = CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents3") )', 'varchar(max)')
SET @LogRecord_Var = CAST('' AS XML).value('xs:hexBinary(sql:variable("@LogRecord"))', 'varchar(max)')

---First get the modifed data chunks in string format
SET @RowLogData_Var = SUBSTRING(@LogRecord_Var, CHARINDEX(@RowLogContents3_Var,@LogRecord_Var)+LEN(@RowLogContents3_Var) ,LEN(@LogRecord_Var))
--Then convert it into the hex values.
SELECT @RowLogData_Hex = CAST('' AS XML).value('xs:hexBinary( substring(sql:variable("@RowLogData_Var"),0) )', 'varbinary(max)')
FROM (SELECT CASE SUBSTRING(@RowLogData_Var, 1, 2)WHEN '0x' THEN 3 ELSE 0 END) AS t(pos)

-- Before recovering the modfied data we need to get the total fixed length data size and start position of the varaible data

SELECT @TotalFixedLengthData = CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2))))
,@VariableLength_Offset_Start = CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2))))+5+CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2)))) + 1, 2))))/8.0))
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN

SET @FixedLength_Offset = CONVERT(BINARY(2),REVERSE(CONVERT(BINARY(4),(@RowLogContents0))))--)
SET @VariableLength_Offset = CONVERT(INT,CONVERT(BINARY(2),REVERSE(@RowLogContents0)))

/* We already have modified data chunks in @RowLogData_Hex but this data is in merge format (modified plus actual data)
So , here we need [Row Log Contents 1] field , because in this field we have the data length both the modified and actual data
so this length will help us to break it into original and modified data chunks.
*/
SET @FixedLength_Loc = CONVERT(INT,SUBSTRING(@RowLogContents1,1,1))
SET @VariableLength_Loc = CONVERT(INT,SUBSTRING(@RowLogContents1,3,1))

/*First , we need to break Fix length data actual with the help of data length */
SET @OldFixedLengthStartPosition= CHARINDEX(@RowLogContents4,@RowLogData_Hex)
SET @FixedOldValues = SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition,@FixedLength_Loc)
SET @FixedLengthIncrease = (CASE WHEN (Len(@FixedOldValues)%4) = 0 THEN 1 ELSE (4-(LEN(@FixedOldValues)%4)) END)
/*After that , we need to break Fix length data modified data with the help of data length */
SET @FixedNewValues =SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease,@FixedLength_Loc)

/*Same we need to break the variable data with the help of data length*/
SET @VariableOldValues =SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease+@FixedLength_Loc+(@FixedLengthIncrease),@VariableLength_Loc)
SET @VariableLengthIncrease = (CASE WHEN (LEN(@VariableOldValues)%4) = 0 THEN 1 ELSE (4-(Len(@VariableOldValues)%4))+1 END)
SET @VariableOldValues = (Case When @VariableLength_Loc = 1 Then @VariableOldValues+0x00 else @VariableOldValues end)

SET @VariableNewValues = SUBSTRING(SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease+@FixedLength_Loc+(@FixedLengthIncrease-1)+@VariableLength_Loc+@VariableLengthIncrease,Len(@RowLogData_Hex)+1),1,Len(@RowLogData_Hex)+1) --LEN(@VariableOldValues)

/*here we need to replace the fixed length & variable length actaul data with modifed data
*/

SELECT @VariableNewValues=CASE
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)+1),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)+1)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues) ),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues))
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-1),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-1)--3 --Substring(@VariableNewValues,0,Len(@VariableNewValues)-1)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-2),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-2)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-3),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-3) --5--Substring(@VariableNewValues,0,Len(@VariableNewValues)-3)
END
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN

INSERT INTO @ModifiedRawData ([PAGE ID],[Slot ID],[AllocUnitId],[Datum],[TRANSACTION ID],[Transaction Name],[Current LSN],[Begin Time],[RowLog Contents 0_var],[RowLog Contents 0],[Slot Info])
SELECT @ConsolidatedPageID AS [PAGE ID],@Slotid AS [Slot ID],@AllocUnitID AS [AllocUnitId],'Restoration' AS [Datum],@TransactionID AS [TRANSACTION ID],@TransactionName AS [Transaction Name],@CurrentLSN AS [Current LSN],@BeginTime AS [Begin Time]
,NULL --> [RowLog Contents 0_var]
,ISNULL( --> due to chained updates; this only works on the most recent update
CAST(REPLACE(SUBSTRING([RowLog Contents 0],0,@TotalFixedLengthData+1),@FixedNewValues, @FixedOldValues) AS VARBINARY(max))
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2)
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 3, CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2))))/8.0)))
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 3 + CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2))))/8.0)), 2)
+ SUBSTRING([RowLog Contents 0],@VariableLength_Offset_Start,(@VariableLength_Offset-(@VariableLength_Offset_Start-1)))
+ CAST(REPLACE(SUBSTRING([RowLog Contents 0],@VariableLength_Offset+1,Len(@VariableNewValues))
,@VariableNewValues,@VariableOldValues) AS VARBINARY)
+ Substring([RowLog Contents 0],@VariableLength_Offset+Len(@VariableNewValues)+1,LEN([RowLog Contents 0]))
,[RowLog Contents 0]) --> [RowLog Contents 0]
,[Slot Info]
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN

--> Convert the old data which is in hex format to string format (not required).
UPDATE @ModifiedRawData SET [RowLog Contents 0_var] = CAST('' AS XML).value('xs:hexBinary(sql:column("[RowLog Contents 0]") )', 'varchar(max)')
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN
END

FETCH NEXT FROM Page_Data_Cursor INTO @ConsolidatedPageID,@Slotid,@AllocUnitID,@TransactionID,@TransactionName,@CurrentLSN,@BeginTime,@RowLogContents0,@RowLogContents1,@RowLogContents2,@RowLogContents3,@RowLogContents4,@LogRecord,@Operation
END

CLOSE Page_Data_Cursor
DEALLOCATE Page_Data_Cursor
/*******************CURSOR END*********************/
------------------------------------------------------------------------------------------------------------
DECLARE @ModRawDataLoop INT
--> Add sequence index number(s)
UPDATE A SET [EntryID] = B.[index] FROM @ModifiedRawData A
JOIN (SELECT ROW_NUMBER() OVER (ORDER BY [Current LSN],[Datum] DESC) AS [index], [ID] FROM @ModifiedRawData) B ON
B.[ID] = A.[ID]
--> Add backward reference(s) and forward reference(s)
UPDATE A SET
[PrevEntry] =
ISNULL((SELECT MAX(B.[EntryID]) AS [EntryID] FROM @ModifiedRawData B
WHERE B.[Slot ID] = A.[Slot ID] AND B.[EntryID] < A.[EntryID]),0)
,[NextEntry] =
ISNULL((SELECT MIN(B.[EntryID]) AS [EntryID] FROM @ModifiedRawData B
WHERE B.[Slot ID] = A.[Slot ID] AND B.[EntryID] > A.[EntryID]),0)
FROM @ModifiedRawData A
--> Add chain level(s)
UPDATE A SET [ChainLevel] = B.[index] FROM @ModifiedRawData A
JOIN (SELECT DENSE_RANK() OVER (PARTITION BY [SLOT ID] ORDER BY [Current LSN])-1 AS [index], [ID] FROM @ModifiedRawData) B ON
B.[ID] = A.[ID]
--> Set the process order(s) --> the reverse of the [ChainLevel]
UPDATE A SET
[Process] = CASE WHEN ([ChainLevel] = 0) THEN 0
ELSE (SELECT MAX([ChainLevel]) FROM @ModifiedRawData B WHERE B.[Slot ID] = A.[Slot ID]) - [ChainLevel]
END
FROM @ModifiedRawData A
--select * from @ModifiedRawData order by [EntryID]

--> Get the chained UPDATE records (forward in time) to locate the replaced "Reference" record(s) (chained UPDATEs)
SELECT B.* INTO #T1
FROM @ModifiedRawData A
INNER JOIN @ModifiedRawData B ON B.[Transaction Name] = 'UPDATE'
AND B.[NextEntry] = A.[EntryID]
AND B.[Datum] = 'Reference' AND A.[Datum] = 'Restoration'
--AND B.[Current LSN] <> A.[Current LSN] --> should always be true
SET @ModRawDataLoop = @@ROWCOUNT
--select * from #T1

IF (@ModRawDataLoop > 0) BEGIN
WHILE (@ModRawDataLoop > 0) BEGIN
/*
If the [Operation] Type is 'LOP_MODIFY_ROW' then it is very simple to recover the modified data. The old data is in [RowLog Contents 0] Field and modified data is in [RowLog Contents 1] Field. Simply replace it with the modified data and get the old data.
*/
--> First, change the byte of [RowLog Contents 0_var] that may differ from the first byte of [RowLog Contents 1_var] (I don't know why these don't match sometimes)
--> Fix the copy before it is restored back into the applicable records (next)
UPDATE #T1 SET
[RowLog Contents 0_var] =
SUBSTRING(B.[RowLog Contents 0_var],1,PATINDEX('%'+SUBSTRING(A.[RowLog Contents 1_var],3,LEN(A.[RowLog Contents 1_var]))+'%',B.[RowLog Contents 0_var])-3)
+SUBSTRING(A.[RowLog Contents 1_var],1,2)
+SUBSTRING(B.[RowLog Contents 0_var],PATINDEX('%'+SUBSTRING(A.[RowLog Contents 1_var],3,LEN(A.[RowLog Contents 1_var]))+'%',B.[RowLog Contents 0_var]),LEN(B.[RowLog Contents 0_var]))
,[RowLog Contents 0] =
SUBSTRING(B.[RowLog Contents 0],1,PATINDEX('%'+SUBSTRING(A.[RowLog Contents 1_var],3,LEN(A.[RowLog Contents 1_var]))+'%',B.[RowLog Contents 0_var])/2-1)
+SUBSTRING(A.[RowLog Contents 1],1,1)
+SUBSTRING(B.[RowLog Contents 0],PATINDEX('%'+SUBSTRING(A.[RowLog Contents 1_var],3,LEN(A.[RowLog Contents 1_var]))+'%',B.[RowLog Contents 0_var])/2+1,LEN(B.[RowLog Contents 0]))
FROM @PreliminaryRawData A
INNER JOIN #T1 C ON C.[Current LSN] = A.[Current LSN]
INNER JOIN @ModifiedRawData B ON B.[EntryID] = C.[NextEntry] --> source location
WHERE A.[Operation] IN ('LOP_MODIFY_ROW') AND C.[Process] = 1
--select * from #T1
--> Restore (one level) the replaced (and therefore lost) "Reference" information (chained UPDATEs)
-- for both the "Reference" and "Restoration" records, and the original source record
UPDATE @ModifiedRawData SET
[RowLog Contents 0_var] = B.[RowLog Contents 0_var]
,[RowLog Contents 0] = B.[RowLog Contents 0]
FROM @ModifiedRawData A
INNER JOIN #T1 B ON A.[EntryID] IN (B.[EntryID],B.[PrevEntry],B.[NextEntry])
WHERE B.[Process] = 1
--select * from @ModifiedRawData order by [EntryID]
--> Now, the substitution will work, so update [RowLog Contents 0_var]
UPDATE @ModifiedRawData SET
[RowLog Contents 0_var] =
--> look for the UPDATE mate from the previous record pull
REPLACE(UPPER(B.[RowLog Contents 0_var]),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("A.[RowLog Contents 1]") )','varchar(max)')),UPPER(CAST('' AS XML).value('xs:hexBinary(sql:column("A.[RowLog Contents 0]") )','varchar(max)')))
,[RowLog Contents 0] = NULL
FROM @PreliminaryRawData A
INNER JOIN @ModifiedRawData B ON B.[Current LSN]=A.[Current LSN]
INNER JOIN #T1 C ON C.[PrevEntry] = B.[EntryID]
WHERE A.[Operation] IN ('LOP_MODIFY_ROW') AND B.[Process] = 1

-- Convert the old data which is in string format to hex format (required).
UPDATE @ModifiedRawData SET
[RowLog Contents 0] = CAST('' AS XML).value('xs:hexBinary(substring(sql:column("[RowLog Contents 0_var]"), 0) )', 'varbinary(max)')
FROM @ModifiedRawData
WHERE [RowLog Contents 0] IS NULL
SET @ModRawDataLoop = @@ROWCOUNT
--print '@ModRawDataLoop (LOP_MODIFY_ROW)= '+CONVERT(varchar,@ModRawDataLoop)
--select * from @ModifiedRawData order by [EntryID]

/*******************CURSOR START*********************/
---Now we have modifed data plus its slot ID , page ID and allocunit as well.
--After that we need to get the old values before modfication, these data are in chunks.
DECLARE Page_Data_Cursor CURSOR FOR
SELECT A.[PAGE ID],A.[Slot ID],A.[AllocUnitId],A.[TRANSACTION ID],A.[Transaction Name],A.[Current LSN],A.[Begin Time],A.[RowLog Contents 0],[RowLog Contents 1],[RowLog Contents 2],[RowLog Contents 3],[RowLog Contents 4],[Log Record],[Operation]
FROM @PreliminaryRawData A
INNER JOIN @ModifiedRawData B ON B.[Current LSN] = A.[Current LSN] --> skip this section if there are no updates
WHERE [Operation] IN ('LOP_MODIFY_COLUMNS') AND B.[Process] = 1 AND B.[Datum] = 'Restoration'
ORDER BY A.[Slot ID],A.[TRANSACTION ID] DESC

SET @ModRawDataLoop = 0
/****************************************/

OPEN Page_Data_Cursor

FETCH NEXT FROM Page_Data_Cursor INTO @ConsolidatedPageID,@Slotid,@AllocUnitID,@TransactionID,@TransactionName,@CurrentLSN,@BeginTime,@RowLogContents0,@RowLogContents1,@RowLogContents2,@RowLogContents3,@RowLogContents4,@LogRecord,@Operation
WHILE @@FETCH_STATUS = 0
BEGIN
--IF @Operation ='LOP_MODIFY_COLUMNS'
BEGIN

/* If the @Operation Type is 'LOP_MODIFY_ROW' then we need to follow a different procedure to recover modified
.Because this time the data is also in chunks but merge with the data log.
*/
--First, we need to get the [RowLog Contents 3] Because in [Log Record] field the modified data is available after the [RowLog Contents 3] data.
SET @RowLogContents3_Var = CAST('' AS XML).value('xs:hexBinary(sql:variable("@RowLogContents3") )', 'varchar(max)')
SET @LogRecord_Var = CAST('' AS XML).value('xs:hexBinary(sql:variable("@LogRecord"))', 'varchar(max)')

---First get the modifed data chunks in string format
SET @RowLogData_Var = SUBSTRING(@LogRecord_Var, CHARINDEX(@RowLogContents3_Var,@LogRecord_Var)+LEN(@RowLogContents3_Var) ,LEN(@LogRecord_Var))
--Then convert it into the hex values.
SELECT @RowLogData_Hex = CAST('' AS XML).value('xs:hexBinary( substring(sql:variable("@RowLogData_Var"),0) )', 'varbinary(max)')
FROM (SELECT CASE SUBSTRING(@RowLogData_Var, 1, 2)WHEN '0x' THEN 3 ELSE 0 END) AS t(pos)

-- Before recovering the modfied data we need to get the total fixed length data size and start position of the varaible data

SELECT @TotalFixedLengthData = CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2))))
,@VariableLength_Offset_Start = CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2))))+5+CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0] , 2 + 1, 2)))) + 1, 2))))/8.0))
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN

SET @FixedLength_Offset = CONVERT(BINARY(2),REVERSE(CONVERT(BINARY(4),(@RowLogContents0))))--)
SET @VariableLength_Offset = CONVERT(INT,CONVERT(BINARY(2),REVERSE(@RowLogContents0)))

/* We already have modified data chunks in @RowLogData_Hex but this data is in merge format (modified plus actual data)
So , here we need [Row Log Contents 1] field , because in this field we have the data length both the modified and actual data
so this length will help us to break it into original and modified data chunks.
*/
SET @FixedLength_Loc = CONVERT(INT,SUBSTRING(@RowLogContents1,1,1))
SET @VariableLength_Loc = CONVERT(INT,SUBSTRING(@RowLogContents1,3,1))

/*First , we need to break Fix length data actual with the help of data length */
SET @OldFixedLengthStartPosition= CHARINDEX(@RowLogContents4,@RowLogData_Hex)
SET @FixedOldValues = SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition,@FixedLength_Loc)
SET @FixedLengthIncrease = (CASE WHEN (Len(@FixedOldValues)%4) = 0 THEN 1 ELSE (4-(LEN(@FixedOldValues)%4)) END)
/*After that , we need to break Fix length data modified data with the help of data length */
SET @FixedNewValues =SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease,@FixedLength_Loc)

/*Same we need to break the variable data with the help of data length*/
SET @VariableOldValues =SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease+@FixedLength_Loc+(@FixedLengthIncrease),@VariableLength_Loc)
SET @VariableLengthIncrease = (CASE WHEN (LEN(@VariableOldValues)%4) = 0 THEN 1 ELSE (4-(Len(@VariableOldValues)%4))+1 END)
SET @VariableOldValues = (Case When @VariableLength_Loc = 1 Then @VariableOldValues+0x00 else @VariableOldValues end)

SET @VariableNewValues = SUBSTRING(SUBSTRING(@RowLogData_Hex,@OldFixedLengthStartPosition+@FixedLength_Loc+@FixedLengthIncrease+@FixedLength_Loc+(@FixedLengthIncrease-1)+@VariableLength_Loc+@VariableLengthIncrease,Len(@RowLogData_Hex)+1),1,Len(@RowLogData_Hex)+1) --LEN(@VariableOldValues)

/*here we need to replace the fixed length & variable length actaul data with modifed data
*/

SELECT @VariableNewValues=CASE
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)+1),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)+1)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues) ),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues))
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-1),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-1)--3 --Substring(@VariableNewValues,0,Len(@VariableNewValues)-1)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-2),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-2)
WHEN Charindex(Substring(@VariableNewValues,0,Len(@VariableNewValues)-3),[RowLog Contents 0])<>0 Then Substring(@VariableNewValues,0,Len(@VariableNewValues)-3) --5--Substring(@VariableNewValues,0,Len(@VariableNewValues)-3)
END
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN

UPDATE @ModifiedRawData SET
[RowLog Contents 0] =
CAST(REPLACE(SUBSTRING([RowLog Contents 0],0,@TotalFixedLengthData+1),@FixedNewValues, @FixedOldValues) AS VARBINARY(max))
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2)
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 3, CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2))))/8.0)))
+ SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 3 + CONVERT(INT, ceiling(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], @TotalFixedLengthData + 1, 2))))/8.0)), 2)
+ SUBSTRING([RowLog Contents 0],@VariableLength_Offset_Start,(@VariableLength_Offset-(@VariableLength_Offset_Start-1)))
+ CAST(REPLACE(SUBSTRING([RowLog Contents 0],@VariableLength_Offset+1,Len(@VariableNewValues))
,@VariableNewValues,@VariableOldValues) AS VARBINARY)
+ Substring([RowLog Contents 0],@VariableLength_Offset+Len(@VariableNewValues)+1,LEN([RowLog Contents 0]))
,[RowLog Contents 0_var] = NULL
FROM @ModifiedRawData
WHERE [Current LSN]=@CurrentLSN AND [Process] = 1 AND [Datum] = 'Restoration'

--> Convert the old data which is in hex format to string format (not required).
UPDATE @ModifiedRawData SET [RowLog Contents 0_var] = CAST('' AS XML).value('xs:hexBinary(sql:column("[RowLog Contents 0]") )', 'varchar(max)')
FROM @ModifiedRawData
WHERE [RowLog Contents 0_var] IS NULL
SET @ModRawDataLoop = @ModRawDataLoop + @@ROWCOUNT

END

FETCH NEXT FROM Page_Data_Cursor INTO @ConsolidatedPageID,@Slotid,@AllocUnitID,@TransactionID,@TransactionName,@CurrentLSN,@BeginTime,@RowLogContents0,@RowLogContents1,@RowLogContents2,@RowLogContents3,@RowLogContents4,@LogRecord,@Operation
END
--print '@ModRawDataLoop (LOP_MODIFY_COLUMNS)= '+CONVERT(varchar,@ModRawDataLoop)

CLOSE Page_Data_Cursor
DEALLOCATE Page_Data_Cursor
/*******************CURSOR END*********************/
--select * from @ModifiedRawData order by [EntryID]

--> Update the process order
UPDATE #T1 SET [Process] = [Process] - 1
FROM #T1
WHERE [Process] > 0
SET @ModRawDataLoop = (SELECT COUNT(*) FROM #T1 WHERE [Process] > 0)
--print '@ModRawDataLoop (remaining)= '+CONVERT(varchar,@ModRawDataLoop)

IF (@ModRawDataLoop > 0) BEGIN
--> Update the process order
UPDATE @ModifiedRawData SET [Process] = [Process] - 1
FROM @ModifiedRawData
WHERE [Process] > 0

--> Now look ahead and get (temporarily store) the replaced "Reference" information (chained UPDATEs)
-- this is required for UPDATEs occurring before the most recent UPDATE
UPDATE #T1 SET --> redundant the for the first level
[RowLog Contents 0_var] = A.[RowLog Contents 0_var]
,[RowLog Contents 0] = A.[RowLog Contents 0]
FROM @ModifiedRawData A
INNER JOIN #T1 B ON B.[NextEntry] = A.[EntryID]
WHERE B.[Process] = 1
--select * from #T1
END
END
END
------------------------------------------------------------------------------------------------------------
IF (@Debug > 0) BEGIN
print 'select * from @ModifiedRawData2'
select '@ModifiedRawData2'
select * from @ModifiedRawData ORDER BY [Current LSN], [Datum] Desc
END

DECLARE @RowLogContents VARBINARY(8000)
DECLARE @AllocUnitName NVARCHAR(MAX)
DECLARE @SQL NVARCHAR(MAX)

DECLARE @bitTable TABLE(
[ID] INT
,[Bitvalue] INT
)
--Create table to set the bit position of one byte.

INSERT INTO @bitTable
SELECT 0,2 UNION ALL
SELECT 1,2 UNION ALL
SELECT 2,4 UNION ALL
SELECT 3,8 UNION ALL
SELECT 4,16 UNION ALL
SELECT 5,32 UNION ALL
SELECT 6,64 UNION ALL
SELECT 7,128

--Create table to collect the row data.
DECLARE @DeletedRecords TABLE(
[ID] INT IDENTITY(1,1)
,[RowLogContents] VARBINARY(8000)
,[AllocUnitID] BIGINT
,[TransactionID] NVARCHAR(Max)
,[Slot ID] INT
,[FixedLengthData] SMALLINT
,[TotalNoOfCols] SMALLINT
,[NullBitMapLength] SMALLINT
,[NullBytes] VARBINARY(8000)
,[TotalNoOfVarCols] SMALLINT
,[ColumnOffsetArray] VARBINARY(8000)
,[VarColumnStart] SMALLINT
,[NullBitMap] VARCHAR(MAX)
,[TRANSACTION ID] NVARCHAR(Max)
,[Transaction Name] NVARCHAR(MAX)
,[Datum] VARCHAR(20)
,[Current LSN] VARCHAR(MAX)
,[Begin Time] DATETIME
)
--Create a common table expression to get all the row data plus how many bytes we have for each row.
;WITH RowData AS
(SELECT
[RowLog Contents 0] AS [RowLogContents]
,[AllocUnitID]
,[ID] AS [TransactionID]
,[Slot ID] as [Slot ID]
--[Fixed Length Data] = Substring (RowLog content 0, Status Bit A+ Status Bit B + 1,2 bytes)
,CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) AS [FixedLengthData] --@FixedLengthData

--[TotalnoOfCols] = Substring (RowLog content 0, [Fixed Length Data] + 1,2 bytes)
,CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2)))) as [TotalNoOfCols]

--[NullBitMapLength]=ceiling([Total No of Columns] /8.0)
,CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)) as [NullBitMapLength]

--[Null Bytes] = Substring (RowLog content 0, Status Bit A+ Status Bit B + [Fixed Length Data] +1, [NullBitMapLength] )
,SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 3,
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0))) as [NullBytes]

--[TotalNoOfVarCols] = Substring (RowLog content 0, Status Bit A+ Status Bit B + [Fixed Length Data] +1, [Null Bitmap length] + 2 )
,(CASE WHEN SUBSTRING([RowLog Contents 0], 1, 1) In (0x30,0x70)
THEN CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0],
CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 3 +
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)), 2))))
ELSE null END) AS [TotalNoOfVarCols]

--[ColumnOffsetArray]= Substring (RowLog content 0, Status Bit A+ Status Bit B + [Fixed Length Data] +1, [Null Bitmap length] + 2 , [TotalNoOfVarCols]*2 )
,(CASE WHEN SUBSTRING([RowLog Contents 0], 1, 1) In (0x30,0x70)
THEN SUBSTRING([RowLog Contents 0],
CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 3 +
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)) + 2,
(CASE WHEN SUBSTRING([RowLog Contents 0], 1, 1) In (0x30,0x70)
THEN CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0],
CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 3 +
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)), 2))))
ELSE null END) * 2)
ELSE null END) AS [ColumnOffsetArray]

-- Variable column Start = Status Bit A+ Status Bit B + [Fixed Length Data] + [Null Bitmap length] + 2+([TotalNoOfVarCols]*2)
,CASE WHEN SUBSTRING([RowLog Contents 0], 1, 1)In (0x30,0x70)
THEN (CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 4 +
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)) +
((CASE WHEN SUBSTRING([RowLog Contents 0], 1, 1) In (0x30,0x70)
THEN CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0],
CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 3 +
CONVERT(INT, CEILING(CONVERT(INT, CONVERT(BINARY(2), REVERSE(SUBSTRING([RowLog Contents 0], CONVERT(SMALLINT, CONVERT(BINARY(2),
REVERSE(SUBSTRING([RowLog Contents 0], 2 + 1, 2)))) + 1, 2))))/8.0)), 2))))
ELSE null END) * 2))
ELSE NULL END AS [VarColumnStart]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
FROM @ModifiedRawData
)

---Use this technique to repeat the row till the no of bytes of the row.
,N1 (n) AS (SELECT 1 UNION ALL SELECT 1)
,N2 (n) AS (SELECT 1 FROM N1 AS X, N1 AS Y)
,N3 (n) AS (SELECT 1 FROM N2 AS X, N2 AS Y)
,N4 (n) AS (SELECT ROW_NUMBER() OVER(ORDER BY X.n) FROM N3 AS X, N3 AS Y)

INSERT INTO @DeletedRecords
SELECT [RowLogContents]
,[AllocUnitID]
,[TransactionID]
,[Slot ID]
,[FixedLengthData]
,[TotalNoOfCols]
,[NullBitMapLength]
,[NullBytes]
,[TotalNoOfVarCols]
,[ColumnOffsetArray]
,[VarColumnStart]
--Get the Null value against each column (1 means null zero means not null)
,[NullBitMap]=(REPLACE(STUFF(
(SELECT ',' +
(CASE WHEN [ID]=0 THEN CONVERT(NVARCHAR(1),(SUBSTRING(NullBytes, n, 1) % 2)) ELSE CONVERT(NVARCHAR(1),((SUBSTRING(NullBytes, n, 1) / [Bitvalue]) % 2)) END) --as [nullBitMap]
FROM N4 AS Nums
JOIN RowData AS C ON n <= NullBitMapLength
CROSS JOIN @bitTable WHERE C.[RowLogContents] = D.[RowLogContents]
ORDER BY [RowLogContents],n ASC FOR XML PATH('')
),1,1,''),',',''))
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
FROM RowData D
IF (@Debug > 0) BEGIN
print 'select * from @DeletedRecords'
select '@DeletedRecords'
select * from @DeletedRecords
END

CREATE TABLE [#temp_Data](
[FieldName] VARCHAR(MAX) COLLATE database_default NOT NULL
,[FieldValue] VARCHAR(MAX) COLLATE database_default NULL
,[FieldSetValue] VARCHAR(MAX) COLLATE database_default NULL
,[Rowlogcontents] VARBINARY(8000)
,[TransactionID] VARCHAR(MAX) COLLATE database_default NOT NULL
,[Slot ID] INT
,[NonID] INT
,[nullbit] INT
,[TRANSACTION ID] NVARCHAR(MAX)
,[Transaction Name] NVARCHAR(MAX)
,[Datum] VARCHAR(20)
,[Current LSN] VARCHAR(MAX)
,[Begin Time] DATETIME
--,[System_type_id] INT
)
--Create common table expression and join it with the rowdata table
--to get each column details
;With CTE AS
/*This part is for variable data columns*/
(SELECT
A.[ID]
,[Rowlogcontents]
,[TransactionID]
,[Slot ID]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
,[NAME]
,cols.leaf_null_bit AS nullbit
,leaf_offset
,ISNULL(syscolumns.length, cols.max_length) AS [length]
,cols.system_type_id
,cols.leaf_bit_position AS bitpos
,ISNULL(syscolumns.xprec, cols.precision) AS xprec
,ISNULL(syscolumns.xscale, cols.scale) AS xscale
,SUBSTRING([nullBitMap], cols.leaf_null_bit, 1) AS is_null
--Calculate the variable column size from the variable column offset array
,(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
ELSE 0 END
) AS [Column value Size]

--Calculate the column length
,(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING ([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE (SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
) AS [Column Length]

--Get the Hexa decimal value from the RowlogContent
--HexValue of the variable column=Substring([Column value Size] - [Column Length] + 1,[Column Length])
--This is the data of your column but in the Hexvalue
,CASE WHEN SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=1
THEN NULL
ELSE SUBSTRING(Rowlogcontents,
(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
ELSE 0 END
)
-(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
))
)+1,(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
))
)
END AS hex_Value

FROM @DeletedRecords A
INNER JOIN sys.allocation_units allocunits ON
A.[AllocUnitId]=allocunits.[Allocation_Unit_Id]
INNER JOIN sys.partitions partitions ON
(allocunits.type IN (1, 3) AND partitions.hobt_id = allocunits.container_id)
OR (allocunits.type = 2 AND partitions.partition_id = allocunits.container_id)
INNER JOIN sys.system_internals_partition_columns cols ON cols.partition_id = partitions.partition_id
LEFT OUTER JOIN syscolumns ON syscolumns.id = partitions.object_id AND syscolumns.colid = cols.partition_column_id
WHERE leaf_offset < 0

UNION
/*This part is for fixed data columns*/
SELECT
A.[ID]
,[Rowlogcontents]
,[TransactionID]
,[Slot ID]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
,[NAME]
,cols.leaf_null_bit AS [nullbit]
,leaf_offset
,ISNULL(syscolumns.length, cols.max_length) AS [length]
,cols.system_type_id
,cols.leaf_bit_position AS bitpos
,ISNULL(syscolumns.xprec, cols.precision) AS xprec
,ISNULL(syscolumns.xscale, cols.scale) AS xscale
,SUBSTRING([nullBitMap], cols.leaf_null_bit, 1) AS is_null
,(SELECT TOP 1 ISNULL(SUM(CASE WHEN C.leaf_offset >1 THEN max_length ELSE 0 END),0)
FROM sys.system_internals_partition_columns C
WHERE cols.partition_id=C.partition_id AND C.leaf_null_bit<cols.leaf_null_bit
)+5 AS [Column value Size]
,syscolumns.length AS [Column Length]

,CASE WHEN SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=1
THEN NULL
ELSE SUBSTRING(Rowlogcontents,
(SELECT TOP 1 ISNULL(SUM(CASE WHEN C.leaf_offset >1 THEN max_length ELSE 0 END),0)
FROM sys.system_internals_partition_columns C
WHERE cols.partition_id =C.partition_id AND C.leaf_null_bit<cols.leaf_null_bit
)+5
,syscolumns.length)
END AS hex_Value
FROM @DeletedRecords A
INNER JOIN sys.allocation_units allocunits ON
A.[AllocUnitId]=allocunits.[Allocation_Unit_Id]
INNER JOIN sys.partitions partitions ON
(allocunits.type IN (1, 3) AND partitions.hobt_id = allocunits.container_id)
OR (allocunits.type = 2 AND partitions.partition_id = allocunits.container_id)
INNER JOIN sys.system_internals_partition_columns cols ON cols.partition_id = partitions.partition_id
LEFT OUTER JOIN syscolumns ON syscolumns.id = partitions.object_id AND syscolumns.colid = cols.partition_column_id
WHERE leaf_offset>0
)
--Converting data from Hexvalue to its orgional datatype.
--Implemented datatype conversion mechanism for each datatype
--Select * from sys.columns Where [object_id]=object_id('' + @SchemaName_n_TableName + '')
--Select * from CTE
INSERT INTO #temp_Data
SELECT
NAME,
CASE
WHEN system_type_id IN (231, 239) THEN LTRIM(RTRIM(CONVERT(NVARCHAR(max),hex_Value))) --NVARCHAR ,NCHAR
WHEN system_type_id IN (167,175) THEN LTRIM(RTRIM(CONVERT(VARCHAR(max),REPLACE(hex_Value, 0x00, 0x20)))) --VARCHAR,CHAR
WHEN system_type_id = 48 THEN CONVERT(VARCHAR(MAX), CONVERT(TINYINT, CONVERT(BINARY(1), REVERSE (hex_Value)))) --TINY INTEGER
WHEN system_type_id = 52 THEN CONVERT(VARCHAR(MAX), CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE (hex_Value)))) --SMALL INTEGER
WHEN system_type_id = 56 THEN CONVERT(VARCHAR(MAX), CONVERT(INT, CONVERT(BINARY(4), REVERSE(hex_Value)))) -- INTEGER
WHEN system_type_id = 127 THEN CONVERT(VARCHAR(MAX), CONVERT(BIGINT, CONVERT(BINARY(8), REVERSE(hex_Value))))-- BIG INTEGER
WHEN system_type_id = 61 Then CONVERT(VARCHAR(MAX),CONVERT(DATETIME,CONVERT(VARBINARY(8000),REVERSE (hex_Value))),100) --DATETIME
--WHEN system_type_id IN( 40) Then CONVERT(VARCHAR(MAX),CONVERT(DATE,CONVERT(VARBINARY(8000),(hex_Value))),100) --DATE This datatype only works for SQL Server 2008
WHEN system_type_id =58 Then CONVERT(VARCHAR(MAX),CONVERT(SMALLDATETIME,CONVERT(VARBINARY(8000),REVERSE(hex_Value))),100) --SMALL DATETIME
WHEN system_type_id = 108 THEN CONVERT(VARCHAR(MAX), CAST(CONVERT(NUMERIC(38,30), CONVERT(VARBINARY,CONVERT(VARBINARY,xprec)+CONVERT(VARBINARY,xscale))+CONVERT(VARBINARY(1),0) + hex_Value) as FLOAT)) --- NUMERIC
WHEN system_type_id In(60,122) THEN CONVERT(VARCHAR(MAX),Convert(MONEY,Convert(VARBINARY(8000),Reverse(hex_Value))),2) --MONEY,SMALLMONEY
WHEN system_type_id =106 THEN CONVERT(VARCHAR(MAX), CAST(CONVERT(Decimal(38,34), CONVERT(VARBINARY,Convert(VARBINARY,xprec)+CONVERT(VARBINARY,xscale))+CONVERT(VARBINARY(1),0) + hex_Value) as FLOAT)) --- DECIMAL
WHEN system_type_id = 104 THEN CONVERT(VARCHAR(MAX),CONVERT (BIT,CONVERT(BINARY(1), hex_Value)%2)) -- BIT
WHEN system_type_id =62 THEN RTRIM(LTRIM(STR(CONVERT(FLOAT,SIGN(CAST(CONVERT(VARBINARY(8000),Reverse(hex_Value)) AS BIGINT)) * (1.0 + (CAST(CONVERT(VARBINARY(8000),Reverse(hex_Value)) AS BIGINT) & 0x000FFFFFFFFFFFFF) * POWER(CAST(2 AS FLOAT), -52)) * POWER(CAST(2 AS FLOAT),((CAST(CONVERT(VARBINARY(8000),Reverse(hex_Value)) AS BIGINT) & 0x7ff0000000000000) / EXP(52 * LOG(2))-1023))),53,LEN(hex_Value)))) --- FLOAT
WHEN system_type_id =59 THEN Left(LTRIM(STR(CAST(SIGN(CAST(Convert(VARBINARY(8000),REVERSE(hex_Value)) AS BIGINT))* (1.0 + (CAST(CONVERT(VARBINARY(8000),Reverse(hex_Value)) AS BIGINT) & 0x007FFFFF) * POWER(CAST(2 AS Real), -23)) * POWER(CAST(2 AS Real),(((CAST(CONVERT(VARBINARY(8000),Reverse(hex_Value)) AS INT) )& 0x7f800000)/ EXP(23 * LOG(2))-127))AS REAL),23,23)),8) --Real
WHEN system_type_id In (165,173) THEN (CASE WHEN CHARINDEX(0x,cast('' AS XML).value('xs:hexBinary(sql:column("hex_Value"))', 'VARBINARY(8000)')) = 0 THEN '0x' ELSE '' END) +cast('' AS XML).value('xs:hexBinary(sql:column("hex_Value"))', 'varchar(max)') -- BINARY,VARBINARY
WHEN system_type_id =36 THEN CONVERT(VARCHAR(MAX),CONVERT(UNIQUEIDENTIFIER,hex_Value)) --UNIQUEIDENTIFIER
END AS [FieldValue]
,NULL AS [FieldSetValue]
,[Rowlogcontents]
,[TransactionID]
,[Slot ID]
,[ID]
,[nullbit]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
FROM CTE
ORDER BY [nullbit]

UPDATE #temp_Data SET [FieldSetValue] = --> New Column data
(CASE
-- VARCHAR; CHAR;
WHEN system_type_id In (167,175,189) THEN ISNULL('''' + [FieldValue] + '''','NULL')
-- NVARCHAR; NCHAR
WHEN system_type_id In (231,239) THEN ISNULL('N''' + [FieldValue] + '''','NULL')
-- SMALLDATETIME; DATE; DATETIME; UNIQUEIDENTIFIER
WHEN system_type_id In (58,40,61,36) THEN ISNULL('''' + [FieldValue] + '''','NULL')
-- TINYINT; SMALLINT; INT; REAL; MONEY; FLOAT; BIT; DECIMAL; NUMERIC; SMALLMONEY; BIGINT
WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN ISNULL([FieldValue],'NULL')
END)
FROM sys.columns [D]
WHERE [object_id] = object_id(''+@SchemaName_n_TableName+'')
AND [Fieldname] = D.[name]

/*Create Update statement*/
/*Now we have the modified and actual data as well*/
/*We need to create the update statement in case of recovery*/

;With CTE AS
(SELECT
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' , ' AS [Field]
----(CASE
---- -- VARCHAR; CHAR;
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' ,' + ' '
---- -- NVARCHAR; NCHAR
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '=' + ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' ,' + ''
---- -- SMALLDATETIME; DATE; DATETIME; UNIQUEIDENTIFIER
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' ,' + ' '
---- -- TINYINT; SMALLINT; INT; REAL; MONEY; FLOAT; BIT; DECIMAL; NUMERIC; SMALLMONEY; BIGINT
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' ,' + ' '
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,'D' AS [Type] --> Different
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON
[A].[FieldName]=[B].[FieldName]
AND [A].[Slot ID]=[B].[Slot ID]
--And [A].[TransactionID]=[B].[TransactionID]+1
AND [A].[TRANSACTION ID]=[B].[TRANSACTION ID] --> new condition
AND [A].[TransactionID]<>[B].[TransactionID] --> new condition
----AND [B].[TransactionID] =
---- (SELECT Min(Cast([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )
INNER JOIN sys.columns [D] ON [object_id] = object_id(''+@SchemaName_n_TableName+'')
AND A.[Fieldname] = D.[name]
WHERE ISNULL([A].[FieldValue],'') <> ISNULL([B].[FieldValue],'')

UNION ALL

SELECT
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' AND' AS [Field]
----(CASE
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '='+ ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' AND'
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,'S' AS [Type] --> Same
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON [A].[FieldName] = [B].[FieldName]
AND [A].[Slot ID] = [B].[Slot ID]
--AND [A].[TransactionID] = [B].[TransactionID]+1
AND [A].[TRANSACTION ID]=[B].[TRANSACTION ID] --> new condition
AND [A].[TransactionID]<>[B].[TransactionID] --> new condition
----AND [B].[TransactionID] =
---- (SELECT MIN(CAST([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )
INNER JOIN sys.columns [D] ON [object_id] = object_id('' + @SchemaName_n_TableName + '')
AND [A].[Fieldname] = D.[name]
WHERE ISNULL([A].[FieldValue],'') = ISNULL([B].[FieldValue],'')
----AND A.[TransactionID] NOT IN
---- (SELECT MIN(CAST([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )

UNION ALL --> new

SELECT --> new
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' AND' AS [Field]
----(CASE
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '=' + ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' AND'
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,CASE WHEN ([A].[Transaction Name] = 'INSERT') THEN 'N' ELSE 'O' END AS [Type] --> New or Old
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON
[A].[FieldName]=[B].[FieldName]
AND [A].[Slot ID]=[B].[Slot ID]
AND [A].[Transaction Name] IN ('INSERT','DELETE')
AND [A].[TransactionID]=[B].[TransactionID] --> self
INNER JOIN sys.columns [D] ON [object_id] = object_id(''+@SchemaName_n_TableName+'')
AND A.[Fieldname] = D.[name]
)

,CTEUpdateQuery AS
(SELECT
CASE A.[Transaction Name]
WHEN 'UPDATE' THEN
'UPDATE [' + @SchemaName_n_TableName + '] SET ' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM CTE B
WHERE A.[Slot ID]=B.[Slot ID] AND A.[TransactionID]=B.[TransactionID] AND B.[Type]='D' FOR XML PATH('')
),1,1,''), LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM CTE B
WHERE A.[Slot ID]=B.[Slot ID] AND A.[TransactionID]=B.[TransactionID] AND B.[Type]='D' FOR XML PATH('')
),1,1,'') )-2 --> -2 removes the final ', '
) +

' WHERE ' +

LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'') + ' '
FROM CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='S' FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'') + ' '
FROM CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='S' FOR XML PATH('')
),1,1,'') )-4 --> -4 removes the final ' AND'
)
WHEN 'DELETE' THEN
'INSERT INTO [' + @SchemaName_n_TableName + '] (' +
LEFT(STUFF(
(SELECT ' [' + ISNULL([FieldName] + '],','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' [' + ISNULL([FieldName] + '],','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') )-1 --> -1 removes the final ','
) + ') VALUES (' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([FieldSetValue] + ',','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([FieldSetValue] + ',','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') )-1 --> -1 removes the final ','
) + ')'
WHEN 'INSERT' THEN
'DELETE FROM [' + @SchemaName_n_TableName + '] WHERE ' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='N' FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='N' FOR XML PATH('')
),1,1,'') )-4 --> -4 removes the final ' AND'
)
END AS [Update Statement]
,[Slot ID]
,[TransactionID]
,[Rowlogcontents]
,[A].[NonID]
,MAX([A].[nullbit])+1 AS [nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM CTE A
GROUP BY [Slot ID]
,[TransactionID]
,[Rowlogcontents]
,[A].[NonID]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Begin Time]
,[A].[Current LSN]
,[A].[Datum]
)

INSERT INTO #temp_Data
SELECT 'Update Statement',ISNULL([Update Statement],''),NULL,NULL,[TransactionID],[Slot ID],[NonID],[nullbit],[TRANSACTION ID],[Transaction Name],[Datum],[Current LSN],[Begin Time]
FROM CTEUpdateQuery

/****************************************/
IF (@Debug > 0) BEGIN
print 'select * from CTE1'
select 'CTE1'
select * from (
/*This part is for variable data columns*/
SELECT
A.[ID]
,[Rowlogcontents]
,[TransactionID]
,[Slot ID]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
,[NAME]
,cols.leaf_null_bit AS nullbit
,leaf_offset
,ISNULL(syscolumns.length, cols.max_length) AS [length]
,cols.system_type_id
,cols.leaf_bit_position AS bitpos
,ISNULL(syscolumns.xprec, cols.precision) AS xprec
,ISNULL(syscolumns.xscale, cols.scale) AS xscale
,SUBSTRING([nullBitMap], cols.leaf_null_bit, 1) AS is_null
--Calculate the variable column size from the variable column offset array
,(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
ELSE 0 END
) AS [Column value Size]

--Calculate the column length
,(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING ([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE (SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
) AS [Column Length]

--Get the Hexa decimal value from the RowlogContent
--HexValue of the variable column=Substring([Column value Size] - [Column Length] + 1,[Column Length])
--This is the data of your column but in the Hexvalue
,CASE WHEN SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=1
THEN NULL
ELSE SUBSTRING(Rowlogcontents,
(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
ELSE 0 END
)
-(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
))
)+1,(
(CASE WHEN leaf_offset<1 AND SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=0
THEN CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*(leaf_offset*-1))-1, 2))))
- ISNULL(NULLIF(CONVERT(SMALLINT, CONVERT(BINARY(2), REVERSE(SUBSTRING([ColumnOffsetArray], (2*((leaf_offset*-1)-1))-1, 2)))), 0), [varColumnStart]) --> If Null OR zero
ELSE 0 END
))
)
END AS hex_Value

FROM @DeletedRecords A
INNER JOIN sys.allocation_units allocunits ON
A.[AllocUnitId]=allocunits.[Allocation_Unit_Id]
INNER JOIN sys.partitions partitions ON
(allocunits.type IN (1, 3) AND partitions.hobt_id = allocunits.container_id)
OR (allocunits.type = 2 AND partitions.partition_id = allocunits.container_id)
INNER JOIN sys.system_internals_partition_columns cols ON cols.partition_id = partitions.partition_id
LEFT OUTER JOIN syscolumns ON syscolumns.id = partitions.object_id AND syscolumns.colid = cols.partition_column_id
WHERE leaf_offset < 0

UNION
/*This part is for fixed data columns*/
SELECT
A.[ID]
,[Rowlogcontents]
,[TransactionID]
,[Slot ID]
,[TRANSACTION ID]
,[Transaction Name]
,[Datum]
,[Current LSN]
,[Begin Time]
,[NAME]
,cols.leaf_null_bit AS [nullbit]
,leaf_offset
,ISNULL(syscolumns.length, cols.max_length) AS [length]
,cols.system_type_id
,cols.leaf_bit_position AS bitpos
,ISNULL(syscolumns.xprec, cols.precision) AS xprec
,ISNULL(syscolumns.xscale, cols.scale) AS xscale
,SUBSTRING([nullBitMap], cols.leaf_null_bit, 1) AS is_null
,(SELECT TOP 1 ISNULL(SUM(CASE WHEN C.leaf_offset >1 THEN max_length ELSE 0 END),0)
FROM sys.system_internals_partition_columns C
WHERE cols.partition_id=C.partition_id AND C.leaf_null_bit<cols.leaf_null_bit
)+5 AS [Column value Size]
,syscolumns.length AS [Column Length]

,CASE WHEN SUBSTRING([nullBitMap], cols.leaf_null_bit, 1)=1
THEN NULL
ELSE SUBSTRING(Rowlogcontents,
(SELECT TOP 1 ISNULL(SUM(CASE WHEN C.leaf_offset >1 THEN max_length ELSE 0 END),0)
FROM sys.system_internals_partition_columns C
WHERE cols.partition_id =C.partition_id AND C.leaf_null_bit<cols.leaf_null_bit
)+5
,syscolumns.length)
END AS hex_Value
FROM @DeletedRecords A
INNER JOIN sys.allocation_units allocunits ON A.[AllocUnitId]=allocunits.[Allocation_Unit_Id]
INNER JOIN sys.partitions partitions ON
(allocunits.type IN (1, 3) AND partitions.hobt_id = allocunits.container_id)
OR (allocunits.type = 2 AND partitions.partition_id = allocunits.container_id)
INNER JOIN sys.system_internals_partition_columns cols ON cols.partition_id = partitions.partition_id
LEFT OUTER JOIN syscolumns ON syscolumns.id = partitions.object_id AND syscolumns.colid = cols.partition_column_id
WHERE leaf_offset>0
) AS t1
order by [Begin Time],[ID],[nullbit]

print 'select * from CTE2'
select 'CTE2'
select * into #CTE from (
SELECT
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' , ' AS [Field]
----(CASE
---- -- VARCHAR; CHAR;
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' ,' + ' '
---- -- NVARCHAR; NCHAR
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '=' + ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' ,' + ''
---- -- SMALLDATETIME; DATE; DATETIME; UNIQUEIDENTIFIER
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' ,' + ' '
---- -- TINYINT; SMALLINT; INT; REAL; MONEY; FLOAT; BIT; DECIMAL; NUMERIC; SMALLMONEY; BIGINT
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' ,' + ' '
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,'D' AS [Type] --> Different
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON
[A].[FieldName]=[B].[FieldName]
AND [A].[Slot ID]=[B].[Slot ID]
--And [A].[TransactionID]=[B].[TransactionID]+1
AND [A].[TRANSACTION ID]=[B].[TRANSACTION ID] --> new condition
AND [A].[TransactionID]<>[B].[TransactionID] --> new condition
AND [A].[Current LSN]=[B].[Current LSN] --> new condition
----AND [B].[TransactionID] =
---- (SELECT Min(Cast([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )
INNER JOIN sys.columns [D] ON [object_id] = object_id(''+@SchemaName_n_TableName+'')
AND A.[Fieldname] = D.[name]
WHERE ISNULL([A].[FieldValue],'') <> ISNULL([B].[FieldValue],'')

UNION ALL

SELECT
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' AND' AS [Field]
----(CASE
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '='+ ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' AND'
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,'S' AS [Type] --> Same
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON [A].[FieldName] = [B].[FieldName]
AND [A].[Slot ID] = [B].[Slot ID]
--AND [A].[TransactionID] = [B].[TransactionID]+1
AND [A].[TRANSACTION ID]=[B].[TRANSACTION ID] --> new condition
AND [A].[TransactionID]<>[B].[TransactionID] --> new condition
AND [A].[Current LSN]=[B].[Current LSN] --> new condition
----AND [B].[TransactionID] =
---- (SELECT MIN(CAST([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )
INNER JOIN sys.columns [D] ON [object_id] = object_id('' + @SchemaName_n_TableName + '')
AND [A].[Fieldname] = D.[name]
WHERE ISNULL([A].[FieldValue],'') = ISNULL([B].[FieldValue],'')
----AND A.[TransactionID] NOT IN
---- (SELECT MIN(CAST([TransactionID] AS INT)) AS [TransactionID]
---- FROM #temp_Data AS [C]
---- WHERE [A].[Slot ID]=[C].[Slot ID]
---- GROUP BY [Slot ID]
---- )

UNION ALL --> new

SELECT --> new
QUOTENAME([Name]) + '=' + ISNULL([A].[FieldSetValue],'NULL') + ' AND' AS [Field]
----(CASE
---- WHEN system_type_id In (167,175,189) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (231,239) THEN QUOTENAME([Name]) + '=' + ISNULL('N''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (58,40,61,36) THEN QUOTENAME([Name]) + '=' + ISNULL('''' + [A].[FieldValue] + '''','NULL') + ' AND'
---- WHEN system_type_id In (48,52,56,59,60,62,104,106,108,122,127) THEN QUOTENAME([Name]) + '=' + ISNULL([A].[FieldValue],'NULL') + ' AND'
---- END) AS [Field]
,A.[Slot ID]
,A.[TransactionID] AS [TransactionID]
,CASE WHEN ([A].[Transaction Name] = 'INSERT') THEN 'N' ELSE 'O' END AS [Type] --> New or Old
,[A].[Rowlogcontents]
,[A].[NonID]
,[A].[nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #temp_Data AS [A]
INNER JOIN #temp_Data AS [B] ON
[A].[FieldName]=[B].[FieldName]
AND [A].[Slot ID]=[B].[Slot ID]
AND [A].[Transaction Name] IN ('INSERT','DELETE')
AND [A].[TransactionID]=[B].[TransactionID] --> self
INNER JOIN sys.columns [D] ON [object_id] = object_id(''+@SchemaName_n_TableName+'')
AND A.[Fieldname] = D.[name]
) as t2
select * from #CTE
order by [Begin Time],[Slot ID],[NonID],[nullbit]

print 'select * from CTEUpdateQuery'
select 'CTEUpdateQuery'
SELECT
CASE A.[Transaction Name]
WHEN 'UPDATE' THEN
'UPDATE [' + @SchemaName_n_TableName + '] SET ' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM #CTE B
WHERE A.[Slot ID]=B.[Slot ID] AND A.[TransactionID]=B.[TransactionID] AND B.[Type]='D' FOR XML PATH('')
),1,1,''), LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM #CTE B
WHERE A.[Slot ID]=B.[Slot ID] AND A.[TransactionID]=B.[TransactionID] AND B.[Type]='D' FOR XML PATH('')
),1,1,'') )-2 --> -2 removes the final ', '
) +

' WHERE ' +

LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'') + ' '
FROM #CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='S' FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'') + ' '
FROM #CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='S' FOR XML PATH('')
),1,1,'') )-4 --> -4 removes the final ' AND'
)
WHEN 'DELETE' THEN
'INSERT INTO [' + @SchemaName_n_TableName + '] (' +
LEFT(STUFF(
(SELECT ' [' + ISNULL([FieldName] + '],','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' [' + ISNULL([FieldName] + '],','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') )-1 --> -1 removes the final ','
) + ') VALUES (' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([FieldSetValue] + ',','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([FieldSetValue] + ',','')
FROM #temp_Data C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Rowlogcontents] IS NOT NULL FOR XML PATH('')
),1,1,'') )-1 --> -1 removes the final ','
) + ')'
WHEN 'INSERT' THEN
'DELETE FROM [' + @SchemaName_n_TableName + '] WHERE ' +
LEFT(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM #CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='N' FOR XML PATH('')
),1,1,'') ,LEN(STUFF(
(SELECT ' ' + ISNULL([Field],'')
FROM #CTE C
WHERE A.[Slot ID]=C.[Slot ID] AND A.[TransactionID]=C.[TransactionID] AND C.[Type]='N' FOR XML PATH('')
),1,1,'') )-4 --> -4 removes the final ' AND'
)
END AS [Update Statement]
,[Slot ID]
,[TransactionID]
,[Rowlogcontents]
,[A].[NonID]
,MAX([A].[nullbit])+1 AS [nullbit]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Datum]
,[A].[Current LSN]
,[A].[Begin Time]
FROM #CTE A
GROUP BY [Slot ID]
,[TransactionID]
,[Rowlogcontents]
,[A].[NonID]
,[A].[TRANSACTION ID]
,[A].[Transaction Name]
,[A].[Begin Time]
,[A].[Current LSN]
,[A].[Datum]
drop table #CTE
END

IF (@Debug > 0) BEGIN
print 'select * from temp_Data1'
select '#temp_Data1'
select * from #temp_Data order by [TransactionID],[nullbit]
END

--Create the column name in the same order to do pivot table.
DECLARE @FieldNames VARCHAR(MAX)
SET @FieldNames = STUFF(
(SELECT ','+CAST(QUOTENAME([Name]) AS VARCHAR(MAX))
FROM syscolumns
WHERE id = object_id(''+@SchemaName_n_TableName+'') FOR XML PATH('')
),1,1,'')

--Finally, pivot table and get the change history so one can get the data back.
--The [Update Statement] column will give you the query that you can execute for recovery.
-- NOTE: Need a placeholder type for [Execution Account] (else it will be int)
SET @sql = 'SELECT ROW_NUMBER() OVER (ORDER BY [LSN],[Datum] DESC) AS [RowNo],' + @FieldNames
+ ',[Datum],[Update Statement],[Transaction],-1 AS [Prev RowNo],[Date],[Execution Account],[TRANSACTION ID],[Slot ID],[LSN] '
+ 'INTO [@ResultTable] '
+ 'FROM (SELECT [FieldName],[FieldValue],[Transaction Name] AS [Transaction],[Datum] AS [Datum],[Begin Time] AS [Date]'
+',[TRANSACTION ID] AS [Execution Account],[TRANSACTION ID],[Slot ID],[Current LSN] AS [LSN] FROM #temp_Data) AS src '
+ 'PIVOT (Min([FieldValue]) FOR [FieldName] IN (' + @FieldNames + ',[Update Statement])) AS pvt '
+ 'ORDER BY [LSN],[Datum] DESC'

--> Create a table to hold the dynamic SQL results --> doesn't seem to work
DECLARE @sql1 VARCHAR(MAX)
SET @sql1 = 'Declare @result Table ([RecNo] INT NOT NULL IDENTITY(1,1) PRIMARY KEY,' + REPLACE(@FieldNames,',',' varchar(max),') + 'varchar(max),'
+ '[Datum] varchar(20),[Update Statement] varchar(max),[TRANSACTION ID] varchar(max),[Transaction] varchar(max)'
+',[Slot ID] int,[LSN] varchar(max),[Prev RowNo] int,[Date] varchar(20))'
--EXEC(@sql1)

EXEC sp_executesql @sql
IF OBJECT_ID (N'[@ResultTable]', N'U') IS NOT NULL
BEGIN
UPDATE [@ResultTable] SET [Prev RowNo] =
ISNULL((SELECT MAX(B.[RowNo]) AS [ID] FROM [@ResultTable] B
WHERE B.[Slot ID] = A.[Slot ID] AND B.[RowNo] < A.[RowNo]),0)
FROM [@ResultTable] A
UPDATE [@ResultTable] SET [Execution Account] =
(SELECT [Transaction Account] FROM #TransIdAllList B WHERE B.[Transaction ID] = A.[Transaction ID])
FROM [@ResultTable] A
SELECT * FROM [@ResultTable]
DROP TABLE [@ResultTable]
END

IF (@Debug > 0) BEGIN
print @FieldNames
print @sql1
print ''
print @sql
END

GO --> required for testing/debugging (dumps all local entities from above)
SET NOEXEC OFF

PS: Não entendeu nada ?!?? Blz… isso não é para os fracos… 😉

SQL Saturday #284 – Porto Alegre


E ai pessoal…

Fiz o upload dos slides da minha apresentação no SQL Saturday #284

Já havia apresentado algumas coisas através dos webcasts da comunidade, mas essa foi minha primeira experiência com um público de carne e osso…

Se vocês gostaram tentarei fazer isso mais vezes…

Os arquivos das demos estão aqui.

Usar o xp_logininfo


Em alguns casos nos deparamos com logins estranhos nos servidores SQL.

Uma coisa que deixa qualquer DBA feliz da vida (#SQN) é encontrar um grupo de Windows dentro com permissões dentro do SQL, mais sexy ainda quando esse grupo esta na role de SysAdmin…

Em todo o caso, o DBA nem sempre tem acesso a administração do AD para saber quem, quantos, quais, porque, são os usuários do grupo do Windows e tem que perguntar para alguém de administração do SO para ter esta informação.

O que nem todo DBA sabe, é que existe uma Stored Procedure, que vem desde o SQL 2000, pode ajudar a descobrir esta informação…

Ex. 1 Todos os usuários de um grupo:


EXEC xp_logininfo 'BUILTIN\Administrators', 'members'

Ex. 2 Quais grupos o usuário faz parte:


EXEC xp_logininfo 'Domain\User', 'all'

Challenge Accepted and Now Completed !!!


Vocês conhecem a expressão: “Mais feliz que pinto no lixo”? ou “Mais feliz que filho de barbeiro em quermesse”?

hoje recebi o seguinte email do pessoal da Microsoft:

MASTER

SIM !!! Depois de passar por todo o calvário desde o treinamento,,, ir algumas vezes até os EUA para fazer o exame teórico… consegui passar nas provas necessárias para a certificação…

Oficialmente….

achievement_unlocked1

20131119_170628

20131119_171016

e agora com o direito de ter um post no The Master Blog

Atualização !!!

E agora no link do Meet the Masters tem meu nome

Demorou mas agora ta no Transcript:

master

 

Wait Stats e Extended Events


Olá pessoal, complementando o Webcast que apresentei em 11/04 estou disponibilizando os arquivos SQL de exemplo, arquivo PPT e o Dashboard em Excel.

SkyDrive – WT_EE.RARMIrror – WT_EE.RAR

Link para a gravação do Webcast.

Lembrete:

  1. Lembre-se de trocar o local onde vai salvar o arquivo do evento;
  2. Lembre-se de se estiver usando apenas o arquivo como saída parar o evento pare uma vez ou outra a captura, dependendo da quantidade de execuções e conexões o arquivo pode crescer muito e muito rápido.
  3. se você não configurar o filtro corretamente, você pode para seu ambiente.
  4. A conexao do powerpivot tem que ser alterado apontando para seu servidor.

Bom, por enquanto é isso.

Update Statistics quando vai acontecer?


Como todo o bom DBA você tem um plano de manutenção configurado para seu ambiente SQL.

Você costuma fazer rebuild/reindex, update statistics, backup, garante que o HA está funcionado,,,

Você provavelmente deve ter a opção de “auto update statistics” habilitada em suas bases e sabe como ela funciona,,, certo?

Bom,,, no bom e velho “by the book” o “auto update statistics” funciona assim:

  • Em uma tabela permanente:
    1. se a tabela não tem linhas, as estatísticas são atualizadas quando uma alteração for executada na tabela
    2. se o número de linhas for menor que 500, as estatísticas são atualizadas a cada 500 alterações na tabela
    3. se o número de linhas for superior a 500, as estatísticas são atualizadas a cada 20% + 500 alterações na tabela
  • Tabelas temporárias:
    1. se a tabela não tem linhas, as estatísticas são atualizadas quando uma alteração for executada na tabela
    2. se a tabela possui menos de 6 linhas, as estatísticas são atualizadas a cada 6 alterações na tabela
    3. se o número de linhas for menor que 500, as estatísticas são atualizadas a cada 500 alterações na tabela
    4. se o número de linhas for superior a 500, as estatísticas são atualizadas a cada 20% + 500 alterações na tabela
  • Tabelas variáveis (ficou feio,,, eu sei)
    1. Não existem estatísticas em variáveis de tabela (agora ficou menos pior)

Até aí nenhuma novidade certo? certo….

Com esse conceito em mente,,, imagine que você tem umas 40 tabelas com alguns 14.000.000 de registros cada, umas outras 200 tabelas com uns 30.000 registros cada,,, você sabe quem vai ser a próxima vítima do malévolo processo de “auto update statistics” ?

Acho que muito poucas pessoas tem a opção de “auto update statistics asynchronously” habilitada, então alguma query vai sofrer com a espera da atualização de uma estatística e alguém vai achar que é lentidão no sistema… Smiley de boca aberta

Então como monitorar a quantidade de alterações de uma tabela pra saber se ela está chegando aos malvados 20% +500 ?

Tá lá uma query:

/*SQL 2005*/ 
SELECT SO.NAME AS tableName, SC.NAME AS columnName, SSC.*, SSR.* FROM sys.sysrowsetcolumns SSC 
INNER JOIN sys.sysrowsets SSR ON SSC.rowsetID = SSR.rowsetID 
INNER JOIN sys.sysobjects SO ON SSR.idmajor = SO.id 
INNER JOIN sys.syscolumns SC on SSR.idmajor = SC.id AND SSC.rowsetcolid = SC.colid 
WHERE SO.xtype = 'U' 
ORDER BY so.name, sc.colid 
/*SQL 2008*/  
SELECT SO.NAME AS tableName, SC.NAME AS columnName, SSC.*, SSR.* FROM sys.sysrscols SSC  
INNER JOIN sys.sysrowsets SSR ON SSC.rowsetID = SSR.rowsetID  
INNER JOIN sys.sysobjects SO ON SSR.idmajor = SO.id  
INNER JOIN sys.syscolumns SC on SSR.idmajor = SC.id AND SSC.rscolid = SC.colid  
WHERE SO.xtype = 'U'  
ORDER BY so.name, sc.colid

Não conseguiu executar??????? hehehehe Smiley de boca aberta

Precisa habilitar o DAC, as tabelas sysrscols, sysrowsetcolumns e sysrowsets só podem ser acessadas pelo DAC.

Outra coisa, não esqueça de mudar a base,,,

Mas até ai, o que tem de interessante no resultado?

O nome da tabela já sabemos, qual a coluna? grande coisa,,, o que importa é a coluna rcmodified e a coluna rcrows, quantidade de modificações e contagem de linhas respectivamente.

Agora sim,,, já começamos a ter alguma coisa legal…. mas tem como melhorar? sabemos as tabelas e as colunas… temos como saber quais as estatísticas que vão ser impactadas pela atualização? Claro…

/*SQL 2005*/
SELECT SO.NAME AS tableName, COL_NAME(sc.object_id, sc.column_id) AS columnName, A.name as stats_name, SSC.*, SSR.* FROM sys.sysrowsetcolumns SSC 
INNER JOIN sys.sysrowsets SSR ON SSC.rowsetID = SSR.rowsetID 
INNER JOIN sys.sysobjects SO ON SSR.idmajor = SO.id 
INNER JOIN sys.stats_columns SC on SSR.idmajor = SC.object_id AND SSC.rowsetcolid = SC.column_id 
INNER JOIN sys.stats as A ON A.object_id = SO.id 
WHERE SO.xtype = 'U' 
ORDER BY so.name, sc.column_id 
/*SQL 2008*/ 
SELECT SO.NAME AS tableName, COL_NAME(sc.object_id, sc.column_id) AS columnName, A.name as stats_name, SSC.*, SSR.* FROM sys.sysrscols SSC 
INNER JOIN sys.sysrowsets SSR ON SSC.rowsetID = SSR.rowsetID 
INNER JOIN sys.sysobjects SO ON SSR.idmajor = SO.id 
INNER JOIN sys.stats_columns SC on SSR.idmajor = SC.object_id AND SSC.rscolid = SC.column_id 
INNER JOIN sys.stats as A ON A.object_id = SO.id 
WHERE SO.xtype = 'U' 
ORDER BY so.name, sc.column_id 

Isso é uma informação interessante,,, por que precisamos disso? Imagine uma tabela com alguns milhões de linhas, se a atualização de estatísticas ocorre apenas a cada 20%+500 modificações é bem provável que o intervalo entre uma atualização e a outra seja um pouco grande…

Aí você pergunta: mas eu faço rebuild dos meus índices com uma boa frequência e eu sei que, com esse processo, ele já faz a atualização das estatísticas, o que eu ganho com isso?

Ai eu respondo: Você pode ter estatísticas que são criadas automaticamente,,, lembra da opção do “auto create statistics” que costuma estar habilitada por padrão? da uma olhada na sua tabela, veja se existem estatísticas começando com _WA então,,, o rebuild de índices vai atualizas as estatísticas que ele utiliza e não todas as da tabela…

bom,,,, é isso,,, bom proveito…

Pressão de processador?


A algumas semanas atrás eu estava ajudando um cliente a localizar problemas de lentidão no ambiente dele. Não havia um ponto exato, não era sempre na mesma aplicação, muitas vezes nem a mesma unidade, isso ajudava muito na localização do problema,,, Smiley triste

Um dos analistas de desenvolvimento me indagou se o servidor de SQL estava sofrendo com problemas de processador,,, em alguns momentos o servidor apresentava alguns picos em um dos núcleos mas nada muito longo muito menos alarmante.

proc

Com a query abaixo, mostrei que não havia problemas de processamento,,, pelo menos naquele momento…

 Select signal_wait_time_ms=sum(signal_wait_time_ms)<br>,'%signal (cpu) waits' = cast(100.0 * sum(signal_wait_time_ms) / sum (wait_time_ms) as numeric(20,2))<br>,resource_wait_time_ms=sum(wait_time_ms - signal_wait_time_ms)<br>,'%resource waits'= cast(100.0 * sum(wait_time_ms - signal_wait_time_ms) / sum (wait_time_ms) as numeric(20,2))<br>From sys.dm_os_wait_stats 

O resultado é o seguinte:

proc1

Agora vem a pergunta: Legal, mas idaí?

O que nos interessa nesse resultado é o %signal (cpu) waits e o %resource waits.

A matemática é bem simples: quanto mais %recouce waits e menos %signal (cpu) waits melhor, quer dizer que, nesse momento não está havendo problemas de pressão com processador, não quer dizer que daqui a 1 segundo não comece a ter, mas no momento da execução dessa query não havia problema.

English version

A few weeks ago i was helping a client to find a slow problem on his environment. Don´t had a exact point, not always the same apllication, even the same place and this help a lot to find the problem.

One of the developers ask me if the SQL Server had problems with processos pressure,,, in a few moments on the day the server show a top processes in one of the cores, but was not the problem.

With the query below i show that we don´t have any problem with the processor, in that moment…

 Select signal_wait_time_ms=sum(signal_wait_time_ms)<br>,'%signal (cpu) waits' = cast(100.0 * sum(signal_wait_time_ms) / sum (wait_time_ms) as numeric(20,2))<br>,resource_wait_time_ms=sum(wait_time_ms - signal_wait_time_ms)<br>,'%resource waits'= cast(100.0 * sum(wait_time_ms - signal_wait_time_ms) / sum (wait_time_ms) as numeric(20,2))<br>From sys.dm_os_wait_stats 

The result was:

proc1

And then comes the question: Cool, but WTF?

The important is %signal (cpu) waits and %resource waits.

The mathematic is simple: more %recouce waits and lass %signal (cpu) waits is better, in that moment the server don´t have processos pressure.

Sorry about the poor English, i´ll fix at night.

Índices? pra que manutenção disso?


Sou muito fã de ferramentas que ajudem a facilitar o dia a dia na administração do SQL, vocês já devem ter visto isso no Post Top 5 – Ferramentas Grátis, Smiley de boca aberta

Eu estava fazendo o download de umas ferramentas no site da RedGate e achei esse programa muito interessante,,, simples,,, gratuito,,, o SQL Index Manager,,,

Com apenas 2.4MB, ele promete uma análise de todos os índices de todas as bases que estão na sua instância e recomenda o rebuild ou reindex de cada um deles,,,

Fiz um teste em uma instância com 230 bases, com mais de 7000 índices e ele demorou aprox. 4 minutos.

A ferramenta possui uma interface extremamente simples:

indexmanager01

Você pode deixar a ferramenta executar a manutenção para você, ou

indexmanager02

Ela gera os scripts para que você execute manualmente

indexmanager03

O tempo que ela demora para executar o rebuild ou reindex é o mesmo que o script ou algum plano de manutenção que você crie levaria para fazer, porque no final, a ferramenta faz a mesma coisa que você já deveria fazer…

indexmanager04

Now in English…

I´m a fanatic about tools that help the day by day in SQL administration.

I was downloading a few tools from RedGate and find this very nice program, simple and free the SQL Index Manager,,,

With only 2.4MB, the program analyse all your indexes in all your databases and recomends a rebuild or reindex of each one.

I do a test in a server with 230 databases and more that 7000 indexes he toke 4 minutes.

The tool is extreme easy of use. (image1)

He can fix for you or generate the script. (image2)

The scripts are simples without a lot of comments (image3)

And take the same time of your Maintenance plan or custom script. (image4)

T-SQL Tuesday #26 – Segundas Chances


Todo mundo merece uma segunda chance,, ou para fazer melhor, ou para simplesmente não fazer,,, então,,, até no SQL temos uma segunda chance…

Dessa vez o Sr. David Howard (Blog | Twitter) deu a oportunidade de escrevermos novamente sobre algum tópico anterior do T-SQL Tuesday, ou para melhora-lo ou para fazer um se você não participou…

Eu resolvi melhorar o meu script para montar um Mirror com SQLCMD,,, na versão anterior (#25) se o banco de dados tiver mais que um datafile você tem que modificar o script na mão e compensar a criação desse outro arquivo… Nesta versão o script vai ler o arquivo de backup em uma temp table e montar o script de restore com todas as variáveis…

Vale lembrar que você precisa habilitar a opção de SQLCMD no SSMS e não esqueça de trocar o caminho do backup…

Everyone deserves a second chance, or to do better or to simply not do, then, even in SQL havea second chance…
This time Mr. David Howard (blog | twitter) gave us the opportunity to write again about a previous topic of Tuesday’s T-SQL, or to improve it or make one if you did not participate …
I decided to improve my script to create a Mirror with SQLCMD, in the previous version (#25) if the database has more than one datafile you have to modify the script and make the creation of another file … this version will read backup file in a temp table and mount the restore script with all the variables …
Remember that you need to enable the option of SQLCMD in SSMS and do not forget to change the backup path …

:SETVAR PrincipalServer (local)\INST01
:SETVAR MirrorServer (local)\INST02
:SETVAR SERVER (servername)
:SETVAR db DB_NAME
go

:ON ERROR EXIT
go

:CONNECT $(PrincipalServer)

ALTER DATABASE $(db)
 SET RECOVERY FULL
go

CREATE ENDPOINT Mirroring
 STATE=STARTED
 AS TCP (LISTENER_PORT=5091)
 FOR DATABASE_MIRRORING (ROLE=ALL)
GO

:CONNECT $(MirrorServer)

CREATE ENDPOINT Mirroring
 STATE=STARTED
 AS TCP (LISTENER_PORT=5092)
 FOR DATABASE_MIRRORING (ROLE=ALL)
GO

:CONNECT $(PrincipalServer)

BACKUP DATABASE $(db)
TO DISK = 'D:\DB01\local\$(db).bak'
WITH INIT
GO

:CONNECT $(MirrorServer)

DECLARE @InstanceName sql_variant,
 @InstanceDir sql_variant,
 @SQLDataRoot nvarchar(512),
 @ExecStr nvarchar(max)

SELECT @InstanceName = ISNULL(SERVERPROPERTY('InstanceName'), 'MSSQLServer')

EXECUTE master.dbo.xp_regread 'HKEY_LOCAL_MACHINE',
 'SOFTWARE\Microsoft\Microsoft SQL Server\Instance Names\SQL',
 @InstanceName, @InstanceDir OUTPUT

SELECT @ExecStr = 'EXECUTE master.dbo.xp_regread '
 + '''HKEY_LOCAL_MACHINE'', '
 + '''SOFTWARE\Microsoft\Microsoft SQL Server\'
 + convert(varchar, @InstanceDir)
 + '\Setup'', ''SQLDataRoot'', @SQLDataRoot OUTPUT'

EXEC master.dbo.sp_executesql @ExecStr
 , N'@SQLDataRoot nvarchar(512) OUTPUT'
 , @SQLDataRoot OUTPUT

IF @SQLDataRoot IS NULL
BEGIN
 RAISERROR ('I can´t find where restore the Database... I going to stop...', 16, -1)
END

CREATE TABLE #BackupFileList
( LogicalName sysname NULL
 , PhysicalName sysname NULL
 , [Type] char(1)
 , FileGroupName sysname NULL
 , Size bigint
 , MaxSize bigint
 , FileId smallint
 , CreateLSN numeric(25,0)
 , DropLSN numeric(25,0)
 , UniqueId uniqueidentifier
 , ReadOnlyLSN numeric(25,0)
 , ReadWriteLSN numeric(25,0)
 , BackupSizeInBytes bigint
 , SourceBlockSize bigint
 , FileGroupId smallint
 , LogGroupGUID uniqueidentifier
 , DifferentialBaseLSN numeric(25,0)
 , DifferentialBaseGUID uniqueidentifier
 , IsReadOnly bit
 , IsPresent bit
 , TDEThumbPrint varbinary(32)
)

INSERT #BackupFileList
 EXEC('RESTORE FILELISTONLY FROM DISK = ''D:\DB01\local\$(db).bak''')

UPDATE #BackupFileList
 SET PhysicalName
 = @SQLDataRoot
 + N'\Data\'
 + REVERSE(SUBSTRING(REVERSE(PhysicalName)
 , 1, PATINDEX('%\%', REVERSE(PhysicalName)) -1))

DECLARE @LogicalName sysname
 , @PhysicalName sysname

DECLARE FileListCursor CURSOR FAST_FORWARD FOR
 SELECT LogicalName, PhysicalName
 FROM #BackupFileList

OPEN FileListCursor

FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName

SELECT @ExecStr = N'RESTORE DATABASE $(db)' +
 N' FROM DISK = ''D:\DB01\local\$(db).bak''' +
 N' WITH MOVE ''' + @LogicalName + N''' TO ''' + @PhysicalName + N''''

FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName

WHILE @@FETCH_STATUS <> -1
BEGIN
 SELECT @ExecStr = @ExecStr + N', MOVE ''' + @LogicalName
 + ''' TO ''' + @PhysicalName + ''''
 FETCH NEXT FROM FileListCursor INTO @LogicalName, @PhysicalName
END

SELECT @ExecStr = @ExecStr + N' , NORECOVERY, REPLACE'

-- if you receive the error message because the script don´t found where he need to restore, you can uncomment the next line and get the restore command,,,
-- to restore manual...
-- SELECT @ExecStr

EXEC (@ExecStr)

DEALLOCATE FileListCursor
GO

:CONNECT $(PrincipalServer)
SELECT DATABASEPROPERTYEX(N'$(db)', N'Status') AS 'Principal Database State' -- Returns ONLINE
SELECT db_name(sd.[database_id]) AS [Database Name],
 sd.mirroring_guid,
 sd.mirroring_state,
 sd.mirroring_state_desc,
 sd.mirroring_partner_name,
 sd.mirroring_witness_name,
 sd.mirroring_witness_state,
 sd.mirroring_witness_state_desc,
 sd.mirroring_role,
 sd.mirroring_role_desc,
 sd.mirroring_role_sequence,
 sd.mirroring_safety_level,
 sd.mirroring_safety_level_desc,
 sd.mirroring_safety_sequence,
 sd.mirroring_failover_lsn
FROM sys.database_mirroring AS sd
WHERE sd.[database_id] = db_id(N'$(db)')
go

:CONNECT $(MirrorServer)
SELECT DATABASEPROPERTYEX(N'$(db)', N'Status') AS 'Mirror Database State' -- Returns RESTORING
SELECT db_name(sd.[database_id]) AS [Database Name],
 sd.mirroring_guid,
 sd.mirroring_state,
 sd.mirroring_state_desc,
 sd.mirroring_partner_name,
 sd.mirroring_witness_name,
 sd.mirroring_witness_state,
 sd.mirroring_witness_state_desc,
 sd.mirroring_role,
 sd.mirroring_role_desc,
 sd.mirroring_role_sequence,
 sd.mirroring_safety_level,
 sd.mirroring_safety_level_desc,
 sd.mirroring_safety_sequence,
 sd.mirroring_failover_lsn
FROM sys.database_mirroring AS sd
WHERE sd.[database_id] = db_id(N'$(db)')
go

:CONNECT $(PrincipalServer)

BACKUP LOG $(db)
TO DISK = 'D:\DB01\local\$(db)_Log.bak'
WITH INIT
GO

:CONNECT $(MirrorServer)

RESTORE LOG $(db)
FROM DISK = 'D:\DB01\local\$(db)_Log.bak'
WITH NORECOVERY
GO

ALTER DATABASE $(db)
 SET PARTNER = 'TCP://$(server):5091'
GO

:CONNECT $(PrincipalServer)

ALTER DATABASE $(db)
 SET PARTNER = 'TCP://$(server):5092'
GO

SELECT db_name(sd.[database_id]) AS [Database Name],
 sd.mirroring_guid,
 sd.mirroring_state,
 sd.mirroring_state_desc,
 sd.mirroring_partner_name,
 sd.mirroring_witness_name,
 sd.mirroring_witness_state,
 sd.mirroring_witness_state_desc,
 sd.mirroring_role,
 sd.mirroring_role_desc,
 sd.mirroring_role_sequence,
 sd.mirroring_safety_level,
 sd.mirroring_safety_level_desc,
 sd.mirroring_safety_sequence,
 sd.mirroring_failover_lsn
FROM sys.database_mirroring AS sd
WHERE sd.[database_id] = db_id(N'$(db)')
GO

Não ganhou seus presentes de natal?


Não recebeu seus presentes de natal? então fala com o Grinch

Esse é a mesma coisa do post Feliz Natal em T-SQL, você precisa rodar em SQL 2008 ou superior… o arquivo com o código pode ser baixado aqui.


SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (169 -166, 118 -152, 93 -154, 45 -192, 39 -208, 35 -233, 37 -262, 45 -289, 42 -328, 44 -347, 53 -376, 60 -359,
 64 -337, 63 -314, 59 -301, 48 -289, 50 -269, 54 -246, 60 -230, 72 -216, 57 -217, 73 -213, 68 -196, 75 -192,
 72 -197, 75 -213, 77 -198, 88 -180, 80 -198, 77 -214, 85 -245, 103 -248, 99 -245, 100 -242, 103 -240, 112 -240,
 104 -238, 106 -227, 116 -214, 129 -209, 139 -213, 134 -210, 142 -204, 150 -204, 143 -201, 147 -196, 154 -194,
 164 -196, 156 -193, 158 -185, 163 -177, 173 -174, 166 -174, 171 -165, 169 -166)
 ),
 POLYGON(
 (281 -177, 289 -176, 296 -179, 302 -182, 307 -187, 283 -426, 275 -494, 275 -534, 122 -534, 127 -509, 134 -508,
 135 -518, 143 -525, 155 -523, 158 -517, 166 -520, 176 -517, 181 -511, 190 -510, 196 -502, 196 -494, 202 -491,
 204 -483, 204 -480, 211 -474, 213 -462, 219 -455, 221 -449, 217 -439, 219 -431, 219 -422, 214 -413, 238 -382,
 243 -364, 243 -342, 249 -321, 257 -289, 271 -214, 281 -177)
 ),
 POLYGON(
 (122 -534, 127 -509, 120 -504, 116 -500, 116 -486, 112 -486, 106 -509, 104 -534, 122 -534)
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (190 -207, 201 -214, 209 -226, 212 -235, 214 -278, 219 -294, 234 -317, 241 -342, 242 -355, 241 -366, 239 -380,
 234 -388, 224 -400, 212 -413, 194 -435, 187 -446, 180 -459, 172 -467, 162 -471, 153 -470, 144 -464, 136 -453,
 125 -439, 117 -426, 102 -412, 88 -400, 73 -384, 70 -371, 68 -356, 71 -342, 76 -331, 82 -321, 90 -309, 92 -293,
 93 -282, 103 -280, 131 -256, 167 -217, 186 -204, 190 -207)
 ),
 POLYGON(
 (319 -40, 321 -57, 324 -79, 318 -84, 312 -84, 312 -91, 306 -104, 297 -105, 288 -110, 288 -90, 281 -78, 278 -59,
 295 -45, 309 -36, 314 -36, 319 -40)
 ),
 LINESTRING(
 309 -96, 304 -98,300 -98
 ),
 LINESTRING(
 311 -84, 304 -72, 303 -64, 304 -54
 ),
 LINESTRING(
 302 -68, 296 -66, 294 -59
 ),
 POLYGON(
 (319 -40, 328 -37, 344 -37, 349 -40, 348 -52, 344 -58, 332 -59, 321 -58, 319 -40)
 ),
 POLYGON(
 (322 -59, 343 -59, 346 -66, 344 -75, 338 -84, 331 -83, 323 -80, 322 -59)
 ),
 POLYGON(
 (323 -81, 327 -83, 338 -85, 337 -96, 332 -101, 325 -104, 317 -103, 311 -97, 312 -84, 318 -84, 323 -81)
 ),
 POLYGON(
 (306 -120, 307 -129, 311 -134, 312 -140, 309 -152, 308 -168, 296 -161, 286 -161, 284 -156, 288 -130,
 294 -128, 306 -120)
 ),
 POLYGON(
 (154 -472, 156 -476, 158 -485, 156 -491, 153 -498, 159 -487, 176 -474, 183 -464, 185 -453, 179 -460, 171 -467,
 165 -470, 155 -471, 154 -472)
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (171 -165, 179 -159, 185 -160, 182 -157, 190 -147, 202 -144, 211 -148, 214 -157, 206 -168, 215 -160, 221 -168,
 221 -175, 206 -184, 221 -178, 229 -186, 228 -192, 221 -197, 228 -197, 231 -205, 225 -212, 218 -211, 222 -216,
 219 -226, 211 -231, 204 -218, 191 -208, 201 -205, 191 -205, 178 -209, 167 -218, 144 -242, 128 -260, 111 -274,
 98 -282, 85 -283, 95 -284, 91 -299, 81 -299, 74 -294, 67 -294, 60 -290, 59 -284, 61 -279, 54 -268, 58 -258,
 66 -253, 74 -253, 77 -257, 77 -252, 85 -245, 103 -248, 99 -245, 100 -242, 103 -240, 112 -240, 104 -238, 106 -227,
 116 -214, 129 -209, 139 -213, 134 -210, 142 -204, 150 -204, 143 -201, 147 -196, 154 -194, 164 -196, 156 -193,
 158 -185, 163 -177, 173 -174, 166 -174, 171 -165)
 ),
 POLYGON(
 (122 -435, 114 -439, 108 -445, 106 -456, 111 -460, 118 -455, 112 -465, 109 -473, 109 -482, 115 -486, 122 -479,
 116 -489, 116 -497, 119 -503, 125 -507, 132 -508, 136 -504, 134 -515, 140 -522, 152 -524, 158 -517, 158 -510,
 160 -517, 170 -519, 178 -514, 181 -507, 184 -510, 193 -509, 196 -501, 195 -493, 200 -493, 204 -486, 200 -475,
 205 -478, 210 -472, 213 -466, 212 -461, 209 -457, 214 -459, 218 -457, 220 -450, 215 -440, 218 -434, 218 -423,
 214 -417, 208 -417, 196 -434, 185 -453, 183 -465, 176 -474, 160 -486, 156 -491, 153 -498, 155 -490, 158 -484,
 155 -476, 153 -472, 146 -466, 139 -457, 122 -435)
 ),
 POLYGON(
 (271 -152, 280 -153, 285 -158, 286 -161, 289 -160, 296 -160, 304 -165, 310 -172, 319 -172, 325 -176, 327 -180,
 326 -187, 320 -192, 319 -198, 315 -202, 307 -203, 307 -188, 300 -182, 290 -178, 282 -176, 278 -185, 266 -185,
 263 -181, 264 -177, 269 -175, 262 -176, 258 -171, 259 -166, 262 -164, 269 -165, 264 -162, 265 -157, 271 -152)
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (316 0, 329 0, 324 -39, 318 -40, 314 -36, 316 0)
 ),
 POLYGON(
 (303 0, 316 0, 315 -36, 304 -40, 303 0)
 ),
 POLYGON(
 (307 -104, 311 -98, 321 -105, 332 -105, 340 -108, 346 -117, 345 -124, 347 -129, 344 -131, 343 -126, 338 -125, 330 -122,
 324 -117, 328 -122, 326 -128, 323 -132, 318 -134, 317 -139, 312 -133, 307 -130, 306 -124, 308 -119, 311 -112, 306 -119,
 301 -124, 293 -128, 288 -128, 288 -132, 284 -127, 283 -122, 284 -114, 291 -108, 301 -104, 307 -104)
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (151 -306, 146 -311, 135 -316, 125 -318, 116 -317, 110 -312, 106 -306, 119 -303, 136 -300, 151 -306)
 ),
 POLYGON(
 (137 -303, 144 -304, 146 -307, 144 -310, 138 -312, 133 -309, 132 -305, 137 -303)
 ),
 POLYGON(
 (161 -302, 165 -296, 178 -288, 188 -286, 203 -289, 205 -294, 204 -305, 202 -307, 182 -312, 171 -310, 164 -306,
 161 -302)
 ),
 POLYGON(
 (184 -291, 185 -296, 184 -301, 176 -306, 173 -304, 170 -300, 172 -293, 179 -290, 184 -291)
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 POLYGON(
 (143 -439, 142 -434, 148 -425, 155 -420, 162 -418, 168 -418, 180 -427, 183 -432, 183 -435, 181 -436, 176 -430,
 168 -427, 159 -424, 149 -426, 143 -433, 143 -439)
 ),
 LINESTRING(
 161 -424, 160 -419
 ),
 LINESTRING(
 173 -422, 176 -430
 )
)', 0)

UNION ALL

SELECT geometry::STGeomFromText('GEOMETRYCOLLECTION(
 LINESTRING(
 151 -326, 147 -331, 147 -335, 157 -333, 160 -336, 164 -338, 168 -335, 171 -334, 180 -335, 179 -330, 174 -328
 ),
 LINESTRING(
 146 -332, 136 -344, 132 -357, 130 -373, 132 -396, 136 -410, 137 -419
 ),
 LINESTRING(
 168 -338, 170 -344, 171 -351, 167 -391
 ),
 LINESTRING(
 181 -333, 187 -342, 188 -351, 192 -375, 191 -401, 190 -417, 190 -440, 186 -443, 182 -445, 179 -443, 175 -438
 ),
 LINESTRING(
 138 -436, 140 -442, 143 -446, 153 -436, 157 -431, 160 -432
 ),
 LINESTRING(
 150 -413, 153 -410, 157 -407, 164 -404, 173 -406, 176 -410
 ),
 LINESTRING(
 139 -446, 148 -457, 152 -460, 157 -462, 162 -463, 168 -462, 175 -457, 180 -447
 ),
 LINESTRING(
 126 -352, 121 -357, 117 -368, 116 -376, 117 -390, 121 -402, 135 -437
 ),
 LINESTRING(
 105 -396, 113 -412, 118 -425
 ),
 LINESTRING(
 216 -388, 214 -403, 208 -416
 ),
 LINESTRING(
 198 -360, 202 -370, 202 -382, 200 -403, 194 -434
 ),
 LINESTRING(
 175 -316, 181 -317, 193 -316, 205 -313
 ),
 LINESTRING(
 177 -318, 189 -323, 199 -323, 214 -316
 ),
 LINESTRING(
 174 -320, 186 -330, 199 -334, 213 -330, 220 -321
 ),
 LINESTRING(
 157 -326, 162 -322, 171 -323
 ),
 LINESTRING(
 155 -320, 161 -317, 167 -318
 ),
 LINESTRING(
 154 -316, 160 -312
 ),
 LINESTRING(
 106 -318, 110 -321, 121 -326, 132 -323, 148 -313
 ),
 LINESTRING(
 99 -324, 108 -334, 119 -335, 137 -325, 150 -312
 ),
 LINESTRING(
 94 -335, 100 -344, 111 -345, 123 -339, 137 -330, 147 -321, 153 -311
 ),
 LINESTRING(
 105 -307, 88 -304
 ),
 LINESTRING(
 106 -309, 94 -313
 ),
 LINESTRING(
 207 -294, 221 -295
 ),
 LINESTRING(
 205 -291, 219 -289
 ),
 LINESTRING(
 206 -290, 205 -283, 202 -281
 ),
 LINESTRING(
 158 -298, 158 -284, 160 -278
 ),
 LINESTRING(
 158 -284, 154 -263
 ),
 LINESTRING(
 154 -258, 152 -244
 ),
 LINESTRING(
 151 -272, 148 -266, 144 -261, 138 -257
 ),
 LINESTRING(
 153 -291, 149 -282, 140 -271, 130 -265
 ),
 LINESTRING(
 158 -264, 161 -250, 165 -241, 170 -235, 175 -233
 ),
 LINESTRING(
 169 -266, 173 -254, 178 -244, 182 -237
 ),
 LINESTRING(
 196 -244, 204 -220
 ),
 LINESTRING(
 167 -292, 198 -242
 ),
 LINESTRING(
 168 -291, 199 -241
 ),
 LINESTRING(
 169 -290, 201 -240
 ),
 LINESTRING(
 170 -289, 202 -240
 ),
 LINESTRING(
 171 -289, 204 -242
 ),
 LINESTRING(
 172 -288, 205 -244
 ),
 LINESTRING(
 173 -288, 210 -250
 ),
 LINESTRING(
 175 -287, 212 -252
 ),
 LINESTRING(
 178 -286, 217 -254
 ),
 LINESTRING(
 152 -306, 119 -288, 101 -293
 ),
 LINESTRING(
 153 -306, 119 -287, 102 -291
 ),
 LINESTRING(
 153 -306, 119 -286, 102 -287
 ),
 LINESTRING(
 153 -306, 120 -284, 103 -286
 ),
 LINESTRING(
 154 -305, 121 -282, 104 -283
 ),
 LINESTRING(
 156 -304, 121 -280, 104 -283
 )
)', 0);

Se deu tudo certo,, você deve conseguir ver uma imagem assim:

Feliz Natal em T-SQL


E ai pessoal,,,

Um Feliz natal para todos vcs !!

Para visualizar o cartão você precisa usar o SSMS em um SQL 2008 ou superior…

What´s Up…

Merry Xmas to you !!!

To see the card you need use the SSMS connected in a SQL Server 2008 or above.

O Arquivo também pode ser baixado aqui.

IF OBJECT_ID('tempdb..#R2') IS NOT NULL
	DROP TABLE #R2;

CREATE TABLE #R2
(
	first int,
	last int,
	y int
);

INSERT INTO #R2 (first, last, y)
VALUES (329, 330, -499),(333, 333, -499),(335, 335, -499),(338, 338, -499),(341, 341, -499),(374, 374, -499),(377, 378, -499),(381, 381, -499),(384, 404, -499),(406, 406, -499),
(409, 409, -499),(325, 342, -498),(345, 346, -498),(357, 357, -498),(360, 361, -498),(363, 367, -498),(369, 412, -498),(415, 415, -498),(318, 318, -497),(321, 415, -497),
(417, 417, -497),(290, 293, -496),(295, 295, -496),(315, 418, -496),(263, 297, -495),(312, 420, -495),(260, 299, -494),(309, 324, -494),(326, 326, -494),(338, 339, -494),
(341, 365, -494),(367, 368, -494),(370, 370, -494),(372, 375, -494),(409, 422, -494),(258, 301, -493),(306, 319, -493),(321, 321, -493),(346, 346, -493),(350, 353, -493),
(355, 355, -493),(358, 358, -493),(413, 424, -493),(257, 265, -492),(267, 317, -492),(415, 425, -492),(256, 262, -491),(264, 266, -491),(270, 273, -491),(275, 284, -491),
(288, 293, -491),(295, 314, -491),(416, 427, -491),(471, 481, -491),(256, 260, -490),(263, 269, -490),(272, 274, -490),(278, 280, -490),(291, 293, -490),(295, 295, -490),
(297, 311, -490),(418, 428, -490),(466, 466, -490),(468, 486, -490),(255, 260, -489),(262, 263, -489),(266, 270, -489),(275, 275, -489),(280, 281, -489),(294, 295, -489),
(299, 310, -489),(420, 430, -489),(463, 489, -489),(256, 260, -488),(262, 262, -488),(266, 267, -488),(270, 272, -488),(275, 276, -488),(281, 282, -488),(295, 296, -488),
(301, 307, -488),(421, 433, -488),(462, 492, -488),(255, 260, -487),(262, 262, -487),(266, 267, -487),(272, 273, -487),(277, 277, -487),(282, 283, -487),(296, 298, -487),
(301, 308, -487),(424, 435, -487),(460, 493, -487),(255, 259, -486),(262, 262, -486),(266, 266, -486),(272, 272, -486),(274, 275, -486),(278, 279, -486),(283, 285, -486),
(298, 299, -486),(302, 307, -486),(427, 436, -486),(459, 470, -486),(476, 476, -486),(484, 495, -486),(255, 260, -485),(263, 263, -485),(266, 266, -485),(275, 276, -485),
(278, 280, -485),(284, 286, -485),(299, 300, -485),(304, 308, -485),(429, 437, -485),(457, 467, -485),(487, 497, -485),(243, 250, -484),(253, 253, -484),(255, 260, -484),
(262, 263, -484),(266, 267, -484),(275, 277, -484),(280, 281, -484),(285, 286, -484),(300, 301, -484),(306, 309, -484),(431, 439, -484),(456, 465, -484),(490, 498, -484),
(241, 260, -483),(263, 263, -483),(266, 267, -483),(277, 278, -483),(280, 282, -483),(286, 288, -483),(301, 303, -483),(307, 310, -483),(433, 440, -483),(455, 463, -483),
(490, 499, -483),(241, 261, -482),(263, 264, -482),(267, 267, -482),(279, 279, -482),(282, 283, -482),(287, 287, -482),(303, 303, -482),(308, 311, -482),(434, 441, -482),
(455, 461, -482),(490, 492, -482),(494, 501, -482),(240, 261, -481),(263, 264, -481),(267, 268, -481),(279, 280, -481),(284, 284, -481),(288, 289, -481),(303, 305, -481),
(309, 312, -481),(436, 442, -481),(454, 459, -481),(490, 491, -481),(495, 501, -481),(173, 178, -480),(184, 184, -480),(240, 244, -480),(248, 261, -480),(264, 265, -480),
(268, 268, -480),(279, 281, -480),(283, 285, -480),(289, 290, -480),(305, 306, -480),(310, 313, -480),(436, 443, -480),(452, 458, -480),(491, 492, -480),(496, 502, -480),
(169, 188, -479),(240, 244, -479),(249, 249, -479),(254, 262, -479),(265, 265, -479),(268, 269, -479),(279, 282, -479),(285, 286, -479),(291, 292, -479),(306, 307, -479),
(311, 314, -479),(438, 444, -479),(451, 457, -479),(491, 491, -479),(498, 503, -479),(166, 192, -478),(240, 244, -478),(249, 250, -478),(256, 256, -478),(258, 258, -478),
(260, 262, -478),(265, 266, -478),(269, 270, -478),(280, 283, -478),(286, 287, -478),(291, 292, -478),(307, 307, -478),(312, 315, -478),(439, 445, -478),(451, 456, -478),
(492, 492, -478),(498, 504, -478),(164, 195, -477),(240, 245, -477),(249, 250, -477),(261, 263, -477),(265, 266, -477),(269, 270, -477),(280, 284, -477),(287, 288, -477),
(292, 293, -477),(307, 309, -477),(312, 316, -477),(439, 446, -477),(450, 455, -477),(491, 491, -477),(498, 505, -477),(162, 177, -476),(180, 180, -476),(182, 199, -476),
(240, 245, -476),(250, 251, -476),(263, 263, -476),(266, 266, -476),(270, 271, -476),(284, 284, -476),(287, 288, -476),(293, 294, -476),(309, 310, -476),(314, 317, -476),
(440, 446, -476),(449, 454, -476),(492, 492, -476),(498, 505, -476),(160, 172, -475),(186, 186, -475),(188, 202, -475),(241, 245, -475),(250, 251, -475),(262, 263, -475),
(266, 267, -475),(270, 271, -475),(281, 281, -475),(284, 286, -475),(288, 289, -475),(294, 295, -475),(310, 310, -475),(314, 318, -475),(441, 453, -475),(491, 491, -475),
(498, 499, -475),(501, 506, -475),(158, 168, -474),(190, 205, -474),(207, 207, -474),(241, 246, -474),(251, 252, -474),(263, 264, -474),(267, 267, -474),(271, 271, -474),
(281, 282, -474),(285, 286, -474),(290, 290, -474),(295, 296, -474),(310, 312, -474),(315, 319, -474),(441, 452, -474),(491, 491, -474),(499, 499, -474),(502, 506, -474),
(156, 165, -473),(194, 209, -473),(242, 247, -473),(252, 253, -473),(264, 264, -473),(267, 268, -473),(281, 282, -473),(285, 287, -473),(290, 291, -473),(296, 297, -473),
(312, 312, -473),(316, 320, -473),(442, 452, -473),(491, 491, -473),(499, 499, -473),(502, 507, -473),(155, 163, -472),(175, 177, -472),(179, 183, -472),(195, 195, -472),
(197, 197, -472),(199, 211, -472),(213, 213, -472),(242, 248, -472),(253, 253, -472),(263, 264, -472),(268, 268, -472),(271, 272, -472),(282, 282, -472),(286, 288, -472),
(291, 293, -472),(297, 297, -472),(312, 313, -472),(318, 321, -472),(443, 451, -472),(491, 492, -472),(498, 499, -472),(504, 507, -472),(154, 161, -471),(170, 177, -471),
(179, 179, -471),(181, 181, -471),(183, 190, -471),(200, 215, -471),(242, 249, -471),(254, 254, -471),(264, 264, -471),(268, 268, -471),(272, 273, -471),(281, 282, -471),
(286, 289, -471),(292, 293, -471),(297, 297, -471),(313, 314, -471),(319, 321, -471),(444, 450, -471),(490, 491, -471),(498, 499, -471),(504, 508, -471),(153, 159, -470),
(168, 170, -470),(184, 184, -470),(189, 194, -470),(204, 218, -470),(244, 249, -470),(254, 255, -470),(264, 264, -470),(267, 268, -470),(272, 272, -470),(282, 282, -470),
(286, 290, -470),(293, 294, -470),(298, 299, -470),(314, 315, -470),(319, 322, -470),(444, 450, -470),(498, 499, -470),(504, 508, -470),(152, 158, -469),(165, 168, -469),
(193, 196, -469),(206, 220, -469),(245, 250, -469),(255, 257, -469),(264, 264, -469),(273, 273, -469),(282, 282, -469),(286, 291, -469),(294, 294, -469),(298, 300, -469),
(315, 315, -469),(319, 323, -469),(444, 450, -469),(490, 490, -469),(498, 498, -469),(505, 509, -469),(152, 156, -468),(162, 162, -468),(164, 165, -468),(167, 167, -468),
(194, 194, -468),(196, 199, -468),(210, 221, -468),(245, 252, -468),(257, 259, -468),(263, 264, -468),(268, 269, -468),(273, 273, -468),(281, 282, -468),(287, 292, -468),
(294, 295, -468),(300, 300, -468),(315, 317, -468),(321, 324, -468),(445, 449, -468),(490, 490, -468),(498, 498, -468),(505, 509, -468),(534, 535, -468),(151, 156, -467),
(162, 163, -467),(199, 200, -467),(202, 203, -467),(205, 205, -467),(212, 223, -467),(246, 253, -467),(259, 263, -467),(268, 268, -467),(272, 273, -467),(281, 282, -467),
(287, 292, -467),(295, 296, -467),(300, 301, -467),(316, 317, -467),(322, 324, -467),(445, 450, -467),(490, 490, -467),(497, 498, -467),(506, 509, -467),(533, 537, -467),
(151, 155, -466),(160, 162, -466),(203, 206, -466),(208, 208, -466),(215, 224, -466),(247, 254, -466),(261, 262, -466),(267, 268, -466),(273, 273, -466),(282, 282, -466),
(286, 293, -466),(296, 296, -466),(301, 303, -466),(317, 318, -466),(322, 325, -466),(446, 450, -466),(489, 489, -466),(497, 497, -466),(506, 510, -466),(522, 522, -466),
(533, 538, -466),(151, 155, -465),(159, 160, -465),(204, 204, -465),(206, 211, -465),(217, 225, -465),(248, 256, -465),(267, 268, -465),(272, 272, -465),(281, 282, -465),
(286, 294, -465),(296, 297, -465),(302, 303, -465),(318, 319, -465),(324, 326, -465),(446, 450, -465),(489, 489, -465),(497, 497, -465),(506, 510, -465),(520, 524, -465),
(531, 539, -465),(150, 154, -464),(158, 159, -464),(211, 214, -464),(220, 226, -464),(249, 258, -464),(266, 266, -464),(271, 272, -464),(281, 282, -464),(286, 288, -464),
(292, 295, -464),(298, 298, -464),(303, 304, -464),(319, 320, -464),(325, 328, -464),(445, 451, -464),(488, 489, -464),(497, 497, -464),(506, 511, -464),(520, 527, -464),
(529, 543, -464),(151, 154, -463),(157, 159, -463),(213, 215, -463),(221, 227, -463),(249, 261, -463),(263, 267, -463),(270, 271, -463),(280, 281, -463),(285, 288, -463),
(292, 295, -463),(298, 299, -463),(303, 305, -463),(319, 320, -463),(325, 330, -463),(446, 452, -463),(488, 488, -463),(496, 496, -463),(507, 511, -463),(520, 546, -463),
(548, 548, -463),(551, 551, -463),(150, 154, -462),(157, 158, -462),(215, 217, -462),(223, 227, -462),(248, 267, -462),(269, 271, -462),(279, 280, -462),(284, 287, -462),
(294, 296, -462),(299, 299, -462),(304, 305, -462),(321, 322, -462),(326, 331, -462),(333, 335, -462),(447, 452, -462),(488, 488, -462),(496, 496, -462),(507, 510, -462),
(520, 553, -462),(151, 155, -461),(158, 158, -461),(217, 219, -461),(223, 228, -461),(247, 253, -461),(259, 272, -461),(278, 280, -461),(284, 287, -461),(294, 297, -461),
(299, 300, -461),(305, 306, -461),(321, 322, -461),(327, 337, -461),(448, 454, -461),(487, 488, -461),(496, 496, -461),(507, 511, -461),(519, 533, -461),(537, 558, -461),
(152, 157, -460),(219, 220, -460),(224, 229, -460),(247, 253, -460),(263, 265, -460),(267, 278, -460),(281, 281, -460),(283, 286, -460),(295, 297, -460),(300, 301, -460),
(306, 306, -460),(321, 323, -460),(327, 339, -460),(448, 454, -460),(495, 496, -460),(507, 510, -460),(518, 522, -460),(524, 532, -460),(539, 560, -460),(152, 157, -459),
(220, 221, -459),(224, 230, -459),(246, 251, -459),(268, 268, -459),(270, 286, -459),(295, 298, -459),(301, 302, -459),(306, 307, -459),(323, 328, -459),(332, 332, -459),
(336, 340, -459),(450, 455, -459),(486, 487, -459),(495, 495, -459),(507, 511, -459),(517, 521, -459),(543, 543, -459),(545, 562, -459),(153, 158, -458),(221, 222, -458),
(226, 231, -458),(246, 251, -458),(274, 285, -458),(296, 299, -458),(302, 302, -458),(307, 308, -458),(323, 326, -458),(337, 341, -458),(451, 456, -458),(485, 486, -458),
(494, 494, -458),(507, 514, -458),(516, 522, -458),(545, 563, -458),(154, 158, -457),(222, 223, -457),(227, 232, -457),(246, 250, -457),(277, 277, -457),(279, 280, -457),
(282, 282, -457),(297, 299, -457),(302, 303, -457),(308, 308, -457),(323, 325, -457),(338, 342, -457),(452, 457, -457),(485, 485, -457),(494, 494, -457),(507, 521, -457),
(544, 553, -457),(556, 564, -457),(154, 158, -456),(223, 223, -456),(227, 233, -456),(245, 250, -456),(297, 300, -456),(303, 304, -456),(308, 309, -456),(323, 323, -456),
(329, 329, -456),(339, 343, -456),(452, 457, -456),(484, 484, -456),(493, 493, -456),(507, 520, -456),(544, 550, -456),(552, 552, -456),(554, 554, -456),(557, 565, -456),
(154, 159, -455),(223, 225, -455),(228, 234, -455),(245, 249, -455),(298, 301, -455),(304, 305, -455),(309, 310, -455),(322, 322, -455),(327, 331, -455),(339, 343, -455),
(454, 459, -455),(483, 484, -455),(493, 493, -455),(507, 519, -455),(543, 548, -455),(550, 555, -455),(559, 565, -455),(155, 159, -454),(225, 225, -454),(229, 234, -454),
(244, 249, -454),(299, 301, -454),(304, 304, -454),(310, 310, -454),(321, 322, -454),(327, 336, -454),(339, 343, -454),(455, 459, -454),(483, 483, -454),(492, 492, -454),
(507, 512, -454),(515, 517, -454),(543, 550, -454),(554, 558, -454),(560, 566, -454),(155, 160, -453),(225, 226, -453),(230, 236, -453),(241, 241, -453),(244, 248, -453),
(299, 302, -453),(305, 305, -453),(310, 311, -453),(321, 321, -453),(327, 332, -453),(334, 339, -453),(342, 344, -453),(455, 460, -453),(482, 483, -453),(491, 492, -453),
(507, 511, -453),(515, 516, -453),(543, 549, -453),(556, 558, -453),(561, 566, -453),(156, 161, -452),(226, 227, -452),(231, 237, -452),(239, 239, -452),(241, 248, -452),
(300, 303, -452),(305, 306, -452),(311, 311, -452),(321, 321, -452),(328, 329, -452),(336, 339, -452),(342, 344, -452),(457, 461, -452),(481, 482, -452),(491, 491, -452),
(507, 510, -452),(516, 517, -452),(543, 548, -452),(558, 559, -452),(562, 565, -452),(157, 162, -451),(226, 227, -451),(232, 248, -451),(300, 303, -451),(305, 305, -451),
(307, 307, -451),(311, 311, -451),(320, 320, -451),(338, 339, -451),(342, 344, -451),(458, 462, -451),(481, 481, -451),(490, 491, -451),(507, 511, -451),(516, 517, -451),
(540, 548, -451),(552, 554, -451),(558, 559, -451),(562, 566, -451),(158, 163, -450),(228, 228, -450),(233, 247, -450),(301, 303, -450),(306, 307, -450),(312, 313, -450),
(321, 321, -450),(338, 340, -450),(342, 344, -450),(458, 462, -450),(480, 481, -450),(489, 490, -450),(506, 511, -450),(517, 517, -450),(539, 547, -450),(552, 555, -450),
(558, 559, -450),(562, 567, -450),(158, 164, -449),(228, 229, -449),(234, 247, -449),(302, 304, -449),(307, 307, -449),(312, 313, -449),(320, 320, -449),(337, 344, -449),
(459, 462, -449),(479, 479, -449),(489, 489, -449),(506, 508, -449),(511, 511, -449),(516, 516, -449),(536, 547, -449),(551, 554, -449),(558, 560, -449),(563, 566, -449),
(159, 165, -448),(230, 231, -448),(235, 247, -448),(302, 305, -448),(307, 308, -448),(313, 314, -448),(320, 320, -448),(336, 337, -448),(340, 344, -448),(422, 426, -448),
(459, 463, -448),(478, 479, -448),(487, 488, -448),(506, 507, -448),(511, 512, -448),(515, 517, -448),(536, 547, -448),(551, 555, -448),(558, 560, -448),(562, 566, -448),
(160, 165, -447),(231, 232, -447),(236, 240, -447),(243, 247, -447),(303, 306, -447),(308, 308, -447),(314, 314, -447),(320, 321, -447),(335, 336, -447),(341, 344, -447),
(420, 422, -447),(424, 425, -447),(427, 428, -447),(460, 464, -447),(477, 478, -447),(487, 488, -447),(505, 507, -447),(511, 516, -447),(535, 539, -447),(542, 548, -447),
(552, 552, -447),(554, 554, -447),(558, 560, -447),(562, 566, -447),(161, 166, -446),(231, 233, -446),(238, 240, -446),(242, 246, -446),(303, 306, -446),(308, 309, -446),
(314, 315, -446),(334, 336, -446),(340, 344, -446),(416, 420, -446),(427, 429, -446),(460, 464, -446),(476, 476, -446),(486, 486, -446),(505, 507, -446),(511, 516, -446),
(534, 537, -446),(542, 549, -446),(557, 559, -446),(562, 567, -446),(569, 575, -446),(579, 579, -446),(162, 166, -445),(233, 234, -445),(243, 245, -445),(304, 306, -445),
(309, 309, -445),(314, 315, -445),(321, 321, -445),(330, 334, -445),(341, 344, -445),(414, 416, -445),(427, 428, -445),(460, 464, -445),(474, 476, -445),(485, 486, -445),
(504, 506, -445),(511, 517, -445),(534, 536, -445),(542, 549, -445),(557, 558, -445),(561, 582, -445),(162, 167, -444),(234, 235, -444),(242, 246, -444),(304, 306, -444),
(309, 310, -444),(315, 316, -444),(322, 322, -444),(329, 333, -444),(341, 343, -444),(412, 414, -444),(425, 427, -444),(461, 465, -444),(473, 474, -444),(504, 507, -444),
(509, 519, -444),(534, 536, -444),(543, 551, -444),(554, 558, -444),(560, 586, -444),(163, 167, -443),(235, 236, -443),(238, 238, -443),(242, 246, -443),(304, 307, -443),
(309, 310, -443),(315, 316, -443),(322, 323, -443),(329, 332, -443),(340, 343, -443),(411, 412, -443),(421, 425, -443),(462, 465, -443),(472, 473, -443),(484, 484, -443),
(503, 512, -443),(516, 519, -443),(533, 535, -443),(543, 556, -443),(560, 590, -443),(164, 168, -442),(236, 238, -442),(242, 246, -442),(305, 307, -442),(309, 311, -442),
(316, 316, -442),(323, 323, -442),(329, 332, -442),(340, 342, -442),(408, 411, -442),(419, 423, -442),(462, 465, -442),(470, 473, -442),(483, 484, -442),(503, 511, -442);

INSERT INTO #R2(first, last, y)
VALUES (517, 520, -442),(527, 527, -442),(533, 541, -442),(544, 549, -442),(551, 551, -442),(553, 554, -442),(559, 594, -442),(164, 169, -441),(239, 246, -441),(306, 308, -441),
(310, 310, -441),(316, 316, -441),(323, 324, -441),(330, 331, -441),(339, 342, -441),(406, 408, -441),(415, 419, -441),(462, 470, -441),(481, 482, -441),(502, 510, -441),
(517, 520, -441),(524, 552, -441),(555, 574, -441),(579, 596, -441),(165, 170, -440),(240, 246, -440),(306, 308, -440),(310, 311, -440),(316, 317, -440),(324, 326, -440),
(337, 341, -440),(405, 406, -440),(413, 416, -440),(462, 469, -440),(480, 482, -440),(502, 505, -440),(507, 507, -440),(509, 509, -440),(518, 521, -440),(523, 534, -440),
(536, 539, -440),(541, 575, -440),(583, 597, -440),(166, 171, -439),(242, 246, -439),(306, 308, -439),(310, 311, -439),(316, 317, -439),(326, 329, -439),(332, 332, -439),
(334, 340, -439),(404, 405, -439),(410, 413, -439),(462, 467, -439),(478, 480, -439),(501, 505, -439),(519, 527, -439),(530, 533, -439),(565, 576, -439),(588, 599, -439),
(166, 172, -438),(242, 246, -438),(306, 309, -438),(311, 311, -438),(316, 317, -438),(328, 339, -438),(403, 404, -438),(408, 410, -438),(463, 466, -438),(477, 478, -438),
(500, 504, -438),(519, 524, -438),(574, 576, -438),(590, 600, -438),(167, 172, -437),(241, 246, -437),(307, 308, -437),(311, 312, -437),(317, 318, -437),(331, 334, -437),
(337, 339, -437),(401, 403, -437),(406, 406, -437),(408, 409, -437),(462, 467, -437),(476, 477, -437),(499, 503, -437),(520, 525, -437),(574, 578, -437),(593, 601, -437),
(168, 174, -436),(242, 246, -436),(307, 309, -436),(311, 312, -436),(317, 317, -436),(332, 334, -436),(337, 340, -436),(399, 401, -436),(405, 407, -436),(463, 467, -436),
(474, 475, -436),(498, 502, -436),(520, 529, -436),(531, 533, -436),(535, 536, -436),(538, 540, -436),(543, 546, -436),(574, 579, -436),(594, 601, -436),(169, 175, -435),
(241, 245, -435),(307, 309, -435),(312, 312, -435),(317, 318, -435),(333, 334, -435),(338, 340, -435),(399, 400, -435),(404, 405, -435),(463, 467, -435),(472, 474, -435),
(497, 501, -435),(520, 579, -435),(597, 601, -435),(171, 177, -434),(241, 245, -434),(307, 309, -434),(311, 312, -434),(317, 317, -434),(333, 334, -434),(338, 340, -434),
(398, 398, -434),(401, 403, -434),(464, 472, -434),(495, 500, -434),(520, 528, -434),(530, 532, -434),(534, 536, -434),(538, 538, -434),(540, 542, -434),(544, 555, -434),
(557, 579, -434),(597, 601, -434),(171, 179, -433),(241, 244, -433),(308, 309, -433),(312, 313, -433),(317, 317, -433),(333, 334, -433),(338, 340, -433),(397, 397, -433),
(400, 402, -433),(464, 469, -433),(494, 499, -433),(520, 523, -433),(546, 548, -433),(552, 554, -433),(560, 563, -433),(567, 579, -433),(597, 602, -433),(172, 179, -432),
(240, 244, -432),(307, 310, -432),(312, 313, -432),(317, 318, -432),(334, 334, -432),(338, 340, -432),(395, 400, -432),(433, 433, -432),(464, 469, -432),(492, 497, -432),
(520, 522, -432),(546, 549, -432),(551, 554, -432),(561, 562, -432),(567, 569, -432),(576, 577, -432),(579, 579, -432),(594, 594, -432),(598, 602, -432),(174, 182, -431),
(240, 243, -431),(308, 310, -431),(313, 313, -431),(318, 318, -431),(334, 334, -431),(338, 340, -431),(394, 399, -431),(431, 435, -431),(465, 469, -431),(490, 496, -431),
(520, 521, -431),(546, 549, -431),(552, 554, -431),(560, 562, -431),(567, 568, -431),(576, 576, -431),(579, 580, -431),(593, 595, -431),(598, 602, -431),(177, 183, -430),
(239, 243, -430),(308, 310, -430),(312, 312, -430),(317, 318, -430),(334, 335, -430),(338, 341, -430),(394, 397, -430),(421, 422, -430),(428, 428, -430),(430, 434, -430),
(465, 470, -430),(488, 495, -430),(520, 522, -430),(546, 548, -430),(551, 554, -430),(560, 562, -430),(566, 569, -430),(571, 572, -430),(574, 577, -430),(580, 580, -430),
(593, 596, -430),(598, 602, -430),(179, 186, -429),(239, 242, -429),(308, 310, -429),(312, 313, -429),(318, 318, -429),(334, 335, -429),(339, 341, -429),(392, 396, -429),
(421, 434, -429),(466, 470, -429),(484, 493, -429),(520, 521, -429),(546, 548, -429),(551, 554, -429),(559, 562, -429),(565, 570, -429),(572, 582, -429),(593, 596, -429),
(598, 602, -429),(180, 186, -428),(216, 225, -428),(239, 241, -428),(308, 311, -428),(313, 313, -428),(317, 318, -428),(334, 334, -428),(339, 341, -428),(392, 394, -428),
(409, 409, -428),(420, 430, -428),(433, 434, -428),(466, 474, -428),(476, 476, -428),(478, 491, -428),(520, 522, -428),(546, 548, -428),(551, 552, -428),(554, 561, -428),
(566, 567, -428),(575, 576, -428),(579, 586, -428),(594, 595, -428),(598, 603, -428),(182, 187, -427),(214, 221, -427),(223, 226, -427),(238, 241, -427),(308, 311, -427),
(313, 313, -427),(318, 318, -427),(334, 335, -427),(338, 340, -427),(390, 394, -427),(407, 409, -427),(420, 422, -427),(425, 425, -427),(427, 427, -427),(432, 434, -427),
(467, 491, -427),(520, 522, -427),(546, 548, -427),(551, 556, -427),(559, 560, -427),(565, 567, -427),(575, 576, -427),(581, 581, -427),(584, 584, -427),(586, 590, -427),
(593, 594, -427),(598, 602, -427),(183, 188, -426),(213, 213, -426),(215, 225, -426),(237, 240, -426),(308, 310, -426),(312, 314, -426),(318, 318, -426),(334, 334, -426),
(339, 341, -426),(389, 391, -426),(407, 410, -426),(420, 422, -426),(433, 434, -426),(468, 487, -426),(489, 491, -426),(520, 522, -426),(545, 552, -426),(554, 555, -426),
(559, 561, -426),(565, 567, -426),(575, 575, -426),(581, 581, -426),(589, 594, -426),(598, 602, -426),(185, 189, -425),(220, 220, -425),(224, 224, -425),(237, 240, -425),
(308, 311, -425),(313, 313, -425),(317, 318, -425),(334, 335, -425),(339, 341, -425),(389, 390, -425),(407, 410, -425),(420, 422, -425),(433, 434, -425),(468, 479, -425),
(481, 481, -425),(483, 483, -425),(485, 486, -425),(490, 491, -425),(520, 522, -425),(546, 552, -425),(555, 556, -425),(558, 560, -425),(565, 566, -425),(575, 575, -425),
(581, 582, -425),(592, 595, -425),(598, 602, -425),(186, 191, -424),(237, 239, -424),(309, 310, -424),(313, 313, -424),(318, 318, -424),(334, 334, -424),(339, 341, -424),
(388, 390, -424),(406, 411, -424),(420, 422, -424),(433, 434, -424),(469, 473, -424),(485, 486, -424),(490, 490, -424),(520, 522, -424),(546, 550, -424),(555, 559, -424),
(565, 566, -424),(574, 574, -424),(581, 581, -424),(593, 602, -424),(186, 192, -423),(199, 202, -423),(236, 239, -423),(309, 311, -423),(313, 313, -423),(317, 318, -423),
(334, 335, -423),(339, 341, -423),(387, 389, -423),(405, 406, -423),(409, 412, -423),(419, 421, -423),(433, 435, -423),(469, 473, -423),(485, 486, -423),(490, 491, -423),
(520, 522, -423),(546, 548, -423),(550, 551, -423),(556, 559, -423),(564, 566, -423),(574, 575, -423),(582, 582, -423),(593, 593, -423),(596, 602, -423),(187, 198, -422),
(201, 201, -422),(221, 221, -422),(236, 239, -422),(309, 313, -422),(318, 318, -422),(334, 334, -422),(339, 340, -422),(386, 387, -422),(402, 407, -422),(410, 413, -422),
(419, 421, -422),(432, 435, -422),(470, 473, -422),(486, 486, -422),(490, 490, -422),(520, 522, -422),(546, 550, -422),(556, 559, -422),(564, 566, -422),(574, 574, -422),
(582, 582, -422),(593, 593, -422),(597, 603, -422),(189, 194, -421),(196, 196, -421),(201, 202, -421),(215, 223, -421),(235, 238, -421),(308, 311, -421),(313, 313, -421),
(318, 318, -421),(334, 335, -421),(339, 340, -421),(386, 386, -421),(401, 404, -421),(411, 414, -421),(418, 420, -421),(433, 435, -421),(470, 473, -421),(485, 486, -421),
(490, 491, -421),(520, 522, -421),(546, 551, -421),(556, 558, -421),(564, 565, -421),(574, 574, -421),(582, 582, -421),(593, 593, -421),(596, 602, -421),(189, 194, -420),
(200, 201, -420),(212, 218, -420),(222, 224, -420),(235, 238, -420),(309, 311, -420),(313, 313, -420),(318, 318, -420),(334, 334, -420),(339, 341, -420),(385, 386, -420),
(400, 403, -420),(412, 420, -420),(433, 435, -420),(470, 474, -420),(485, 486, -420),(520, 522, -420),(547, 550, -420),(556, 558, -420),(564, 565, -420),(573, 573, -420),
(582, 583, -420),(592, 593, -420),(596, 602, -420),(190, 195, -419),(199, 200, -419),(209, 213, -419),(219, 219, -419),(221, 223, -419),(235, 238, -419),(309, 311, -419),
(313, 313, -419),(318, 318, -419),(339, 341, -419),(384, 385, -419),(401, 403, -419),(413, 418, -419),(433, 435, -419),(471, 473, -419),(486, 486, -419),(490, 491, -419),
(520, 522, -419),(546, 550, -419),(556, 558, -419),(564, 565, -419),(573, 573, -419),(583, 583, -419),(593, 593, -419),(596, 601, -419),(190, 197, -418),(199, 200, -418),
(208, 222, -418),(234, 238, -418),(308, 311, -418),(313, 314, -418),(318, 318, -418),(333, 334, -418),(338, 340, -418),(384, 384, -418),(401, 403, -418),(415, 419, -418),
(433, 436, -418),(471, 474, -418),(485, 486, -418),(490, 491, -418),(520, 522, -418),(546, 550, -418),(555, 558, -418),(564, 565, -418),(573, 573, -418),(583, 583, -418),
(592, 592, -418),(596, 600, -418),(191, 199, -417),(207, 210, -417),(212, 213, -417),(215, 216, -417),(235, 238, -417),(309, 310, -417),(313, 313, -417),(318, 318, -417),
(333, 334, -417),(338, 340, -417),(382, 383, -417),(402, 404, -417),(416, 419, -417),(434, 436, -417),(471, 475, -417),(485, 486, -417),(490, 491, -417),(520, 522, -417),
(547, 550, -417),(554, 557, -417),(564, 564, -417),(573, 573, -417),(583, 584, -417),(591, 592, -417),(597, 601, -417),(192, 198, -416),(205, 207, -416),(234, 237, -416),
(309, 311, -416),(313, 314, -416),(318, 318, -416),(333, 334, -416),(338, 340, -416),(382, 382, -416),(402, 403, -416),(417, 420, -416),(433, 436, -416),(472, 474, -416),
(486, 486, -416),(490, 490, -416),(520, 522, -416),(546, 550, -416),(554, 557, -416),(563, 564, -416),(572, 573, -416),(584, 584, -416),(592, 592, -416),(597, 600, -416),
(192, 198, -415),(204, 205, -415),(234, 237, -415),(309, 311, -415),(313, 314, -415),(318, 318, -415),(333, 334, -415),(338, 340, -415),(381, 382, -415),(401, 404, -415),
(417, 419, -415),(433, 436, -415),(472, 475, -415),(486, 486, -415),(490, 491, -415),(520, 522, -415),(546, 550, -415),(553, 556, -415),(563, 564, -415),(572, 572, -415),
(584, 584, -415),(591, 591, -415),(597, 600, -415),(194, 197, -414),(203, 204, -414),(234, 237, -414),(309, 311, -414),(313, 313, -414),(317, 318, -414),(333, 333, -414),
(338, 340, -414),(381, 381, -414),(401, 403, -414),(417, 419, -414),(431, 434, -414),(472, 474, -414),(490, 490, -414),(520, 521, -414),(547, 550, -414),(552, 556, -414),
(562, 563, -414),(572, 572, -414),(584, 585, -414),(592, 592, -414),(597, 601, -414),(194, 197, -413),(202, 202, -413),(234, 237, -413),(309, 311, -413),(313, 313, -413),
(318, 318, -413),(333, 333, -413),(337, 340, -413),(381, 381, -413),(401, 403, -413),(416, 419, -413),(431, 433, -413),(472, 474, -413),(486, 486, -413),(491, 491, -413),
(520, 522, -413),(546, 554, -413),(562, 563, -413),(571, 572, -413),(584, 585, -413),(591, 592, -413),(597, 601, -413),(194, 198, -412),(201, 202, -412),(230, 231, -412),
(233, 237, -412),(308, 311, -412),(313, 313, -412),(317, 318, -412),(333, 333, -412),(337, 340, -412),(380, 380, -412),(401, 403, -412),(417, 418, -412),(431, 433, -412),
(472, 475, -412),(486, 486, -412),(490, 490, -412),(520, 522, -412),(547, 554, -412),(562, 563, -412),(571, 571, -412),(585, 585, -412),(591, 591, -412),(597, 600, -412),
(194, 201, -411),(229, 232, -411),(234, 238, -411),(309, 311, -411),(313, 314, -411),(317, 318, -411),(332, 333, -411),(337, 340, -411),(380, 380, -411),(400, 403, -411),
(416, 418, -411),(430, 432, -411),(472, 475, -411),(485, 486, -411),(520, 522, -411),(546, 552, -411),(562, 563, -411),(571, 571, -411),(585, 585, -411),(590, 591, -411),
(597, 601, -411),(194, 200, -410),(229, 230, -410),(232, 238, -410),(308, 310, -410),(313, 313, -410),(317, 317, -410),(333, 333, -410),(337, 339, -410),(379, 380, -410),
(400, 402, -410),(416, 419, -410),(430, 432, -410),(472, 475, -410),(491, 491, -410),(520, 522, -410),(547, 551, -410),(561, 563, -410),(571, 571, -410),(585, 586, -410),
(591, 591, -410),(597, 600, -410),(194, 200, -409),(230, 230, -409),(233, 238, -409),(308, 310, -409),(313, 313, -409),(317, 317, -409),(332, 333, -409),(338, 339, -409),
(378, 379, -409),(399, 401, -409),(417, 418, -409),(430, 432, -409),(435, 437, -409),(473, 475, -409),(486, 486, -409),(491, 491, -409),(520, 522, -409),(545, 550, -409),
(560, 562, -409),(570, 571, -409),(586, 586, -409),(597, 601, -409),(195, 199, -408),(230, 231, -408),(233, 237, -408),(308, 310, -408),(312, 312, -408),(317, 318, -408),
(332, 333, -408),(337, 339, -408),(378, 378, -408),(399, 401, -408),(416, 418, -408),(429, 431, -408),(435, 438, -408),(473, 475, -408),(486, 486, -408),(491, 491, -408),
(520, 522, -408),(546, 549, -408),(559, 563, -408),(570, 570, -408),(587, 587, -408),(591, 591, -408),(597, 600, -408),(195, 199, -407),(232, 237, -407),(308, 310, -407),
(312, 312, -407),(317, 318, -407),(331, 333, -407),(336, 339, -407),(377, 378, -407),(399, 402, -407),(417, 419, -407),(430, 431, -407),(435, 436, -407),(438, 439, -407),
(473, 475, -407),(520, 522, -407),(544, 547, -407),(559, 563, -407),(570, 570, -407),(586, 586, -407),(591, 591, -407),(597, 600, -407),(194, 198, -406),(233, 238, -406),
(308, 310, -406),(312, 313, -406),(317, 317, -406),(332, 341, -406),(377, 378, -406),(399, 402, -406),(416, 419, -406),(429, 431, -406),(436, 436, -406),(438, 439, -406),
(473, 476, -406),(486, 486, -406),(490, 490, -406),(520, 522, -406),(544, 546, -406),(558, 561, -406),(563, 563, -406),(570, 570, -406),(586, 587, -406),(591, 591, -406),
(597, 601, -406),(194, 198, -405),(233, 238, -405),(307, 310, -405),(312, 312, -405),(317, 318, -405),(332, 342, -405),(377, 377, -405),(400, 403, -405),(417, 419, -405),
(430, 431, -405),(436, 437, -405),(439, 440, -405),(473, 475, -405),(486, 486, -405),(491, 491, -405),(520, 522, -405),(542, 544, -405),(557, 560, -405),(563, 564, -405),
(569, 570, -405),(587, 587, -405),(590, 591, -405),(597, 601, -405),(193, 197, -404),(234, 237, -404),(307, 309, -404),(312, 313, -404),(317, 317, -404),(329, 333, -404),
(335, 336, -404),(338, 343, -404),(376, 376, -404),(401, 402, -404),(417, 420, -404),(429, 431, -404),(437, 438, -404),(440, 440, -404),(473, 476, -404),(491, 491, -404),
(520, 524, -404),(526, 526, -404),(528, 530, -404),(540, 543, -404),(557, 560, -404),(563, 564, -404),(569, 571, -404),(573, 574, -404),(576, 576, -404),(587, 588, -404),
(590, 590, -404),(597, 600, -404),(193, 197, -403),(234, 238, -403),(307, 309, -403),(312, 313, -403),(316, 317, -403),(329, 330, -403),(340, 344, -403),(375, 376, -403),
(401, 403, -403),(418, 420, -403),(430, 431, -403),(438, 438, -403),(440, 441, -403),(473, 476, -403),(485, 486, -403),(491, 491, -403),(520, 534, -403),(538, 541, -403),
(557, 571, -403),(573, 588, -403),(590, 590, -403),(597, 601, -403),(193, 197, -402),(233, 238, -402),(308, 309, -402),(311, 312, -402),(316, 316, -402),(327, 329, -402),
(336, 336, -402),(342, 345, -402),(375, 376, -402),(401, 402, -402),(417, 420, -402),(428, 431, -402),(438, 438, -402),(441, 441, -402),(473, 476, -402),(486, 486, -402),
(490, 490, -402),(520, 540, -402),(556, 560, -402),(562, 562, -402),(564, 570, -402),(582, 582, -402),(584, 584, -402),(586, 592, -402),(597, 600, -402),(193, 196, -401),
(234, 237, -401),(308, 309, -401),(312, 312, -401),(316, 317, -401),(327, 327, -401),(335, 338, -401),(342, 345, -401),(375, 375, -401),(401, 403, -401),(415, 419, -401),
(427, 431, -401),(439, 442, -401),(474, 476, -401),(520, 522, -401),(527, 527, -401),(531, 539, -401),(555, 558, -401),(564, 565, -401),(568, 568, -401),(587, 602, -401);

INSERT INTO #R2(first, last, y)
VALUES (192, 196, -400),(234, 238, -400),(307, 309, -400),(311, 312, -400),(317, 317, -400),(326, 327, -400),(335, 338, -400),(344, 346, -400),(375, 375, -400),(401, 403, -400),
(416, 418, -400),(427, 429, -400),(431, 431, -400),(440, 442, -400),(474, 476, -400),(486, 486, -400),(491, 491, -400),(520, 522, -400),(555, 557, -400),(565, 568, -400),
(588, 591, -400),(593, 593, -400),(595, 595, -400),(597, 602, -400),(192, 196, -399),(234, 237, -399),(307, 309, -399),(311, 312, -399),(316, 316, -399),(326, 326, -399),
(335, 339, -399),(344, 346, -399),(374, 375, -399),(401, 403, -399),(415, 417, -399),(425, 427, -399),(440, 442, -399),(474, 477, -399),(486, 486, -399),(491, 491, -399),
(520, 521, -399),(554, 557, -399),(565, 568, -399),(588, 591, -399),(599, 602, -399),(192, 196, -398),(234, 238, -398),(307, 309, -398),(312, 312, -398),(316, 317, -398),
(325, 325, -398),(335, 339, -398),(344, 346, -398),(374, 374, -398),(401, 404, -398),(415, 416, -398),(424, 426, -398),(441, 443, -398),(475, 477, -398),(490, 490, -398),
(520, 522, -398),(554, 556, -398),(565, 569, -398),(588, 590, -398),(599, 603, -398),(191, 195, -397),(234, 237, -397),(306, 309, -397),(312, 312, -397),(316, 316, -397),
(325, 326, -397),(338, 339, -397),(345, 346, -397),(373, 374, -397),(400, 405, -397),(414, 415, -397),(424, 426, -397),(441, 444, -397),(448, 448, -397),(475, 477, -397),
(486, 486, -397),(520, 521, -397),(553, 556, -397),(565, 568, -397),(588, 590, -397),(600, 603, -397),(191, 195, -396),(233, 237, -396),(307, 309, -396),(311, 312, -396),
(315, 316, -396),(325, 325, -396),(339, 340, -396),(345, 346, -396),(373, 374, -396),(401, 407, -396),(414, 416, -396),(423, 425, -396),(440, 452, -396),(454, 454, -396),
(475, 477, -396),(486, 486, -396),(491, 491, -396),(520, 521, -396),(553, 555, -396),(566, 567, -396),(588, 590, -396),(600, 602, -396),(191, 195, -395),(233, 237, -395),
(307, 308, -395),(310, 311, -395),(316, 316, -395),(325, 325, -395),(330, 330, -395),(339, 340, -395),(344, 346, -395),(373, 373, -395),(403, 407, -395),(413, 415, -395),
(423, 424, -395),(437, 456, -395),(475, 477, -395),(485, 485, -395),(491, 491, -395),(520, 522, -395),(553, 555, -395),(588, 590, -395),(600, 603, -395),(191, 194, -394),
(234, 237, -394),(306, 308, -394),(311, 312, -394),(315, 316, -394),(324, 325, -394),(329, 331, -394),(340, 340, -394),(343, 347, -394),(372, 372, -394),(405, 407, -394),
(413, 415, -394),(423, 424, -394),(434, 443, -394),(447, 458, -394),(476, 477, -394),(486, 486, -394),(491, 491, -394),(520, 521, -394),(552, 555, -394),(600, 602, -394),
(191, 194, -393),(198, 198, -393),(234, 237, -393),(249, 251, -393),(306, 308, -393),(311, 311, -393),(315, 315, -393),(325, 325, -393),(329, 332, -393),(339, 341, -393),
(343, 346, -393),(372, 373, -393),(406, 408, -393),(413, 416, -393),(418, 418, -393),(420, 424, -393),(430, 438, -393),(452, 460, -393),(476, 478, -393),(486, 486, -393),
(519, 521, -393),(552, 554, -393),(599, 603, -393),(191, 195, -392),(197, 198, -392),(234, 238, -392),(248, 251, -392),(306, 308, -392),(311, 311, -392),(315, 316, -392),
(324, 325, -392),(328, 333, -392),(336, 336, -392),(339, 346, -392),(372, 372, -392),(407, 409, -392),(413, 415, -392),(417, 425, -392),(429, 434, -392),(436, 436, -392),
(454, 461, -392),(476, 478, -392),(491, 491, -392),(519, 520, -392),(552, 555, -392),(557, 558, -392),(561, 561, -392),(563, 567, -392),(569, 571, -392),(573, 575, -392),
(577, 578, -392),(580, 586, -392),(589, 590, -392),(600, 603, -392),(190, 197, -391),(234, 238, -391),(248, 248, -391),(252, 252, -391),(306, 308, -391),(311, 311, -391),
(315, 316, -391),(325, 325, -391),(329, 342, -391),(344, 347, -391),(372, 372, -391),(406, 425, -391),(427, 432, -391),(456, 462, -391),(476, 478, -391),(486, 486, -391),
(490, 491, -391),(520, 521, -391),(552, 561, -391),(563, 563, -391),(565, 566, -391),(569, 569, -391),(577, 577, -391),(582, 582, -391),(584, 584, -391),(586, 586, -391),
(588, 594, -391),(600, 603, -391),(190, 196, -390),(234, 238, -390),(248, 249, -390),(251, 251, -390),(306, 308, -390),(310, 310, -390),(315, 315, -390),(325, 326, -390),
(334, 341, -390),(344, 346, -390),(371, 371, -390),(406, 418, -390),(421, 421, -390),(423, 429, -390),(456, 457, -390),(460, 462, -390),(476, 477, -390),(486, 486, -390),
(491, 491, -390),(519, 521, -390),(552, 556, -390),(593, 603, -390),(190, 195, -389),(235, 238, -389),(248, 249, -389),(251, 251, -389),(305, 307, -389),(310, 311, -389),
(315, 316, -389),(326, 327, -389),(339, 340, -389),(343, 345, -389),(370, 371, -389),(405, 408, -389),(412, 416, -389),(423, 427, -389),(458, 458, -389),(460, 463, -389),
(476, 478, -389),(491, 492, -389),(519, 521, -389),(553, 555, -389),(597, 603, -389),(189, 194, -388),(235, 239, -388),(248, 248, -388),(252, 252, -388),(305, 307, -388),
(309, 310, -388),(315, 315, -388),(327, 328, -388),(339, 340, -388),(342, 345, -388),(371, 371, -388),(406, 407, -388),(413, 416, -388),(421, 425, -388),(458, 459, -388),
(461, 463, -388),(475, 478, -388),(486, 486, -388),(490, 491, -388),(519, 521, -388),(553, 556, -388),(597, 603, -388),(188, 193, -387),(235, 239, -387),(248, 248, -387),
(252, 252, -387),(305, 307, -387),(309, 310, -387),(315, 315, -387),(327, 329, -387),(338, 345, -387),(371, 371, -387),(405, 406, -387),(413, 423, -387),(459, 459, -387),
(462, 464, -387),(476, 477, -387),(485, 486, -387),(491, 492, -387),(519, 521, -387),(554, 557, -387),(594, 602, -387),(187, 193, -386),(236, 240, -386),(248, 248, -386),
(251, 251, -386),(305, 307, -386),(310, 310, -386),(314, 315, -386),(327, 330, -386),(333, 333, -386),(337, 344, -386),(370, 370, -386),(406, 407, -386),(414, 421, -386),
(459, 460, -386),(462, 465, -386),(476, 478, -386),(491, 491, -386),(519, 520, -386),(554, 559, -386),(561, 561, -386),(589, 602, -386),(187, 192, -385),(236, 241, -385),
(248, 248, -385),(251, 252, -385),(305, 307, -385),(309, 310, -385),(314, 315, -385),(327, 333, -385),(335, 344, -385),(370, 370, -385),(406, 407, -385),(414, 422, -385),
(459, 460, -385),(463, 465, -385),(475, 477, -385),(486, 486, -385),(491, 491, -385),(520, 521, -385),(555, 564, -385),(567, 568, -385),(570, 570, -385),(576, 576, -385),
(579, 580, -385),(582, 582, -385),(585, 601, -385),(187, 192, -384),(237, 241, -384),(248, 248, -384),(251, 251, -384),(305, 306, -384),(309, 309, -384),(313, 314, -384),
(327, 328, -384),(332, 341, -384),(370, 370, -384),(405, 407, -384),(412, 415, -384),(420, 425, -384),(460, 461, -384),(463, 465, -384),(475, 477, -384),(486, 486, -384),
(491, 492, -384),(519, 521, -384),(555, 598, -384),(186, 191, -383),(212, 212, -383),(215, 221, -383),(223, 223, -383),(225, 225, -383),(227, 227, -383),(237, 241, -383),
(247, 248, -383),(250, 251, -383),(305, 306, -383),(309, 309, -383),(313, 314, -383),(327, 328, -383),(332, 340, -383),(369, 370, -383),(406, 408, -383),(410, 414, -383),
(422, 427, -383),(460, 461, -383),(463, 465, -383),(475, 477, -383),(486, 486, -383),(491, 491, -383),(519, 521, -383),(556, 596, -383),(186, 191, -382),(209, 210, -382),
(212, 212, -382),(214, 214, -382),(217, 218, -382),(221, 222, -382),(225, 228, -382),(230, 230, -382),(233, 233, -382),(238, 242, -382),(247, 248, -382),(250, 250, -382),
(304, 305, -382),(308, 309, -382),(313, 314, -382),(326, 327, -382),(331, 335, -382),(337, 337, -382),(369, 370, -382),(405, 413, -382),(424, 430, -382),(461, 462, -382),
(464, 466, -382),(474, 477, -382),(486, 486, -382),(491, 492, -382),(519, 521, -382),(555, 589, -382),(591, 591, -382),(593, 593, -382),(185, 190, -381),(206, 211, -381),
(229, 232, -381),(234, 235, -381),(237, 243, -381),(248, 250, -381),(304, 306, -381),(308, 308, -381),(314, 314, -381),(326, 326, -381),(331, 333, -381),(349, 349, -381),
(369, 369, -381),(404, 412, -381),(425, 430, -381),(432, 432, -381),(461, 467, -381),(474, 477, -381),(485, 486, -381),(490, 491, -381),(519, 521, -381),(556, 584, -381),
(586, 586, -381),(185, 190, -380),(205, 207, -380),(235, 243, -380),(247, 247, -380),(249, 250, -380),(304, 306, -380),(308, 309, -380),(313, 313, -380),(325, 326, -380),
(331, 333, -380),(348, 350, -380),(369, 369, -380),(403, 405, -380),(427, 428, -380),(431, 432, -380),(462, 462, -380),(464, 467, -380),(475, 476, -380),(491, 491, -380),
(520, 522, -380),(556, 560, -380),(565, 565, -380),(567, 567, -380),(569, 570, -380),(572, 575, -380),(577, 577, -380),(579, 579, -380),(582, 582, -380),(185, 189, -379),
(203, 204, -379),(239, 243, -379),(247, 249, -379),(304, 305, -379),(308, 309, -379),(313, 313, -379),(325, 326, -379),(330, 332, -379),(347, 350, -379),(369, 369, -379),
(402, 405, -379),(428, 429, -379),(432, 434, -379),(461, 465, -379),(467, 467, -379),(474, 476, -379),(486, 486, -379),(491, 492, -379),(520, 521, -379),(556, 560, -379),
(184, 189, -378),(201, 204, -378),(240, 249, -378),(303, 306, -378),(308, 309, -378),(312, 314, -378),(325, 325, -378),(330, 332, -378),(347, 348, -378),(350, 350, -378),
(368, 369, -378),(401, 404, -378),(429, 429, -378),(433, 434, -378),(447, 448, -378),(462, 465, -378),(467, 468, -378),(475, 477, -378),(490, 491, -378),(519, 522, -378),
(557, 561, -378),(184, 189, -377),(199, 201, -377),(213, 213, -377),(216, 217, -377),(220, 220, -377),(225, 226, -377),(240, 248, -377),(303, 305, -377),(308, 308, -377),
(313, 313, -377),(325, 325, -377),(329, 332, -377),(347, 347, -377),(350, 350, -377),(368, 368, -377),(400, 403, -377),(430, 431, -377),(434, 436, -377),(442, 450, -377),
(462, 468, -377),(474, 476, -377),(486, 486, -377),(491, 491, -377),(519, 521, -377),(557, 561, -377),(183, 189, -376),(197, 199, -376),(208, 215, -376),(219, 219, -376),
(221, 230, -376),(241, 247, -376),(303, 305, -376),(307, 308, -376),(312, 312, -376),(324, 325, -376),(328, 331, -376),(346, 346, -376),(349, 350, -376),(368, 368, -376),
(400, 402, -376),(431, 431, -376),(435, 451, -376),(461, 466, -376),(468, 469, -376),(474, 476, -376),(486, 486, -376),(491, 492, -376),(519, 521, -376),(557, 561, -376),
(575, 577, -376),(182, 189, -375),(195, 198, -375),(206, 209, -375),(211, 211, -375),(228, 234, -375),(241, 247, -375),(303, 305, -375),(308, 308, -375),(312, 313, -375),
(324, 325, -375),(328, 331, -375),(345, 347, -375),(349, 349, -375),(368, 369, -375),(399, 401, -375),(431, 432, -375),(436, 442, -375),(449, 452, -375),(461, 466, -375),
(468, 469, -375),(474, 476, -375),(486, 486, -375),(491, 491, -375),(519, 522, -375),(557, 561, -375),(573, 578, -375),(181, 195, -374),(203, 206, -374),(234, 237, -374),
(239, 247, -374),(303, 308, -374),(312, 312, -374),(324, 324, -374),(328, 330, -374),(349, 350, -374),(368, 368, -374),(398, 400, -374),(431, 432, -374),(436, 442, -374),
(450, 454, -374),(460, 463, -374),(466, 469, -374),(475, 477, -374),(486, 486, -374),(491, 491, -374),(520, 521, -374),(557, 561, -374),(572, 582, -374),(584, 584, -374),
(180, 193, -373),(202, 204, -373),(236, 236, -373),(238, 246, -373),(302, 305, -373),(307, 308, -373),(312, 312, -373),(324, 324, -373),(328, 331, -373),(345, 346, -373),
(349, 349, -373),(397, 400, -373),(432, 432, -373),(436, 437, -373),(440, 441, -373),(452, 462, -373),(467, 469, -373),(474, 476, -373),(485, 485, -373),(490, 491, -373),
(520, 521, -373),(558, 561, -373),(570, 586, -373),(179, 190, -372),(200, 202, -372),(240, 245, -372),(303, 305, -372),(307, 307, -372),(312, 312, -372),(323, 324, -372),
(328, 330, -372),(345, 345, -372),(348, 349, -372),(368, 368, -372),(396, 399, -372),(432, 433, -372),(437, 437, -372),(440, 442, -372),(453, 462, -372),(467, 469, -372),
(474, 477, -372),(486, 486, -372),(491, 492, -372),(519, 522, -372),(557, 561, -372),(569, 587, -372),(178, 186, -371),(198, 200, -371),(240, 245, -371),(302, 305, -371),
(307, 307, -371),(312, 312, -371),(323, 324, -371),(327, 330, -371),(345, 346, -371),(348, 349, -371),(396, 398, -371),(432, 433, -371),(437, 437, -371),(440, 442, -371),
(454, 461, -371),(467, 469, -371),(474, 476, -371),(486, 486, -371),(491, 491, -371),(519, 521, -371),(558, 561, -371),(569, 588, -371),(177, 182, -370),(197, 199, -370),
(241, 244, -370),(302, 305, -370),(307, 307, -370),(311, 312, -370),(323, 323, -370),(327, 330, -370),(345, 345, -370),(348, 348, -370),(367, 368, -370),(395, 397, -370),
(433, 434, -370),(437, 437, -370),(440, 443, -370),(456, 460, -370),(468, 469, -370),(473, 476, -370),(486, 486, -370),(491, 492, -370),(519, 522, -370),(531, 532, -370),
(535, 536, -370),(538, 538, -370),(557, 561, -370),(568, 573, -370),(577, 588, -370),(177, 181, -369),(195, 197, -369),(240, 244, -369),(302, 304, -369),(306, 307, -369),
(311, 312, -369),(323, 324, -369),(327, 329, -369),(344, 345, -369),(348, 348, -369),(368, 368, -369),(394, 397, -369),(433, 433, -369),(437, 438, -369),(440, 442, -369),
(468, 469, -369),(474, 476, -369),(486, 486, -369),(491, 491, -369),(519, 524, -369),(526, 541, -369),(558, 562, -369),(566, 573, -369),(578, 581, -369),(584, 588, -369),
(177, 181, -368),(193, 195, -368),(240, 243, -368),(301, 304, -368),(306, 306, -368),(311, 311, -368),(323, 323, -368),(327, 329, -368),(344, 344, -368),(347, 348, -368),
(367, 368, -368),(393, 398, -368),(433, 434, -368),(437, 437, -368),(440, 442, -368),(468, 469, -368),(474, 476, -368),(486, 486, -368),(490, 492, -368),(519, 528, -368),
(540, 540, -368),(542, 544, -368),(557, 561, -368),(563, 573, -368),(577, 580, -368),(585, 588, -368),(176, 180, -367),(190, 194, -367),(240, 243, -367),(302, 304, -367),
(306, 307, -367),(311, 311, -367),(322, 323, -367),(327, 329, -367),(344, 345, -367),(347, 348, -367),(367, 367, -367),(393, 398, -367),(413, 414, -367),(417, 417, -367),
(419, 425, -367),(433, 434, -367),(437, 437, -367),(440, 443, -367),(468, 469, -367),(473, 476, -367),(479, 479, -367),(485, 487, -367),(491, 492, -367),(495, 495, -367),
(505, 505, -367),(509, 509, -367),(517, 528, -367),(544, 545, -367),(558, 573, -367),(579, 579, -367),(585, 588, -367),(177, 180, -366),(186, 190, -366),(192, 192, -366),
(240, 243, -366),(301, 304, -366),(306, 306, -366),(311, 312, -366),(322, 323, -366),(326, 329, -366),(344, 344, -366),(347, 347, -366),(367, 368, -366),(392, 401, -366),
(413, 419, -366),(423, 424, -366),(434, 434, -366),(437, 437, -366),(440, 442, -366),(469, 469, -366),(473, 528, -366),(531, 532, -366),(535, 535, -366),(545, 547, -366),
(558, 574, -366),(584, 588, -366),(177, 180, -365),(185, 187, -365),(189, 189, -365),(239, 243, -365),(302, 304, -365),(306, 306, -365),(311, 312, -365),(323, 323, -365),
(327, 328, -365),(344, 344, -365),(347, 347, -365),(367, 367, -365),(391, 394, -365),(398, 398, -365),(400, 402, -365),(424, 425, -365),(433, 434, -365),(436, 438, -365),
(441, 442, -365),(469, 469, -365),(473, 487, -365),(489, 538, -365),(547, 548, -365),(559, 571, -365),(573, 574, -365),(584, 587, -365),(176, 180, -364),(182, 184, -364),
(239, 242, -364),(301, 304, -364),(306, 306, -364),(311, 311, -364),(322, 323, -364),(326, 328, -364),(344, 344, -364),(347, 348, -364),(380, 380, -364),(391, 393, -364),
(402, 405, -364),(424, 425, -364),(434, 434, -364),(436, 437, -364),(440, 442, -364),(469, 470, -364),(472, 487, -364),(491, 499, -364),(510, 529, -364),(536, 541, -364),
(548, 549, -364),(559, 567, -364),(569, 570, -364),(573, 575, -364),(584, 587, -364),(176, 183, -363),(239, 241, -363),(301, 306, -363),(311, 311, -363),(322, 323, -363),
(327, 328, -363),(344, 344, -363),(346, 347, -363),(358, 358, -363),(367, 367, -363),(379, 381, -363),(390, 392, -363),(404, 406, -363),(408, 408, -363),(423, 426, -363);

INSERT INTO #R2(first, last, y)
VALUES (433, 434, -363),(436, 437, -363),(440, 442, -363),(469, 469, -363),(472, 481, -363),(483, 487, -363),(491, 492, -363),(495, 497, -363),(511, 519, -363),(521, 529, -363),
(540, 544, -363),(549, 551, -363),(560, 565, -363),(570, 570, -363),(573, 574, -363),(583, 587, -363),(177, 182, -362),(212, 212, -362),(214, 214, -362),(216, 216, -362),
(239, 242, -362),(301, 304, -362),(306, 306, -362),(311, 311, -362),(322, 323, -362),(326, 329, -362),(344, 344, -362),(347, 347, -362),(357, 358, -362),(366, 367, -362),
(378, 380, -362),(390, 392, -362),(406, 406, -362),(408, 423, -362),(425, 426, -362),(433, 436, -362),(440, 442, -362),(469, 478, -362),(482, 486, -362),(492, 492, -362),
(497, 499, -362),(512, 518, -362),(526, 530, -362),(543, 546, -362),(550, 551, -362),(560, 563, -362),(570, 575, -362),(583, 586, -362),(176, 181, -361),(209, 217, -361),
(239, 242, -361),(301, 303, -361),(305, 306, -361),(323, 323, -361),(326, 328, -361),(344, 347, -361),(356, 359, -361),(367, 367, -361),(377, 381, -361),(389, 391, -361),
(413, 414, -361),(416, 416, -361),(419, 420, -361),(426, 428, -361),(433, 436, -361),(440, 441, -361),(469, 475, -361),(482, 488, -361),(490, 492, -361),(498, 500, -361),
(512, 517, -361),(526, 530, -361),(546, 547, -361),(551, 552, -361),(561, 562, -361),(571, 572, -361),(576, 577, -361),(582, 586, -361),(177, 181, -360),(207, 209, -360),
(217, 219, -360),(239, 241, -360),(302, 303, -360),(305, 306, -360),(311, 311, -360),(322, 323, -360),(327, 329, -360),(344, 346, -360),(355, 356, -360),(358, 359, -360),
(367, 368, -360),(377, 377, -360),(380, 380, -360),(389, 391, -360),(427, 428, -360),(433, 435, -360),(440, 442, -360),(470, 474, -360),(480, 482, -360),(484, 485, -360),
(487, 491, -360),(499, 501, -360),(512, 517, -360),(526, 530, -360),(548, 549, -360),(552, 553, -360),(560, 561, -360),(576, 586, -360),(177, 180, -359),(205, 207, -359),
(218, 231, -359),(233, 233, -359),(235, 235, -359),(237, 237, -359),(239, 241, -359),(302, 303, -359),(306, 306, -359),(310, 311, -359),(322, 324, -359),(326, 329, -359),
(344, 346, -359),(356, 357, -359),(359, 359, -359),(366, 367, -359),(376, 377, -359),(380, 380, -359),(388, 390, -359),(428, 429, -359),(431, 434, -359),(439, 441, -359),
(469, 472, -359),(480, 481, -359),(484, 485, -359),(489, 491, -359),(500, 503, -359),(511, 518, -359),(523, 531, -359),(549, 550, -359),(553, 553, -359),(559, 560, -359),
(579, 585, -359),(177, 181, -358),(202, 205, -358),(219, 225, -358),(227, 227, -358),(229, 230, -358),(233, 241, -358),(302, 303, -358),(305, 306, -358),(310, 310, -358),
(322, 324, -358),(327, 330, -358),(344, 346, -358),(356, 356, -358),(358, 359, -358),(367, 367, -358),(376, 376, -358),(378, 379, -358),(388, 391, -358),(430, 432, -358),
(439, 441, -358),(469, 470, -358),(479, 480, -358),(482, 484, -358),(489, 490, -358),(502, 504, -358),(509, 511, -358),(514, 517, -358),(522, 531, -358),(550, 551, -358),
(553, 554, -358),(559, 559, -358),(582, 586, -358),(177, 180, -357),(201, 202, -357),(220, 224, -357),(236, 236, -357),(238, 241, -357),(302, 303, -357),(305, 306, -357),
(311, 311, -357),(321, 332, -357),(344, 346, -357),(356, 356, -357),(358, 358, -357),(367, 368, -357),(375, 376, -357),(378, 379, -357),(387, 391, -357),(438, 440, -357),
(469, 470, -357),(479, 480, -357),(483, 483, -357),(490, 491, -357),(503, 510, -357),(514, 517, -357),(521, 531, -357),(551, 551, -357),(554, 555, -357),(558, 559, -357),
(581, 585, -357),(177, 181, -356),(199, 201, -356),(221, 225, -356),(239, 242, -356),(301, 303, -356),(305, 306, -356),(310, 311, -356),(322, 333, -356),(344, 346, -356),
(355, 356, -356),(358, 359, -356),(366, 366, -356),(375, 378, -356),(385, 392, -356),(438, 440, -356),(468, 469, -356),(479, 479, -356),(481, 482, -356),(490, 491, -356),
(504, 504, -356),(506, 507, -356),(513, 517, -356),(522, 529, -356),(531, 532, -356),(552, 553, -356),(555, 555, -356),(558, 558, -356),(582, 585, -356),(177, 181, -355),
(198, 199, -355),(222, 223, -355),(225, 226, -355),(239, 241, -355),(301, 303, -355),(305, 306, -355),(310, 311, -355),(321, 324, -355),(329, 333, -355),(344, 346, -355),
(355, 355, -355),(358, 358, -355),(367, 367, -355),(375, 377, -355),(384, 392, -355),(437, 440, -355),(468, 470, -355),(478, 482, -355),(490, 492, -355),(512, 516, -355),
(522, 527, -355),(530, 532, -355),(552, 558, -355),(581, 584, -355),(177, 180, -354),(197, 198, -354),(223, 223, -354),(226, 226, -354),(239, 242, -354),(301, 304, -354),
(306, 306, -354),(311, 311, -354),(319, 320, -354),(330, 335, -354),(344, 347, -354),(355, 356, -354),(358, 358, -354),(366, 366, -354),(374, 376, -354),(382, 387, -354),
(389, 393, -354),(437, 439, -354),(468, 469, -354),(478, 480, -354),(489, 492, -354),(511, 516, -354),(522, 525, -354),(529, 532, -354),(554, 557, -354),(581, 584, -354),
(177, 180, -353),(196, 197, -353),(223, 228, -353),(239, 241, -353),(302, 306, -353),(311, 311, -353),(318, 320, -353),(324, 324, -353),(332, 335, -353),(344, 346, -353),
(355, 359, -353),(366, 367, -353),(373, 376, -353),(381, 385, -353),(392, 393, -353),(436, 439, -353),(468, 470, -353),(477, 479, -353),(489, 492, -353),(510, 516, -353),
(523, 530, -353),(532, 533, -353),(554, 557, -353),(581, 584, -353),(177, 180, -352),(195, 196, -352),(224, 225, -352),(227, 228, -352),(239, 241, -352),(302, 304, -352),
(306, 306, -352),(317, 318, -352),(323, 326, -352),(333, 335, -352),(345, 346, -352),(355, 355, -352),(358, 358, -352),(366, 366, -352),(373, 376, -352),(381, 385, -352),
(393, 395, -352),(436, 438, -352),(467, 472, -352),(475, 477, -352),(490, 493, -352),(509, 515, -352),(522, 528, -352),(532, 534, -352),(555, 558, -352),(580, 584, -352),
(176, 180, -351),(193, 196, -351),(225, 228, -351),(239, 241, -351),(301, 306, -351),(310, 311, -351),(317, 318, -351),(323, 327, -351),(333, 336, -351),(345, 346, -351),
(355, 356, -351),(358, 358, -351),(365, 366, -351),(373, 375, -351),(381, 385, -351),(395, 397, -351),(434, 439, -351),(467, 476, -351),(489, 494, -351),(509, 513, -351),
(523, 527, -351),(531, 534, -351),(555, 557, -351),(580, 583, -351),(177, 180, -350),(192, 195, -350),(226, 228, -350),(239, 242, -350),(302, 304, -350),(306, 306, -350),
(311, 311, -350),(316, 317, -350),(322, 326, -350),(333, 336, -350),(345, 346, -350),(355, 356, -350),(365, 366, -350),(372, 375, -350),(380, 382, -350),(384, 384, -350),
(396, 398, -350),(434, 440, -350),(466, 474, -350),(489, 495, -350),(508, 512, -350),(524, 527, -350),(530, 532, -350),(534, 534, -350),(556, 557, -350),(579, 583, -350),
(176, 180, -349),(189, 195, -349),(239, 242, -349),(302, 304, -349),(306, 307, -349),(311, 311, -349),(316, 317, -349),(323, 329, -349),(333, 337, -349),(346, 346, -349),
(355, 356, -349),(358, 358, -349),(371, 374, -349),(380, 382, -349),(384, 385, -349),(398, 405, -349),(433, 434, -349),(437, 442, -349),(466, 473, -349),(488, 497, -349),
(508, 511, -349),(524, 530, -349),(534, 535, -349),(556, 559, -349),(570, 572, -349),(579, 583, -349),(176, 180, -348),(189, 195, -348),(239, 242, -348),(302, 306, -348),
(311, 312, -348),(316, 316, -348),(323, 329, -348),(331, 337, -348),(345, 347, -348),(355, 358, -348),(365, 365, -348),(372, 373, -348),(380, 381, -348),(384, 385, -348),
(400, 400, -348),(402, 402, -348),(404, 407, -348),(433, 435, -348),(438, 443, -348),(465, 473, -348),(488, 497, -348),(507, 511, -348),(524, 529, -348),(532, 535, -348),
(555, 560, -348),(569, 573, -348),(578, 583, -348),(175, 179, -347),(188, 189, -347),(192, 194, -347),(240, 242, -347),(302, 304, -347),(306, 307, -347),(311, 312, -347),
(316, 316, -347),(329, 336, -347),(339, 340, -347),(346, 347, -347),(355, 358, -347),(365, 366, -347),(371, 373, -347),(380, 382, -347),(385, 385, -347),(407, 408, -347),
(432, 436, -347),(440, 444, -347),(465, 474, -347),(488, 501, -347),(506, 510, -347),(525, 529, -347),(532, 533, -347),(535, 536, -347),(555, 556, -347),(559, 559, -347),
(568, 569, -347),(571, 572, -347),(579, 583, -347),(176, 179, -346),(186, 188, -346),(191, 194, -346),(240, 243, -346),(302, 305, -346),(307, 307, -346),(311, 312, -346),
(315, 316, -346),(330, 332, -346),(335, 337, -346),(339, 341, -346),(346, 346, -346),(355, 357, -346),(365, 365, -346),(371, 372, -346),(381, 382, -346),(385, 386, -346),
(407, 408, -346),(431, 431, -346),(435, 436, -346),(442, 445, -346),(464, 476, -346),(487, 491, -346),(494, 509, -346),(525, 528, -346),(530, 532, -346),(535, 537, -346),
(555, 555, -346),(558, 560, -346),(568, 570, -346),(579, 582, -346),(176, 179, -345),(186, 187, -345),(191, 192, -345),(194, 194, -345),(240, 243, -345),(303, 307, -345),
(312, 312, -345),(316, 316, -345),(330, 333, -345),(335, 336, -345),(339, 341, -345),(346, 348, -345),(355, 358, -345),(364, 365, -345),(371, 373, -345),(381, 382, -345),
(386, 387, -345),(408, 409, -345),(430, 431, -345),(436, 437, -345),(443, 446, -345),(463, 468, -345),(470, 481, -345),(486, 491, -345),(495, 509, -345),(525, 531, -345),
(534, 538, -345),(555, 561, -345),(569, 569, -345),(578, 582, -345),(176, 179, -344),(185, 186, -344),(191, 193, -344),(240, 243, -344),(302, 305, -344),(307, 308, -344),
(311, 312, -344),(316, 317, -344),(329, 333, -344),(335, 342, -344),(347, 347, -344),(356, 358, -344),(364, 364, -344),(371, 372, -344),(381, 383, -344),(387, 387, -344),
(409, 409, -344),(429, 430, -344),(437, 438, -344),(444, 446, -344),(462, 467, -344),(471, 490, -344),(498, 508, -344),(526, 530, -344),(533, 535, -344),(537, 538, -344),
(556, 562, -344),(579, 581, -344),(176, 179, -343),(185, 186, -343),(191, 191, -343),(193, 193, -343),(241, 243, -343),(302, 305, -343),(307, 308, -343),(311, 313, -343),
(316, 317, -343),(323, 325, -343),(327, 337, -343),(339, 342, -343),(346, 347, -343),(356, 358, -343),(363, 365, -343),(370, 371, -343),(382, 384, -343),(388, 389, -343),
(409, 409, -343),(428, 429, -343),(438, 438, -343),(445, 447, -343),(462, 467, -343),(472, 490, -343),(499, 499, -343),(501, 506, -343),(527, 530, -343),(532, 533, -343),
(537, 539, -343),(558, 559, -343),(562, 563, -343),(578, 582, -343),(176, 180, -342),(185, 186, -342),(190, 191, -342),(193, 194, -342),(241, 243, -342),(303, 305, -342),
(307, 308, -342),(313, 313, -342),(317, 317, -342),(321, 330, -342),(332, 336, -342),(340, 342, -342),(347, 349, -342),(355, 358, -342),(363, 365, -342),(370, 371, -342),
(382, 384, -342),(388, 389, -342),(409, 410, -342),(425, 427, -342),(437, 440, -342),(445, 447, -342),(460, 467, -342),(473, 489, -342),(527, 532, -342),(536, 540, -342),
(559, 560, -342),(563, 564, -342),(577, 581, -342),(176, 180, -341),(184, 185, -341),(190, 190, -341),(193, 193, -341),(241, 243, -341),(303, 305, -341),(307, 308, -341),
(313, 313, -341),(317, 318, -341),(321, 327, -341),(332, 336, -341),(340, 342, -341),(347, 349, -341),(352, 364, -341),(370, 372, -341),(383, 385, -341),(389, 391, -341),
(409, 409, -341),(424, 426, -341),(435, 443, -341),(446, 447, -341),(460, 461, -341),(463, 467, -341),(472, 488, -341),(528, 532, -341),(535, 536, -341),(539, 541, -341),
(560, 561, -341),(564, 565, -341),(577, 581, -341),(176, 180, -340),(184, 184, -340),(189, 190, -340),(192, 193, -340),(242, 244, -340),(303, 306, -340),(308, 309, -340),
(313, 313, -340),(317, 319, -340),(322, 325, -340),(331, 335, -340),(341, 343, -340),(346, 367, -340),(369, 371, -340),(384, 386, -340),(390, 391, -340),(408, 410, -340),
(423, 424, -340),(434, 436, -340),(439, 447, -340),(459, 460, -340),(464, 468, -340),(472, 489, -340),(529, 535, -340),(538, 539, -340),(541, 542, -340),(560, 562, -340),
(565, 568, -340),(576, 580, -340),(176, 184, -339),(189, 189, -339),(192, 193, -339),(242, 244, -339),(303, 306, -339),(308, 309, -339),(313, 314, -339),(319, 324, -339),
(330, 334, -339),(341, 372, -339),(385, 388, -339),(392, 394, -339),(408, 409, -339),(420, 423, -339),(432, 434, -339),(439, 440, -339),(444, 448, -339),(457, 458, -339),
(464, 468, -339),(471, 476, -339),(481, 490, -339),(530, 534, -339),(537, 538, -339),(541, 544, -339),(561, 563, -339),(567, 571, -339),(574, 580, -339),(177, 184, -338),
(189, 189, -338),(192, 192, -338),(242, 244, -338),(304, 306, -338),(309, 309, -338),(314, 314, -338),(321, 324, -338),(326, 326, -338),(328, 334, -338),(341, 354, -338),
(360, 371, -338),(385, 390, -338),(393, 395, -338),(397, 397, -338),(408, 409, -338),(416, 416, -338),(418, 421, -338),(431, 432, -338),(440, 440, -338),(445, 448, -338),
(464, 467, -338),(470, 475, -338),(481, 483, -338),(485, 492, -338),(530, 535, -338),(537, 538, -338),(542, 545, -338),(563, 564, -338),(570, 581, -338),(177, 184, -337),
(189, 190, -337),(192, 192, -337),(242, 245, -337),(304, 307, -337),(309, 310, -337),(313, 314, -337),(322, 329, -337),(331, 335, -337),(340, 351, -337),(366, 366, -337),
(368, 371, -337),(385, 391, -337),(394, 394, -337),(396, 402, -337),(407, 409, -337),(412, 418, -337),(431, 432, -337),(440, 440, -337),(446, 450, -337),(464, 467, -337),
(470, 475, -337),(482, 482, -337),(486, 493, -337),(530, 537, -337),(541, 542, -337),(544, 547, -337),(563, 563, -337),(565, 566, -337),(571, 583, -337),(178, 183, -336),
(189, 192, -336),(242, 245, -336),(304, 307, -336),(310, 310, -336),(314, 315, -336),(325, 329, -336),(332, 345, -336),(348, 352, -336),(369, 372, -336),(385, 395, -336),
(399, 399, -336),(401, 412, -336),(414, 414, -336),(417, 417, -336),(430, 431, -336),(439, 440, -336),(445, 451, -336),(464, 467, -336),(471, 474, -336),(482, 483, -336),
(488, 493, -336),(532, 537, -336),(540, 541, -336),(544, 545, -336),(547, 548, -336),(565, 566, -336),(572, 574, -336),(576, 583, -336),(178, 183, -335),(189, 191, -335),
(242, 245, -335),(305, 307, -335),(310, 311, -335),(315, 315, -335),(327, 329, -335),(332, 343, -335),(351, 354, -335),(369, 371, -335),(377, 377, -335),(385, 387, -335),
(391, 398, -335),(400, 408, -335),(410, 410, -335),(430, 430, -335),(440, 441, -335),(446, 451, -335),(463, 467, -335),(470, 475, -335),(482, 482, -335),(488, 495, -335),
(532, 540, -335),(543, 544, -335),(547, 550, -335),(566, 569, -335),(571, 575, -335),(577, 584, -335),(179, 183, -334),(189, 190, -334),(243, 246, -334),(305, 308, -334),
(310, 311, -334),(315, 316, -334),(329, 330, -334),(333, 346, -334),(353, 355, -334),(369, 372, -334),(376, 377, -334),(385, 387, -334),(392, 404, -334),(429, 429, -334),
(439, 440, -334),(445, 447, -334),(450, 452, -334),(464, 467, -334),(470, 476, -334),(482, 483, -334),(489, 495, -334),(511, 513, -334),(533, 540, -334),(542, 543, -334),
(546, 548, -334),(550, 554, -334),(557, 557, -334),(568, 573, -334),(575, 575, -334),(578, 584, -334),(179, 183, -333),(244, 246, -333),(306, 308, -333),(310, 311, -333),
(315, 316, -333),(328, 338, -333),(344, 347, -333),(354, 356, -333),(369, 372, -333),(375, 378, -333),(385, 388, -333),(395, 398, -333),(428, 430, -333),(437, 443, -333),
(445, 447, -333),(450, 452, -333),(463, 468, -333),(471, 478, -333),(482, 482, -333),(489, 496, -333),(510, 514, -333),(534, 543, -333),(547, 547, -333),(550, 559, -333),
(561, 562, -333),(567, 573, -333),(575, 583, -333),(179, 183, -332),(244, 247, -332),(306, 309, -332),(311, 312, -332),(316, 317, -332),(330, 337, -332),(340, 340, -332),
(347, 349, -332),(356, 358, -332),(370, 371, -332),(376, 378, -332),(385, 387, -332),(395, 398, -332),(426, 429, -332),(436, 446, -332),(450, 452, -332),(463, 466, -332),
(473, 482, -332),(489, 489, -332),(492, 497, -332),(510, 514, -332),(536, 543, -332),(546, 546, -332),(549, 551, -332),(553, 554, -332),(556, 562, -332),(567, 571, -332);

INSERT INTO #R2(first, last, y)
VALUES (573, 573, -332),(576, 582, -332),(179, 183, -331),(244, 247, -331),(306, 309, -331),(312, 313, -331),(317, 318, -331),(330, 340, -331),(349, 351, -331),(357, 359, -331),
(369, 371, -331),(375, 377, -331),(385, 387, -331),(395, 396, -331),(437, 447, -331),(450, 452, -331),(463, 466, -331),(475, 483, -331),(488, 489, -331),(492, 497, -331),
(510, 515, -331),(536, 546, -331),(549, 550, -331),(553, 553, -331),(556, 557, -331),(559, 562, -331),(567, 569, -331),(571, 571, -331),(573, 582, -331),(179, 185, -330),
(245, 247, -330),(307, 309, -330),(312, 312, -330),(317, 318, -330),(329, 333, -330),(339, 343, -330),(351, 353, -330),(358, 359, -330),(370, 372, -330),(375, 375, -330),
(378, 378, -330),(385, 387, -330),(395, 397, -330),(436, 446, -330),(451, 453, -330),(462, 466, -330),(477, 483, -330),(488, 489, -330),(493, 497, -330),(510, 515, -330),
(539, 546, -330),(549, 550, -330),(553, 553, -330),(556, 556, -330),(560, 563, -330),(568, 568, -330),(570, 571, -330),(574, 581, -330),(179, 185, -329),(245, 248, -329),
(307, 310, -329),(313, 313, -329),(318, 318, -329),(328, 333, -329),(343, 345, -329),(352, 354, -329),(359, 361, -329),(369, 371, -329),(375, 376, -329),(378, 378, -329),
(385, 387, -329),(395, 396, -329),(439, 441, -329),(443, 446, -329),(452, 457, -329),(462, 466, -329),(478, 484, -329),(487, 489, -329),(494, 498, -329),(509, 516, -329),
(539, 550, -329),(552, 553, -329),(556, 556, -329),(560, 560, -329),(562, 563, -329),(568, 568, -329),(571, 579, -329),(179, 185, -328),(242, 249, -328),(308, 311, -328),
(313, 314, -328),(318, 319, -328),(328, 338, -328),(344, 347, -328),(353, 355, -328),(360, 361, -328),(370, 372, -328),(375, 377, -328),(385, 387, -328),(395, 396, -328),
(443, 445, -328),(451, 459, -328),(461, 466, -328),(479, 487, -328),(494, 498, -328),(509, 512, -328),(514, 516, -328),(541, 554, -328),(556, 557, -328),(559, 560, -328),
(563, 563, -328),(568, 569, -328),(571, 578, -328),(179, 184, -327),(231, 233, -327),(241, 249, -327),(309, 311, -327),(314, 314, -327),(319, 320, -327),(327, 334, -327),
(336, 339, -327),(347, 349, -327),(355, 356, -327),(361, 362, -327),(369, 372, -327),(375, 377, -327),(385, 388, -327),(395, 396, -327),(430, 431, -327),(433, 434, -327),
(442, 446, -327),(452, 469, -327),(481, 486, -327),(494, 498, -327),(508, 512, -327),(514, 516, -327),(544, 564, -327),(567, 576, -327),(179, 185, -326),(229, 233, -326),
(238, 250, -326),(309, 312, -326),(314, 315, -326),(319, 320, -326),(327, 329, -326),(338, 343, -326),(348, 350, -326),(355, 357, -326),(361, 362, -326),(369, 371, -326),
(375, 378, -326),(385, 387, -326),(394, 396, -326),(429, 434, -326),(441, 447, -326),(451, 456, -326),(458, 471, -326),(481, 486, -326),(494, 499, -326),(508, 511, -326),
(514, 517, -326),(545, 564, -326),(567, 575, -326),(179, 184, -325),(228, 233, -325),(237, 244, -325),(248, 251, -325),(309, 312, -325),(314, 315, -325),(320, 321, -325),
(326, 329, -325),(341, 344, -325),(349, 351, -325),(357, 358, -325),(362, 363, -325),(370, 371, -325),(375, 377, -325),(385, 387, -325),(394, 396, -325),(428, 434, -325),
(440, 449, -325),(452, 456, -325),(459, 474, -325),(482, 485, -325),(493, 499, -325),(507, 511, -325),(514, 516, -325),(548, 565, -325),(567, 573, -325),(179, 184, -324),
(227, 233, -324),(235, 240, -324),(248, 251, -324),(310, 313, -324),(315, 316, -324),(321, 322, -324),(325, 328, -324),(344, 346, -324),(351, 352, -324),(357, 359, -324),
(363, 364, -324),(369, 372, -324),(375, 377, -324),(385, 387, -324),(394, 396, -324),(429, 434, -324),(440, 450, -324),(453, 456, -324),(462, 477, -324),(480, 486, -324),
(489, 493, -324),(495, 499, -324),(507, 510, -324),(515, 517, -324),(552, 570, -324),(179, 184, -323),(221, 238, -323),(249, 251, -323),(311, 313, -323),(315, 317, -323),
(321, 322, -323),(324, 327, -323),(346, 348, -323),(352, 353, -323),(358, 360, -323),(363, 364, -323),(369, 371, -323),(375, 377, -323),(385, 387, -323),(394, 396, -323),
(430, 432, -323),(441, 444, -323),(447, 450, -323),(452, 456, -323),(462, 463, -323),(465, 490, -323),(495, 499, -323),(506, 510, -323),(515, 518, -323),(556, 570, -323),
(178, 183, -322),(220, 228, -322),(230, 236, -322),(250, 252, -322),(311, 314, -322),(317, 317, -322),(322, 327, -322),(346, 349, -322),(352, 354, -322),(360, 360, -322),
(364, 365, -322),(369, 372, -322),(375, 376, -322),(385, 387, -322),(395, 397, -322),(443, 445, -322),(448, 451, -322),(453, 456, -322),(462, 462, -322),(468, 485, -322),
(487, 488, -322),(494, 499, -322),(505, 510, -322),(515, 517, -322),(561, 569, -322),(179, 183, -321),(217, 226, -321),(230, 234, -321),(251, 253, -321),(273, 275, -321),
(312, 314, -321),(316, 318, -321),(323, 326, -321),(350, 351, -321),(354, 355, -321),(360, 361, -321),(365, 365, -321),(370, 371, -321),(375, 376, -321),(385, 388, -321),
(394, 396, -321),(443, 446, -321),(449, 451, -321),(453, 457, -321),(462, 463, -321),(469, 470, -321),(472, 484, -321),(494, 499, -321),(505, 509, -321),(514, 517, -321),
(564, 569, -321),(178, 182, -320),(216, 225, -320),(231, 233, -320),(251, 253, -320),(272, 273, -320),(275, 275, -320),(312, 315, -320),(317, 318, -320),(323, 326, -320),
(350, 351, -320),(355, 356, -320),(361, 362, -320),(366, 366, -320),(369, 371, -320),(374, 376, -320),(385, 387, -320),(395, 397, -320),(443, 444, -320),(446, 447, -320),
(449, 451, -320),(453, 457, -320),(463, 463, -320),(469, 470, -320),(473, 484, -320),(494, 498, -320),(504, 508, -320),(515, 517, -320),(565, 569, -320),(178, 181, -319),
(215, 224, -319),(252, 254, -319),(273, 273, -319),(276, 277, -319),(313, 315, -319),(318, 319, -319),(322, 325, -319),(351, 352, -319),(356, 357, -319),(361, 362, -319),
(366, 366, -319),(369, 371, -319),(374, 376, -319),(385, 388, -319),(395, 397, -319),(443, 443, -319),(446, 447, -319),(449, 451, -319),(454, 458, -319),(463, 463, -319),
(470, 470, -319),(477, 481, -319),(483, 485, -319),(494, 498, -319),(503, 508, -319),(515, 517, -319),(566, 568, -319),(178, 182, -318),(213, 218, -318),(220, 223, -318),
(252, 255, -318),(272, 273, -318),(277, 278, -318),(301, 302, -318),(304, 304, -318),(308, 308, -318),(311, 317, -318),(319, 320, -318),(322, 325, -318),(353, 353, -318),
(356, 357, -318),(362, 363, -318),(366, 367, -318),(369, 371, -318),(374, 375, -318),(385, 388, -318),(395, 398, -318),(443, 446, -318),(449, 451, -318),(454, 459, -318),
(463, 464, -318),(470, 470, -318),(478, 478, -318),(484, 486, -318),(493, 498, -318),(501, 507, -318),(514, 517, -318),(178, 182, -317),(213, 216, -317),(220, 222, -317),
(254, 256, -317),(273, 273, -317),(278, 278, -317),(296, 296, -317),(298, 325, -317),(353, 354, -317),(357, 358, -317),(362, 363, -317),(366, 371, -317),(373, 374, -317),
(385, 389, -317),(391, 391, -317),(396, 399, -317),(443, 446, -317),(449, 451, -317),(454, 465, -317),(470, 471, -317),(477, 478, -317),(486, 488, -317),(492, 498, -317),
(500, 506, -317),(514, 517, -317),(178, 182, -316),(212, 215, -316),(220, 221, -316),(254, 256, -316),(274, 275, -316),(278, 279, -316),(295, 324, -316),(354, 355, -316),
(358, 359, -316),(363, 364, -316),(367, 370, -316),(373, 374, -316),(384, 393, -316),(396, 399, -316),(443, 444, -316),(446, 446, -316),(449, 450, -316),(454, 466, -316),
(471, 471, -316),(478, 479, -316),(487, 487, -316),(489, 505, -316),(513, 516, -316),(177, 182, -315),(211, 214, -315),(220, 220, -315),(255, 257, -315),(274, 275, -315),
(280, 280, -315),(293, 309, -315),(311, 325, -315),(355, 355, -315),(358, 359, -315),(363, 364, -315),(367, 370, -315),(373, 374, -315),(384, 400, -315),(442, 443, -315),
(449, 451, -315),(454, 472, -315),(479, 479, -315),(491, 505, -315),(513, 517, -315),(178, 181, -314),(210, 213, -314),(255, 258, -314),(275, 275, -314),(280, 281, -314),
(292, 299, -314),(302, 307, -314),(312, 327, -314),(329, 329, -314),(355, 357, -314),(359, 360, -314),(364, 364, -314),(366, 370, -314),(373, 374, -314),(382, 385, -314),
(391, 402, -314),(442, 443, -314),(448, 450, -314),(455, 473, -314),(479, 480, -314),(489, 503, -314),(513, 516, -314),(178, 181, -313),(205, 205, -313),(210, 212, -313),
(256, 258, -313),(276, 277, -313),(281, 281, -313),(291, 297, -313),(302, 305, -313),(313, 317, -313),(321, 321, -313),(323, 323, -313),(327, 331, -313),(356, 357, -313),
(359, 360, -313),(364, 369, -313),(372, 374, -313),(378, 378, -313),(381, 385, -313),(393, 403, -313),(441, 442, -313),(448, 449, -313),(455, 476, -313),(479, 481, -313),
(489, 502, -313),(512, 516, -313),(178, 182, -312),(203, 205, -312),(209, 212, -312),(257, 259, -312),(277, 279, -312),(281, 282, -312),(289, 295, -312),(303, 303, -312),
(313, 314, -312),(328, 332, -312),(356, 357, -312),(360, 360, -312),(364, 368, -312),(371, 384, -312),(395, 403, -312),(441, 442, -312),(446, 449, -312),(455, 483, -312),
(485, 501, -312),(512, 516, -312),(178, 181, -311),(189, 191, -311),(203, 205, -311),(208, 211, -311),(258, 261, -311),(279, 280, -311),(282, 283, -311),(289, 293, -311),
(327, 330, -311),(357, 358, -311),(360, 360, -311),(363, 368, -311),(370, 382, -311),(396, 403, -311),(441, 448, -311),(456, 457, -311),(459, 464, -311),(468, 498, -311),
(511, 515, -311),(177, 181, -310),(189, 191, -310),(202, 205, -310),(208, 210, -310),(258, 261, -310),(280, 284, -310),(288, 293, -310),(326, 330, -310),(357, 358, -310),
(360, 377, -310),(398, 402, -310),(440, 448, -310),(455, 457, -310),(460, 465, -310),(470, 497, -310),(510, 515, -310),(178, 182, -309),(189, 191, -309),(202, 205, -309),
(207, 209, -309),(260, 262, -309),(281, 285, -309),(287, 291, -309),(327, 332, -309),(358, 375, -309),(398, 401, -309),(405, 407, -309),(439, 445, -309),(456, 457, -309),
(461, 465, -309),(474, 494, -309),(510, 514, -309),(178, 182, -308),(189, 189, -308),(191, 192, -308),(201, 205, -308),(207, 209, -308),(260, 263, -308),(283, 291, -308),
(331, 333, -308),(358, 365, -308),(371, 376, -308),(398, 401, -308),(406, 407, -308),(437, 442, -308),(455, 458, -308),(462, 467, -308),(477, 492, -308),(509, 514, -308),
(179, 182, -307),(189, 189, -307),(191, 192, -307),(200, 208, -307),(261, 263, -307),(285, 290, -307),(333, 336, -307),(339, 339, -307),(359, 359, -307),(361, 362, -307),
(373, 377, -307),(398, 400, -307),(405, 406, -307),(435, 440, -307),(456, 458, -307),(462, 467, -307),(478, 489, -307),(508, 513, -307),(178, 182, -306),(189, 189, -306),
(191, 191, -306),(200, 208, -306),(261, 264, -306),(285, 289, -306),(335, 341, -306),(374, 377, -306),(397, 400, -306),(406, 406, -306),(413, 413, -306),(433, 440, -306),
(456, 459, -306),(464, 468, -306),(477, 485, -306),(507, 513, -306),(179, 183, -305),(188, 189, -305),(191, 192, -305),(199, 202, -305),(204, 208, -305),(262, 264, -305),
(286, 288, -305),(336, 342, -305),(375, 376, -305),(397, 400, -305),(406, 407, -305),(412, 413, -305),(429, 439, -305),(457, 460, -305),(464, 469, -305),(477, 483, -305),
(506, 512, -305),(179, 183, -304),(188, 191, -304),(198, 201, -304),(204, 207, -304),(263, 265, -304),(285, 288, -304),(338, 338, -304),(342, 343, -304),(375, 377, -304),
(397, 401, -304),(406, 408, -304),(412, 413, -304),(417, 417, -304),(419, 419, -304),(423, 423, -304),(426, 436, -304),(438, 439, -304),(457, 461, -304),(465, 469, -304),
(476, 481, -304),(505, 511, -304),(179, 184, -303),(189, 191, -303),(197, 200, -303),(204, 206, -303),(263, 266, -303),(285, 287, -303),(343, 343, -303),(375, 377, -303),
(396, 402, -303),(407, 413, -303),(416, 432, -303),(438, 439, -303),(457, 462, -303),(466, 470, -303),(476, 480, -303),(503, 510, -303),(179, 184, -302),(188, 191, -302),
(196, 200, -302),(204, 206, -302),(264, 266, -302),(284, 287, -302),(343, 344, -302),(375, 377, -302),(397, 402, -302),(408, 411, -302),(417, 427, -302),(429, 432, -302),
(439, 439, -302),(457, 463, -302),(467, 471, -302),(475, 480, -302),(489, 491, -302),(502, 509, -302),(180, 184, -301),(188, 190, -301),(195, 198, -301),(205, 205, -301),
(265, 267, -301),(284, 287, -301),(344, 345, -301),(374, 377, -301),(397, 403, -301),(416, 419, -301),(421, 421, -301),(423, 424, -301),(431, 432, -301),(439, 439, -301),
(457, 464, -301),(467, 472, -301),(476, 480, -301),(486, 493, -301),(500, 508, -301),(180, 185, -300),(188, 190, -300),(194, 197, -300),(265, 268, -300),(284, 287, -300),
(345, 346, -300),(373, 376, -300),(396, 404, -300),(416, 418, -300),(431, 432, -300),(439, 440, -300),(458, 459, -300),(461, 464, -300),(468, 473, -300),(476, 487, -300),
(492, 494, -300),(499, 507, -300),(180, 186, -299),(188, 190, -299),(193, 196, -299),(266, 268, -299),(284, 286, -299),(346, 347, -299),(371, 375, -299),(396, 398, -299),
(401, 406, -299),(415, 418, -299),(432, 433, -299),(439, 440, -299),(457, 460, -299),(462, 465, -299),(469, 474, -299),(477, 484, -299),(492, 506, -299),(181, 189, -298),
(192, 195, -298),(265, 269, -298),(284, 286, -298),(347, 348, -298),(350, 351, -298),(368, 374, -298),(397, 399, -298),(401, 408, -298),(414, 418, -298),(432, 432, -298),
(440, 440, -298),(458, 460, -298),(463, 466, -298),(470, 475, -298),(478, 483, -298),(491, 492, -298),(496, 505, -298),(182, 194, -297),(265, 270, -297),(284, 286, -297),
(347, 353, -297),(366, 373, -297),(396, 418, -297),(432, 433, -297),(440, 440, -297),(458, 460, -297),(464, 467, -297),(470, 476, -297),(478, 483, -297),(491, 491, -297),
(496, 503, -297),(182, 193, -296),(263, 271, -296),(284, 287, -296),(348, 353, -296),(364, 371, -296),(395, 414, -296),(416, 419, -296),(433, 433, -296),(440, 441, -296),
(458, 461, -296),(464, 468, -296),(472, 476, -296),(480, 485, -296),(489, 490, -296),(497, 503, -296),(182, 192, -295),(261, 264, -295),(267, 272, -295),(284, 287, -295),
(349, 351, -295),(354, 354, -295),(364, 371, -295),(394, 411, -295),(416, 419, -295),(433, 433, -295),(441, 441, -295),(458, 462, -295),(464, 469, -295),(472, 477, -295),
(481, 486, -295),(488, 489, -295),(498, 503, -295),(182, 190, -294),(259, 261, -294),(270, 273, -294),(284, 287, -294),(354, 355, -294),(362, 372, -294),(392, 393, -294),
(395, 395, -294),(403, 403, -294),(405, 410, -294),(417, 419, -294),(433, 433, -294),(440, 441, -294),(459, 470, -294),(473, 478, -294),(480, 488, -294),(499, 504, -294),
(180, 190, -293),(258, 259, -293),(271, 274, -293),(283, 286, -293),(355, 356, -293),(361, 371, -293),(391, 392, -293),(407, 408, -293),(413, 413, -293),(415, 415, -293),
(417, 419, -293),(433, 434, -293),(441, 442, -293),(459, 470, -293),(474, 487, -293),(500, 505, -293),(179, 189, -292),(256, 259, -292),(272, 276, -292),(282, 286, -292),
(355, 357, -292),(361, 372, -292),(390, 392, -292),(411, 419, -292),(433, 434, -292),(441, 441, -292),(459, 462, -292),(464, 464, -292),(466, 471, -292),(475, 486, -292),
(501, 505, -292),(178, 188, -291),(256, 257, -291),(272, 278, -291),(280, 285, -291),(356, 357, -291),(359, 368, -291),(370, 371, -291),(390, 391, -291),(410, 417, -291),
(420, 420, -291),(434, 434, -291),(441, 442, -291),(459, 462, -291),(467, 472, -291),(476, 485, -291),(502, 505, -291),(178, 188, -290),(254, 256, -290),(271, 284, -290),
(357, 366, -290),(368, 372, -290),(389, 390, -290),(409, 411, -290),(414, 416, -290),(418, 422, -290),(434, 435, -290),(441, 442, -290),(456, 461, -290),(467, 473, -290),
(476, 483, -290),(501, 505, -290),(177, 187, -289),(254, 255, -289),(270, 272, -289),(278, 283, -289),(306, 309, -289),(357, 369, -289),(371, 372, -289),(388, 389, -289),
(409, 409, -289),(415, 423, -289),(434, 435, -289),(442, 442, -289),(451, 459, -289),(467, 474, -289),(477, 481, -289),(501, 504, -289),(177, 186, -288),(252, 253, -288);

INSERT INTO #R2(first, last, y)
VALUES (269, 270, -288),(280, 283, -288),(306, 311, -288),(358, 361, -288),(364, 368, -288),(371, 372, -288),(388, 388, -288),(408, 410, -288),(413, 425, -288),(434, 435, -288),
(441, 442, -288),(446, 446, -288),(448, 457, -288),(468, 474, -288),(478, 480, -288),(501, 504, -288),(176, 185, -287),(244, 244, -287),(252, 253, -287),(268, 269, -287),
(281, 283, -287),(297, 297, -287),(300, 300, -287),(306, 307, -287),(310, 311, -287),(316, 318, -287),(321, 322, -287),(358, 360, -287),(364, 366, -287),(370, 372, -287),
(388, 388, -287),(403, 419, -287),(423, 425, -287),(434, 436, -287),(441, 453, -287),(467, 475, -287),(479, 480, -287),(500, 503, -287),(175, 185, -286),(240, 245, -286),
(250, 252, -286),(266, 268, -286),(281, 283, -286),(293, 307, -286),(311, 324, -286),(358, 360, -286),(364, 373, -286),(388, 388, -286),(400, 404, -286),(410, 417, -286),
(423, 425, -286),(434, 449, -286),(459, 461, -286),(467, 476, -286),(480, 481, -286),(499, 503, -286),(175, 184, -285),(238, 240, -285),(242, 242, -285),(245, 246, -285),
(250, 251, -285),(265, 266, -285),(281, 283, -285),(290, 293, -285),(296, 296, -285),(299, 307, -285),(313, 315, -285),(324, 325, -285),(358, 360, -285),(365, 373, -285),
(387, 388, -285),(398, 401, -285),(412, 415, -285),(424, 426, -285),(433, 446, -285),(456, 462, -285),(466, 477, -285),(481, 481, -285),(498, 503, -285),(174, 184, -284),
(237, 239, -284),(245, 246, -284),(248, 250, -284),(264, 265, -284),(280, 283, -284),(288, 290, -284),(299, 303, -284),(323, 325, -284),(359, 360, -284),(365, 367, -284),
(369, 373, -284),(387, 388, -284),(394, 398, -284),(411, 412, -284),(414, 414, -284),(420, 421, -284),(424, 426, -284),(432, 440, -284),(446, 450, -284),(452, 452, -284),
(454, 458, -284),(461, 463, -284),(465, 470, -284),(472, 478, -284),(481, 482, -284),(497, 501, -284),(173, 177, -283),(180, 183, -283),(236, 237, -283),(246, 249, -283),
(262, 264, -283),(280, 283, -283),(287, 289, -283),(298, 301, -283),(322, 324, -283),(358, 360, -283),(365, 369, -283),(371, 374, -283),(387, 387, -283),(393, 395, -283),
(412, 412, -283),(414, 415, -283),(420, 422, -283),(424, 435, -283),(437, 437, -283),(439, 441, -283),(447, 454, -283),(460, 469, -283),(473, 478, -283),(482, 483, -283),
(496, 501, -283),(173, 177, -282),(180, 182, -282),(235, 236, -282),(245, 246, -282),(248, 248, -282),(261, 262, -282),(281, 284, -282),(286, 287, -282),(295, 300, -282),
(323, 324, -282),(358, 360, -282),(365, 375, -282),(386, 387, -282),(391, 393, -282),(411, 414, -282),(420, 422, -282),(424, 434, -282),(440, 441, -282),(448, 450, -282),
(459, 460, -282),(462, 469, -282),(474, 479, -282),(483, 484, -282),(495, 500, -282),(173, 176, -281),(180, 181, -281),(233, 236, -281),(260, 261, -281),(281, 284, -281),
(286, 287, -281),(294, 296, -281),(298, 299, -281),(323, 326, -281),(358, 360, -281),(366, 370, -281),(374, 374, -281),(387, 387, -281),(390, 392, -281),(412, 412, -281),
(414, 415, -281),(421, 421, -281),(424, 430, -281),(433, 433, -281),(439, 442, -281),(450, 453, -281),(456, 460, -281),(463, 468, -281),(475, 479, -281),(484, 484, -281),
(494, 500, -281),(172, 176, -280),(233, 234, -280),(259, 260, -280),(281, 286, -280),(293, 294, -280),(297, 298, -280),(324, 329, -280),(331, 331, -280),(333, 333, -280),
(356, 359, -280),(366, 369, -280),(374, 375, -280),(386, 387, -280),(389, 390, -280),(401, 401, -280),(411, 412, -280),(414, 415, -280),(424, 426, -280),(432, 433, -280),
(439, 440, -280),(442, 443, -280),(451, 457, -280),(462, 468, -280),(476, 481, -280),(484, 485, -280),(494, 499, -280),(171, 175, -279),(232, 233, -279),(258, 258, -279),
(280, 285, -279),(292, 292, -279),(296, 297, -279),(330, 330, -279),(332, 332, -279),(334, 337, -279),(356, 359, -279),(367, 368, -279),(373, 376, -279),(386, 389, -279),
(398, 403, -279),(412, 412, -279),(415, 416, -279),(423, 425, -279),(432, 432, -279),(439, 439, -279),(442, 443, -279),(452, 453, -279),(461, 466, -279),(477, 482, -279),
(486, 487, -279),(492, 498, -279),(172, 175, -278),(230, 231, -278),(257, 257, -278),(279, 284, -278),(291, 292, -278),(295, 296, -278),(335, 337, -278),(356, 358, -278),
(367, 377, -278),(384, 388, -278),(397, 398, -278),(401, 403, -278),(412, 413, -278),(415, 417, -278),(421, 424, -278),(431, 432, -278),(438, 439, -278),(443, 444, -278),
(453, 454, -278),(461, 466, -278),(477, 482, -278),(486, 488, -278),(492, 497, -278),(171, 175, -277),(230, 231, -277),(255, 257, -277),(278, 283, -277),(290, 291, -277),
(294, 294, -277),(336, 337, -277),(356, 358, -277),(368, 377, -277),(384, 388, -277),(396, 397, -277),(401, 403, -277),(412, 413, -277),(415, 424, -277),(431, 432, -277),
(438, 438, -277),(443, 444, -277),(453, 455, -277),(460, 465, -277),(478, 483, -277),(487, 496, -277),(169, 174, -276),(222, 222, -276),(229, 229, -276),(255, 255, -276),
(277, 282, -276),(290, 294, -276),(336, 337, -276),(355, 358, -276),(368, 377, -276),(383, 384, -276),(388, 388, -276),(396, 399, -276),(401, 402, -276),(412, 424, -276),
(429, 431, -276),(438, 439, -276),(444, 444, -276),(454, 464, -276),(479, 484, -276),(488, 496, -276),(168, 174, -275),(219, 224, -275),(228, 229, -275),(254, 255, -275),
(276, 281, -275),(291, 291, -275),(293, 293, -275),(336, 338, -275),(355, 357, -275),(369, 372, -275),(375, 378, -275),(383, 383, -275),(388, 389, -275),(396, 401, -275),
(412, 421, -275),(423, 424, -275),(428, 429, -275),(437, 439, -275),(444, 444, -275),(454, 463, -275),(480, 485, -275),(488, 496, -275),(168, 173, -274),(216, 219, -274),
(222, 223, -274),(227, 228, -274),(253, 254, -274),(276, 280, -274),(337, 339, -274),(354, 357, -274),(369, 371, -274),(373, 375, -274),(378, 379, -274),(382, 383, -274),
(388, 389, -274),(411, 419, -274),(424, 425, -274),(427, 428, -274),(436, 439, -274),(444, 445, -274),(455, 461, -274),(480, 485, -274),(489, 497, -274),(166, 173, -273),
(215, 217, -273),(222, 224, -273),(226, 227, -273),(252, 253, -273),(275, 279, -273),(339, 341, -273),(354, 356, -273),(370, 374, -273),(378, 380, -273),(382, 384, -273),
(388, 389, -273),(409, 420, -273),(424, 428, -273),(436, 439, -273),(444, 444, -273),(454, 461, -273),(482, 485, -273),(491, 498, -273),(165, 172, -272),(213, 215, -272),
(221, 222, -272),(226, 226, -272),(251, 252, -272),(275, 278, -272),(341, 343, -272),(354, 357, -272),(370, 373, -272),(378, 384, -272),(386, 388, -272),(409, 426, -272),
(435, 436, -272),(439, 440, -272),(444, 445, -272),(455, 458, -272),(482, 487, -272),(493, 498, -272),(163, 170, -271),(211, 212, -271),(221, 222, -271),(224, 226, -271),
(250, 251, -271),(274, 277, -271),(342, 344, -271),(354, 357, -271),(371, 372, -271),(376, 387, -271),(408, 424, -271),(435, 436, -271),(440, 441, -271),(444, 445, -271),
(454, 458, -271),(482, 487, -271),(494, 498, -271),(162, 169, -270),(211, 212, -270),(221, 221, -270),(224, 224, -270),(249, 250, -270),(273, 276, -270),(344, 345, -270),
(353, 356, -270),(371, 373, -270),(375, 383, -270),(386, 388, -270),(407, 423, -270),(435, 435, -270),(440, 445, -270),(454, 458, -270),(484, 487, -270),(495, 499, -270),
(161, 168, -269),(209, 211, -269),(220, 221, -269),(223, 224, -269),(249, 249, -269),(272, 276, -269),(344, 344, -269),(353, 356, -269),(372, 375, -269),(377, 382, -269),
(388, 388, -269),(406, 425, -269),(434, 435, -269),(442, 442, -269),(444, 445, -269),(453, 458, -269),(484, 487, -269),(495, 499, -269),(160, 166, -268),(207, 209, -268),
(221, 224, -268),(248, 249, -268),(270, 270, -268),(272, 276, -268),(343, 345, -268),(353, 356, -268),(372, 377, -268),(379, 381, -268),(388, 388, -268),(404, 427, -268),
(433, 436, -268),(444, 445, -268),(450, 458, -268),(484, 487, -268),(495, 499, -268),(159, 165, -267),(207, 208, -267),(221, 223, -267),(247, 248, -267),(270, 275, -267),
(343, 344, -267),(352, 355, -267),(373, 381, -267),(388, 389, -267),(403, 408, -267),(410, 428, -267),(432, 436, -267),(444, 457, -267),(485, 487, -267),(494, 498, -267),
(158, 164, -266),(207, 208, -266),(221, 222, -266),(247, 247, -266),(268, 274, -266),(341, 343, -266),(351, 355, -266),(374, 381, -266),(388, 396, -266),(401, 407, -266),
(410, 417, -266),(419, 436, -266),(444, 457, -266),(462, 473, -266),(484, 488, -266),(494, 498, -266),(158, 163, -265),(205, 206, -265),(246, 246, -265),(267, 268, -265),
(271, 274, -265),(340, 342, -265),(350, 354, -265),(374, 378, -265),(381, 381, -265),(388, 407, -265),(410, 418, -265),(422, 437, -265),(443, 475, -265),(485, 497, -265),
(157, 161, -264),(205, 207, -264),(245, 245, -264),(265, 267, -264),(270, 274, -264),(340, 341, -264),(344, 354, -264),(375, 381, -264),(387, 388, -264),(391, 391, -264),
(397, 404, -264),(407, 407, -264),(410, 419, -264),(424, 477, -264),(485, 497, -264),(157, 161, -263),(204, 210, -263),(244, 245, -263),(265, 266, -263),(271, 273, -263),
(339, 354, -263),(376, 381, -263),(387, 388, -263),(400, 407, -263),(410, 420, -263),(425, 478, -263),(486, 496, -263),(156, 161, -262),(204, 212, -262),(244, 244, -262),
(263, 265, -262),(270, 273, -262),(339, 348, -262),(350, 350, -262),(353, 355, -262),(377, 382, -262),(387, 387, -262),(400, 407, -262),(410, 421, -262),(428, 429, -262),
(431, 442, -262),(444, 444, -262),(446, 460, -262),(462, 462, -262),(465, 466, -262),(468, 468, -262),(470, 479, -262),(487, 495, -262),(156, 160, -261),(205, 209, -261),
(243, 244, -261),(262, 263, -261),(270, 272, -261),(338, 341, -261),(343, 343, -261),(354, 356, -261),(378, 382, -261),(386, 387, -261),(399, 407, -261),(410, 414, -261),
(416, 421, -261),(435, 442, -261),(448, 448, -261),(452, 452, -261),(473, 480, -261),(489, 493, -261),(155, 160, -260),(205, 208, -260),(242, 243, -260),(261, 262, -260),
(270, 272, -260),(338, 340, -260),(354, 358, -260),(379, 382, -260),(385, 388, -260),(397, 404, -260),(407, 408, -260),(410, 414, -260),(417, 422, -260),(437, 443, -260),
(475, 481, -260),(155, 159, -259),(205, 206, -259),(242, 242, -259),(260, 261, -259),(270, 272, -259),(338, 341, -259),(355, 360, -259),(381, 383, -259),(386, 389, -259),
(391, 391, -259),(395, 401, -259),(407, 407, -259),(411, 415, -259),(418, 423, -259),(438, 444, -259),(459, 459, -259),(463, 463, -259),(477, 482, -259),(155, 159, -258),
(204, 206, -258),(241, 242, -258),(259, 260, -258),(270, 272, -258),(337, 341, -258),(356, 362, -258),(381, 399, -258),(407, 408, -258),(411, 415, -258),(419, 424, -258),
(438, 448, -258),(450, 450, -258),(453, 453, -258),(455, 467, -258),(469, 469, -258),(477, 482, -258),(155, 159, -257),(203, 204, -257),(241, 241, -257),(257, 259, -257),
(269, 272, -257),(337, 342, -257),(357, 365, -257),(381, 398, -257),(407, 408, -257),(411, 412, -257),(414, 416, -257),(419, 425, -257),(439, 442, -257),(446, 456, -257),
(461, 462, -257),(467, 470, -257),(478, 482, -257),(156, 159, -256),(202, 203, -256),(240, 240, -256),(257, 258, -256),(269, 271, -256),(336, 344, -256),(359, 362, -256),
(364, 366, -256),(382, 398, -256),(408, 409, -256),(412, 413, -256),(415, 416, -256),(420, 425, -256),(439, 443, -256),(470, 472, -256),(479, 483, -256),(155, 159, -255),
(196, 197, -255),(202, 202, -255),(239, 240, -255),(256, 257, -255),(269, 271, -255),(336, 344, -255),(360, 367, -255),(382, 394, -255),(397, 398, -255),(408, 409, -255),
(412, 413, -255),(415, 417, -255),(421, 426, -255),(439, 443, -255),(471, 473, -255),(480, 483, -255),(155, 158, -254),(196, 198, -254),(200, 202, -254),(239, 239, -254),
(255, 255, -254),(269, 272, -254),(335, 337, -254),(342, 345, -254),(362, 367, -254),(383, 395, -254),(398, 398, -254),(408, 410, -254),(413, 414, -254),(416, 418, -254),
(422, 427, -254),(440, 443, -254),(472, 473, -254),(480, 483, -254),(156, 158, -253),(195, 201, -253),(238, 239, -253),(254, 256, -253),(269, 271, -253),(334, 337, -253),
(343, 347, -253),(365, 367, -253),(384, 391, -253),(393, 395, -253),(398, 399, -253),(409, 409, -253),(414, 414, -253),(416, 418, -253),(422, 428, -253),(440, 444, -253),
(474, 474, -253),(481, 484, -253),(155, 158, -252),(195, 200, -252),(238, 238, -252),(254, 254, -252),(269, 271, -252),(334, 336, -252),(344, 348, -252),(383, 390, -252),
(393, 395, -252),(398, 399, -252),(409, 410, -252),(414, 415, -252),(417, 419, -252),(423, 428, -252),(440, 445, -252),(474, 475, -252),(480, 484, -252),(156, 158, -251),
(195, 200, -251),(237, 238, -251),(253, 254, -251),(269, 271, -251),(333, 335, -251),(346, 349, -251),(381, 388, -251),(393, 395, -251),(399, 400, -251),(410, 410, -251),
(414, 416, -251),(418, 419, -251),(423, 428, -251),(440, 446, -251),(475, 475, -251),(481, 485, -251),(155, 158, -250),(195, 199, -250),(237, 238, -250),(252, 253, -250),
(268, 272, -250),(332, 336, -250),(347, 351, -250),(376, 376, -250),(378, 387, -250),(394, 396, -250),(399, 400, -250),(410, 411, -250),(415, 416, -250),(418, 420, -250),
(424, 429, -250),(441, 448, -250),(450, 450, -250),(475, 476, -250),(481, 485, -250),(155, 158, -249),(195, 195, -249),(197, 199, -249),(237, 237, -249),(252, 252, -249),
(268, 273, -249),(331, 334, -249),(348, 352, -249),(372, 385, -249),(394, 396, -249),(399, 400, -249),(411, 412, -249),(416, 421, -249),(425, 429, -249),(441, 464, -249),
(476, 476, -249),(482, 485, -249),(155, 158, -248),(195, 196, -248),(236, 236, -248),(252, 252, -248),(269, 273, -248),(331, 333, -248),(349, 354, -248),(371, 381, -248),
(395, 397, -248),(400, 400, -248),(411, 412, -248),(417, 421, -248),(425, 430, -248),(442, 448, -248),(452, 452, -248),(459, 459, -248),(461, 461, -248),(463, 467, -248),
(476, 477, -248),(481, 486, -248),(155, 158, -247),(195, 195, -247),(236, 236, -247),(251, 251, -247),(268, 273, -247),(330, 333, -247),(350, 358, -247),(368, 378, -247),
(395, 397, -247),(400, 401, -247),(412, 413, -247),(417, 422, -247),(425, 430, -247),(442, 449, -247),(467, 469, -247),(476, 477, -247),(482, 486, -247),(156, 159, -246),
(194, 195, -246),(235, 236, -246),(250, 251, -246),(268, 272, -246),(330, 332, -246),(352, 373, -246),(375, 379, -246),(395, 397, -246),(401, 402, -246),(413, 414, -246),
(418, 423, -246),(426, 431, -246),(443, 452, -246),(455, 456, -246),(458, 458, -246),(470, 471, -246),(478, 478, -246),(482, 486, -246),(156, 159, -245),(195, 195, -245),
(234, 235, -245),(250, 251, -245),(268, 271, -245),(329, 332, -245),(354, 371, -245),(377, 379, -245),(396, 398, -245),(401, 402, -245),(413, 414, -245),(419, 423, -245),
(427, 432, -245),(443, 464, -245),(470, 472, -245),(478, 478, -245),(483, 487, -245),(155, 158, -244),(194, 195, -244),(234, 234, -244),(250, 250, -244),(267, 271, -244),
(328, 331, -244),(357, 368, -244),(378, 380, -244),(396, 399, -244),(402, 402, -244),(414, 415, -244),(419, 424, -244),(427, 432, -244),(444, 468, -244),(472, 473, -244),
(477, 479, -244),(483, 488, -244),(155, 159, -243),(194, 195, -243),(234, 234, -243),(249, 250, -243),(267, 271, -243),(328, 330, -243),(358, 361, -243),(380, 381, -243),
(396, 399, -243),(402, 403, -243),(415, 416, -243),(420, 425, -243),(428, 433, -243),(446, 468, -243),(473, 474, -243),(479, 479, -243),(483, 488, -243),(155, 158, -242),
(194, 194, -242),(233, 234, -242),(249, 249, -242),(266, 270, -242),(328, 330, -242),(359, 361, -242),(381, 382, -242),(397, 400, -242),(403, 404, -242),(416, 417, -242),
(421, 425, -242),(428, 432, -242),(449, 470, -242),(474, 474, -242),(479, 479, -242),(484, 488, -242),(155, 159, -241),(194, 194, -241),(233, 233, -241),(249, 249, -241),
(265, 270, -241),(328, 330, -241),(361, 362, -241),(382, 383, -241),(396, 400, -241),(402, 407, -241),(416, 418, -241),(422, 426, -241),(428, 433, -241),(457, 457, -241);

INSERT INTO #R2(first, last, y)
VALUES (459, 471, -241),(474, 475, -241),(479, 480, -241),(484, 489, -241),(155, 159, -240),(193, 194, -240),(232, 233, -240),(248, 249, -240),(265, 269, -240),(327, 330, -240),
(361, 362, -240),(383, 383, -240),(396, 403, -240),(405, 409, -240),(417, 418, -240),(422, 427, -240),(429, 433, -240),(465, 471, -240),(475, 475, -240),(480, 480, -240),
(485, 489, -240),(154, 159, -239),(193, 194, -239),(232, 233, -239),(247, 248, -239),(265, 268, -239),(327, 329, -239),(362, 363, -239),(383, 384, -239),(395, 400, -239),
(408, 410, -239),(417, 419, -239),(422, 428, -239),(430, 434, -239),(467, 472, -239),(475, 475, -239),(480, 481, -239),(486, 490, -239),(155, 159, -238),(192, 193, -238),
(232, 232, -238),(247, 248, -238),(264, 268, -238),(327, 329, -238),(363, 364, -238),(384, 384, -238),(395, 399, -238),(410, 412, -238),(418, 419, -238),(423, 428, -238),
(430, 435, -238),(467, 472, -238),(475, 475, -238),(481, 481, -238),(486, 496, -238),(498, 498, -238),(154, 158, -237),(192, 193, -237),(231, 232, -237),(247, 247, -237),
(264, 268, -237),(326, 329, -237),(364, 364, -237),(377, 377, -237),(379, 379, -237),(384, 385, -237),(395, 397, -237),(411, 412, -237),(419, 419, -237),(424, 435, -237),
(468, 473, -237),(475, 477, -237),(481, 482, -237),(487, 501, -237),(154, 159, -236),(192, 192, -236),(231, 231, -236),(246, 247, -236),(264, 267, -236),(326, 328, -236),
(364, 365, -236),(374, 381, -236),(385, 385, -236),(395, 397, -236),(411, 412, -236),(419, 420, -236),(425, 435, -236),(469, 473, -236),(476, 477, -236),(481, 483, -236),
(488, 502, -236),(154, 158, -235),(192, 192, -235),(231, 231, -235),(246, 246, -235),(264, 266, -235),(326, 328, -235),(365, 366, -235),(373, 376, -235),(380, 382, -235),
(385, 386, -235),(394, 396, -235),(399, 399, -235),(412, 413, -235),(420, 421, -235),(425, 436, -235),(469, 473, -235),(476, 485, -235),(487, 504, -235),(153, 158, -234),
(191, 192, -234),(231, 231, -234),(246, 246, -234),(263, 267, -234),(324, 327, -234),(366, 367, -234),(373, 373, -234),(382, 384, -234),(386, 387, -234),(394, 395, -234),
(399, 401, -234),(412, 413, -234),(421, 421, -234),(426, 437, -234),(470, 474, -234),(476, 492, -234),(495, 495, -234),(497, 505, -234),(153, 157, -233),(191, 192, -233),
(230, 231, -233),(245, 246, -233),(263, 266, -233),(324, 327, -233),(367, 367, -233),(373, 373, -233),(383, 384, -233),(386, 387, -233),(394, 396, -233),(398, 402, -233),
(408, 410, -233),(413, 413, -233),(421, 422, -233),(427, 437, -233),(470, 488, -233),(498, 504, -233),(153, 157, -232),(192, 192, -232),(230, 230, -232),(245, 245, -232),
(263, 266, -232),(323, 326, -232),(367, 368, -232),(373, 373, -232),(384, 384, -232),(387, 387, -232),(394, 395, -232),(399, 401, -232),(407, 414, -232),(421, 423, -232),
(427, 438, -232),(470, 479, -232),(482, 485, -232),(498, 504, -232),(152, 157, -231),(192, 192, -231),(229, 230, -231),(244, 245, -231),(262, 266, -231),(322, 326, -231),
(368, 368, -231),(373, 373, -231),(385, 385, -231),(387, 388, -231),(394, 396, -231),(399, 401, -231),(407, 413, -231),(423, 423, -231),(428, 429, -231),(431, 438, -231),
(470, 478, -231),(483, 483, -231),(497, 506, -231),(509, 510, -231),(152, 156, -230),(191, 191, -230),(229, 229, -230),(244, 244, -230),(262, 265, -230),(321, 325, -230),
(368, 369, -230),(373, 374, -230),(384, 384, -230),(388, 388, -230),(394, 395, -230),(400, 401, -230),(407, 409, -230),(412, 413, -230),(423, 424, -230),(429, 439, -230),
(464, 464, -230),(470, 476, -230),(498, 512, -230),(152, 156, -229),(192, 192, -229),(228, 229, -229),(244, 244, -229),(262, 266, -229),(320, 324, -229),(369, 370, -229),
(374, 375, -229),(383, 384, -229),(388, 389, -229),(394, 396, -229),(400, 402, -229),(406, 407, -229),(413, 413, -229),(424, 425, -229),(430, 431, -229),(434, 441, -229),
(459, 476, -229),(501, 512, -229),(151, 155, -228),(191, 192, -228),(228, 228, -228),(243, 244, -228),(263, 266, -228),(318, 324, -228),(369, 370, -228),(375, 378, -228),
(383, 384, -228),(388, 389, -228),(395, 396, -228),(401, 407, -228),(411, 413, -228),(425, 426, -228),(431, 442, -228),(457, 478, -228),(503, 513, -228),(151, 156, -227),
(191, 192, -227),(226, 228, -227),(243, 244, -227),(262, 266, -227),(294, 294, -227),(316, 318, -227),(320, 323, -227),(370, 370, -227),(377, 378, -227),(380, 383, -227),
(389, 391, -227),(395, 397, -227),(401, 406, -227),(411, 414, -227),(426, 428, -227),(432, 434, -227),(436, 444, -227),(447, 447, -227),(450, 452, -227),(455, 472, -227),
(474, 480, -227),(505, 514, -227),(151, 155, -226),(192, 192, -226),(225, 228, -226),(242, 243, -226),(262, 265, -226),(291, 298, -226),(314, 316, -226),(322, 324, -226),
(370, 372, -226),(390, 391, -226),(395, 405, -226),(410, 415, -226),(428, 429, -226),(434, 435, -226),(438, 469, -226),(478, 482, -226),(506, 515, -226),(150, 155, -225),
(191, 192, -225),(223, 228, -225),(243, 243, -225),(262, 266, -225),(291, 292, -225),(296, 300, -225),(311, 316, -225),(321, 324, -225),(371, 373, -225),(391, 393, -225),
(396, 402, -225),(404, 411, -225),(414, 415, -225),(429, 430, -225),(435, 460, -225),(466, 468, -225),(480, 485, -225),(508, 509, -225),(512, 515, -225),(151, 154, -224),
(188, 188, -224),(192, 192, -224),(223, 225, -224),(228, 229, -224),(242, 243, -224),(263, 267, -224),(291, 292, -224),(300, 304, -224),(306, 306, -224),(308, 314, -224),
(322, 323, -224),(373, 373, -224),(392, 393, -224),(397, 401, -224),(403, 403, -224),(405, 411, -224),(415, 417, -224),(429, 432, -224),(437, 438, -224),(440, 457, -224),
(467, 467, -224),(483, 492, -224),(513, 516, -224),(150, 154, -223),(187, 189, -223),(191, 192, -223),(223, 226, -223),(228, 230, -223),(242, 244, -223),(263, 267, -223),
(292, 294, -223),(301, 301, -223),(304, 312, -223),(321, 323, -223),(373, 375, -223),(394, 395, -223),(398, 413, -223),(416, 418, -223),(431, 433, -223),(437, 440, -223),
(442, 448, -223),(450, 450, -223),(452, 456, -223),(466, 467, -223),(484, 484, -223),(487, 487, -223),(489, 489, -223),(491, 493, -223),(513, 517, -223),(150, 155, -222),
(186, 189, -222),(191, 192, -222),(222, 223, -222),(225, 226, -222),(229, 230, -222),(241, 247, -222),(262, 266, -222),(293, 297, -222),(303, 309, -222),(321, 323, -222),
(375, 376, -222),(395, 396, -222),(399, 413, -222),(416, 418, -222),(432, 433, -222),(440, 445, -222),(454, 456, -222),(493, 495, -222),(514, 517, -222),(150, 155, -221),
(185, 192, -221),(223, 223, -221),(227, 228, -221),(230, 233, -221),(241, 248, -221),(262, 265, -221),(267, 267, -221),(295, 305, -221),(321, 323, -221),(376, 377, -221),
(395, 396, -221),(403, 404, -221),(406, 406, -221),(412, 414, -221),(418, 419, -221),(433, 436, -221),(441, 445, -221),(455, 456, -221),(467, 468, -221),(494, 495, -221),
(514, 518, -221),(150, 155, -220),(186, 186, -220),(189, 190, -220),(222, 222, -220),(228, 230, -220),(232, 235, -220),(237, 243, -220),(245, 248, -220),(262, 264, -220),
(266, 267, -220),(320, 323, -220),(377, 378, -220),(396, 397, -220),(412, 415, -220),(419, 420, -220),(435, 436, -220),(442, 445, -220),(456, 456, -220),(468, 468, -220),
(494, 495, -220),(515, 519, -220),(150, 154, -219),(185, 186, -219),(222, 223, -219),(229, 231, -219),(234, 239, -219),(241, 241, -219),(243, 248, -219),(262, 264, -219),
(267, 268, -219),(319, 322, -219),(377, 379, -219),(397, 398, -219),(414, 416, -219),(420, 421, -219),(436, 439, -219),(443, 445, -219),(456, 457, -219),(468, 469, -219),
(495, 496, -219),(516, 519, -219),(150, 155, -218),(185, 185, -218),(222, 222, -218),(230, 233, -218),(241, 244, -218),(247, 248, -218),(261, 264, -218),(268, 268, -218),
(318, 322, -218),(377, 381, -218),(398, 399, -218),(415, 418, -218),(420, 422, -218),(438, 440, -218),(443, 446, -218),(457, 457, -218),(469, 469, -218),(495, 497, -218),
(516, 519, -218),(151, 154, -217),(185, 186, -217),(222, 222, -217),(233, 235, -217),(237, 242, -217),(247, 248, -217),(261, 264, -217),(317, 319, -217),(321, 323, -217),
(377, 382, -217),(398, 400, -217),(416, 418, -217),(422, 424, -217),(440, 446, -217),(457, 458, -217),(469, 469, -217),(495, 497, -217),(516, 520, -217),(151, 155, -216),
(185, 185, -216),(221, 222, -216),(234, 235, -216),(237, 238, -216),(247, 248, -216),(261, 264, -216),(316, 317, -216),(321, 322, -216),(376, 382, -216),(399, 400, -216),
(417, 419, -216),(423, 425, -216),(441, 447, -216),(457, 458, -216),(469, 469, -216),(496, 496, -216),(517, 521, -216),(151, 155, -215),(185, 185, -215),(221, 221, -215),
(247, 248, -215),(261, 264, -215),(313, 316, -215),(321, 322, -215),(377, 379, -215),(381, 384, -215),(399, 401, -215),(418, 421, -215),(425, 427, -215),(443, 446, -215),
(458, 459, -215),(495, 497, -215),(517, 521, -215),(152, 155, -214),(185, 185, -214),(221, 222, -214),(247, 247, -214),(261, 263, -214),(293, 293, -214),(295, 295, -214),
(311, 315, -214),(320, 323, -214),(377, 378, -214),(382, 386, -214),(400, 400, -214),(419, 423, -214),(425, 427, -214),(444, 448, -214),(458, 459, -214),(495, 497, -214),
(517, 521, -214),(152, 156, -213),(184, 184, -213),(221, 224, -213),(246, 247, -213),(261, 264, -213),(291, 298, -213),(309, 314, -213),(320, 322, -213),(376, 378, -213),
(383, 388, -213),(392, 395, -213),(400, 401, -213),(420, 423, -213),(428, 429, -213),(445, 448, -213),(459, 459, -213),(494, 495, -213),(497, 498, -213),(518, 521, -213),
(152, 157, -212),(185, 185, -212),(222, 225, -212),(246, 247, -212),(261, 263, -212),(291, 292, -212),(297, 302, -212),(304, 308, -212),(310, 313, -212),(320, 322, -212),
(376, 378, -212),(385, 388, -212),(393, 397, -212),(401, 401, -212),(421, 424, -212),(428, 430, -212),(446, 449, -212),(459, 460, -212),(493, 494, -212),(497, 497, -212),
(518, 522, -212),(153, 157, -211),(185, 185, -211),(223, 226, -211),(246, 247, -211),(261, 263, -211),(291, 293, -211),(300, 300, -211),(302, 306, -211),(309, 311, -211),
(320, 322, -211),(368, 372, -211),(376, 377, -211),(386, 390, -211),(393, 402, -211),(422, 425, -211),(430, 432, -211),(446, 449, -211),(460, 460, -211),(493, 493, -211),
(497, 497, -211),(518, 522, -211),(153, 158, -210),(185, 186, -210),(224, 227, -210),(246, 247, -210),(261, 264, -210),(293, 294, -210),(308, 310, -210),(320, 321, -210),
(368, 371, -210),(375, 378, -210),(387, 391, -210),(393, 402, -210),(423, 427, -210),(430, 436, -210),(447, 450, -210),(491, 493, -210),(496, 498, -210),(519, 522, -210),
(154, 159, -209),(184, 185, -209),(224, 225, -209),(227, 229, -209),(235, 235, -209),(237, 247, -209),(261, 264, -209),(293, 296, -209),(298, 298, -209),(300, 300, -209),
(305, 308, -209),(319, 322, -209),(366, 371, -209),(375, 377, -209),(389, 396, -209),(398, 402, -209),(424, 430, -209),(436, 438, -209),(447, 451, -209),(490, 491, -209),
(495, 496, -209),(519, 523, -209),(153, 158, -208),(185, 185, -208),(224, 225, -208),(229, 243, -208),(245, 245, -208),(261, 263, -208),(296, 306, -208),(319, 322, -208),
(365, 372, -208),(375, 377, -208),(390, 395, -208),(400, 403, -208),(405, 406, -208),(424, 429, -208),(437, 439, -208),(448, 451, -208),(487, 490, -208),(495, 499, -208),
(519, 523, -208),(153, 158, -207),(185, 186, -207),(224, 224, -207),(231, 234, -207),(236, 236, -207),(240, 241, -207),(261, 263, -207),(302, 302, -207),(318, 323, -207),
(364, 368, -207),(370, 372, -207),(374, 376, -207),(390, 395, -207),(401, 409, -207),(424, 428, -207),(439, 440, -207),(448, 452, -207),(485, 488, -207),(494, 499, -207),
(520, 523, -207),(153, 158, -206),(185, 186, -206),(224, 224, -206),(240, 241, -206),(261, 264, -206),(318, 322, -206),(363, 366, -206),(370, 376, -206),(391, 395, -206),
(401, 409, -206),(424, 426, -206),(440, 440, -206),(449, 452, -206),(482, 484, -206),(493, 494, -206),(496, 499, -206),(519, 523, -206),(152, 157, -205),(186, 186, -205),
(224, 224, -205),(240, 240, -205),(261, 264, -205),(317, 318, -205),(320, 323, -205),(359, 360, -205),(363, 365, -205),(370, 375, -205),(391, 396, -205),(402, 411, -205),
(424, 426, -205),(429, 431, -205),(440, 441, -205),(450, 453, -205),(479, 483, -205),(491, 492, -205),(497, 499, -205),(519, 524, -205),(153, 157, -204),(186, 187, -204),
(224, 224, -204),(240, 241, -204),(262, 264, -204),(315, 317, -204),(321, 323, -204),(358, 364, -204),(370, 375, -204),(392, 395, -204),(403, 411, -204),(423, 425, -204),
(428, 431, -204),(440, 443, -204),(450, 453, -204),(477, 479, -204),(489, 491, -204),(497, 499, -204),(519, 523, -204),(152, 157, -203),(186, 187, -203),(224, 224, -203),
(240, 240, -203),(262, 263, -203),(315, 316, -203),(321, 323, -203),(357, 364, -203),(370, 375, -203),(392, 395, -203),(404, 407, -203),(410, 413, -203),(423, 425, -203),
(428, 431, -203),(441, 444, -203),(451, 454, -203),(476, 478, -203),(487, 489, -203),(496, 499, -203),(519, 523, -203),(153, 157, -202),(187, 187, -202),(224, 224, -202),
(240, 240, -202),(261, 264, -202),(314, 315, -202),(322, 324, -202),(357, 364, -202),(370, 374, -202),(393, 395, -202),(404, 408, -202),(410, 413, -202),(418, 418, -202),
(423, 425, -202),(428, 430, -202),(436, 437, -202),(441, 442, -202),(444, 446, -202),(450, 454, -202),(475, 476, -202),(484, 488, -202),(495, 498, -202),(520, 524, -202),
(153, 156, -201),(187, 188, -201),(223, 224, -201),(240, 241, -201),(262, 264, -201),(312, 314, -201),(321, 324, -201),(356, 363, -201),(371, 374, -201),(393, 396, -201),
(405, 407, -201),(412, 414, -201),(417, 419, -201),(423, 425, -201),(429, 430, -201),(435, 437, -201),(441, 441, -201),(445, 454, -201),(474, 476, -201),(482, 483, -201),
(485, 485, -201),(494, 496, -201),(498, 498, -201),(520, 523, -201),(152, 157, -200),(187, 188, -200),(224, 224, -200),(241, 241, -200),(262, 264, -200),(311, 312, -200),
(322, 324, -200),(355, 363, -200),(371, 374, -200),(393, 395, -200),(405, 408, -200),(412, 415, -200),(417, 420, -200),(423, 425, -200),(429, 430, -200),(435, 438, -200),
(440, 455, -200),(473, 474, -200),(480, 482, -200),(491, 493, -200),(497, 498, -200),(519, 523, -200),(153, 157, -199),(188, 189, -199),(223, 224, -199),(240, 241, -199),
(262, 264, -199),(323, 325, -199),(354, 362, -199),(372, 374, -199),(393, 395, -199),(405, 408, -199),(413, 415, -199),(417, 421, -199),(423, 425, -199),(430, 437, -199),
(440, 455, -199),(473, 474, -199),(479, 480, -199),(490, 492, -199),(497, 497, -199),(519, 523, -199),(153, 157, -198),(188, 188, -198),(224, 224, -198),(261, 265, -198),
(323, 325, -198),(354, 356, -198),(358, 362, -198),(372, 374, -198),(393, 394, -198),(406, 407, -198),(414, 434, -198),(440, 449, -198),(451, 452, -198),(454, 454, -198),
(472, 473, -198),(477, 480, -198),(487, 490, -198),(496, 497, -198),(516, 516, -198),(519, 523, -198),(154, 158, -197),(188, 189, -197),(224, 224, -197),(240, 240, -197),
(261, 265, -197),(323, 325, -197),(353, 355, -197),(359, 362, -197),(372, 374, -197),(406, 406, -197),(414, 419, -197),(421, 432, -197),(439, 445, -197),(472, 472, -197),
(476, 478, -197),(485, 488, -197),(494, 497, -197),(516, 524, -197),(154, 158, -196),(189, 189, -196),(224, 224, -196),(241, 241, -196),(261, 265, -196),(324, 326, -196),
(353, 355, -196),(358, 361, -196),(373, 374, -196),(414, 419, -196),(422, 432, -196),(438, 443, -196),(471, 472, -196),(476, 477, -196),(484, 486, -196),(493, 496, -196),
(498, 498, -196),(516, 523, -196),(154, 159, -195),(189, 189, -195),(224, 224, -195),(241, 241, -195),(261, 265, -195),(324, 326, -195),(352, 354, -195),(358, 361, -195),
(374, 374, -195),(415, 419, -195),(423, 433, -195),(436, 442, -195),(470, 471, -195),(475, 476, -195),(484, 484, -195),(491, 498, -195),(516, 523, -195),(155, 159, -194);

INSERT INTO #R2(first, last, y)
VALUES (189, 190, -194),(224, 224, -194),(241, 241, -194),(261, 266, -194),(324, 327, -194),(351, 354, -194),(359, 361, -194),(374, 375, -194),(415, 419, -194),(424, 442, -194),
(470, 471, -194),(474, 475, -194),(482, 483, -194),(490, 491, -194),(493, 498, -194),(516, 523, -194),(155, 160, -193),(190, 190, -193),(224, 224, -193),(241, 242, -193),
(260, 262, -193),(264, 266, -193),(325, 327, -193),(351, 353, -193),(359, 361, -193),(415, 419, -193),(425, 438, -193),(440, 441, -193),(469, 470, -193),(474, 474, -193),
(482, 483, -193),(489, 490, -193),(493, 497, -193),(516, 516, -193),(520, 524, -193),(156, 160, -192),(189, 190, -192),(224, 224, -192),(260, 262, -192),(265, 267, -192),
(325, 327, -192),(350, 352, -192),(359, 361, -192),(416, 419, -192),(426, 432, -192),(434, 435, -192),(440, 442, -192),(468, 469, -192),(473, 474, -192),(481, 481, -192),
(487, 489, -192),(493, 497, -192),(516, 516, -192),(520, 523, -192),(156, 162, -191),(189, 191, -191),(224, 224, -191),(241, 241, -191),(260, 262, -191),(265, 267, -191),
(326, 327, -191),(350, 352, -191),(359, 360, -191),(416, 419, -191),(426, 428, -191),(440, 442, -191),(467, 468, -191),(473, 473, -191),(480, 481, -191),(485, 486, -191),
(493, 496, -191),(515, 516, -191),(520, 523, -191),(156, 162, -190),(190, 191, -190),(224, 224, -190),(241, 241, -190),(259, 262, -190),(265, 268, -190),(326, 328, -190),
(349, 352, -190),(359, 361, -190),(416, 419, -190),(427, 428, -190),(440, 443, -190),(447, 447, -190),(467, 468, -190),(472, 473, -190),(479, 480, -190),(485, 486, -190),
(495, 495, -190),(515, 515, -190),(519, 523, -190),(157, 163, -189),(190, 193, -189),(224, 224, -189),(241, 241, -189),(259, 261, -189),(265, 268, -189),(326, 328, -189),
(349, 351, -189),(360, 361, -189),(416, 418, -189),(427, 429, -189),(440, 450, -189),(466, 467, -189),(471, 472, -189),(478, 479, -189),(483, 484, -189),(494, 495, -189),
(515, 515, -189),(520, 524, -189),(158, 164, -188),(190, 194, -188),(224, 225, -188),(242, 242, -188),(259, 261, -188),(266, 267, -188),(326, 328, -188),(348, 351, -188),
(360, 360, -188),(417, 418, -188),(428, 429, -188),(441, 452, -188),(465, 466, -188),(470, 471, -188),(477, 478, -188),(483, 484, -188),(492, 493, -188),(515, 516, -188),
(520, 523, -188),(158, 165, -187),(190, 195, -187),(224, 225, -187),(259, 261, -187),(266, 266, -187),(268, 268, -187),(327, 328, -187),(348, 350, -187),(360, 360, -187),
(417, 419, -187),(428, 429, -187),(443, 446, -187),(448, 455, -187),(464, 465, -187),(469, 471, -187),(477, 478, -187),(482, 483, -187),(491, 492, -187),(515, 515, -187),
(520, 523, -187),(159, 165, -186),(191, 197, -186),(225, 225, -186),(242, 242, -186),(259, 260, -186),(266, 269, -186),(326, 329, -186),(339, 339, -186),(348, 350, -186),
(417, 418, -186),(428, 430, -186),(444, 446, -186),(449, 457, -186),(462, 464, -186),(468, 469, -186),(476, 477, -186),(482, 482, -186),(491, 492, -186),(514, 515, -186),
(520, 523, -186),(160, 167, -185),(191, 192, -185),(197, 200, -185),(225, 225, -185),(241, 242, -185),(258, 260, -185),(266, 267, -185),(269, 269, -185),(326, 328, -185),
(338, 342, -185),(347, 350, -185),(417, 419, -185),(428, 431, -185),(444, 446, -185),(452, 463, -185),(467, 468, -185),(474, 476, -185),(480, 481, -185),(490, 491, -185),
(514, 514, -185),(520, 522, -185),(160, 167, -184),(192, 193, -184),(199, 202, -184),(224, 225, -184),(242, 243, -184),(258, 261, -184),(267, 267, -184),(269, 270, -184),
(327, 328, -184),(335, 344, -184),(347, 350, -184),(418, 418, -184),(429, 432, -184),(444, 446, -184),(453, 456, -184),(459, 462, -184),(465, 467, -184),(473, 474, -184),
(479, 480, -184),(488, 489, -184),(514, 514, -184),(519, 522, -184),(161, 168, -183),(192, 193, -183),(202, 204, -183),(224, 226, -183),(243, 244, -183),(258, 260, -183),
(267, 267, -183),(270, 271, -183),(327, 328, -183),(334, 349, -183),(418, 418, -183),(428, 433, -183),(444, 446, -183),(454, 455, -183),(460, 465, -183),(471, 473, -183),
(478, 479, -183),(486, 488, -183),(513, 514, -183),(519, 522, -183),(162, 169, -182),(193, 194, -182),(205, 210, -182),(217, 217, -182),(220, 220, -182),(222, 225, -182),
(243, 245, -182),(258, 260, -182),(267, 268, -182),(270, 270, -182),(327, 328, -182),(333, 337, -182),(339, 339, -182),(341, 349, -182),(418, 418, -182),(429, 433, -182),
(443, 446, -182),(454, 456, -182),(462, 470, -182),(476, 478, -182),(481, 481, -182),(483, 487, -182),(513, 513, -182),(518, 522, -182),(162, 169, -181),(193, 194, -181),
(209, 209, -181),(211, 215, -181),(217, 220, -181),(222, 226, -181),(243, 247, -181),(258, 260, -181),(268, 268, -181),(271, 272, -181),(327, 329, -181),(333, 336, -181),
(343, 349, -181),(429, 434, -181),(444, 447, -181),(454, 456, -181),(464, 480, -181),(482, 483, -181),(509, 509, -181),(512, 512, -181),(518, 522, -181),(164, 170, -180),
(193, 195, -180),(225, 226, -180),(242, 249, -180),(257, 259, -180),(268, 268, -180),(271, 271, -180),(327, 328, -180),(332, 335, -180),(344, 349, -180),(429, 434, -180),
(444, 446, -180),(455, 457, -180),(467, 480, -180),(508, 512, -180),(517, 521, -180),(164, 170, -179),(192, 195, -179),(226, 226, -179),(243, 244, -179),(249, 251, -179),
(258, 259, -179),(268, 269, -179),(271, 272, -179),(327, 328, -179),(331, 334, -179),(344, 349, -179),(429, 429, -179),(432, 434, -179),(444, 446, -179),(455, 456, -179),
(471, 476, -179),(508, 512, -179),(517, 521, -179),(165, 171, -178),(192, 195, -178),(226, 227, -178),(251, 254, -178),(257, 260, -178),(269, 269, -178),(272, 272, -178),
(326, 329, -178),(331, 337, -178),(345, 348, -178),(429, 429, -178),(433, 435, -178),(437, 438, -178),(443, 444, -178),(446, 446, -178),(456, 457, -178),(506, 508, -178),
(510, 512, -178),(517, 520, -178),(165, 171, -177),(193, 195, -177),(227, 227, -177),(243, 244, -177),(253, 255, -177),(257, 259, -177),(269, 270, -177),(272, 273, -177),
(327, 328, -177),(331, 339, -177),(345, 348, -177),(433, 439, -177),(443, 447, -177),(456, 457, -177),(506, 506, -177),(511, 511, -177),(516, 520, -177),(167, 172, -176),
(193, 195, -176),(227, 227, -176),(244, 244, -176),(255, 260, -176),(270, 270, -176),(272, 273, -176),(326, 328, -176),(330, 340, -176),(345, 348, -176),(433, 440, -176),
(443, 443, -176),(446, 446, -176),(456, 458, -176),(505, 506, -176),(515, 519, -176),(167, 172, -175),(195, 196, -175),(227, 227, -175),(244, 244, -175),(256, 260, -175),
(270, 272, -175),(326, 328, -175),(331, 333, -175),(336, 339, -175),(345, 348, -175),(434, 440, -175),(443, 444, -175),(446, 446, -175),(458, 459, -175),(504, 506, -175),
(515, 519, -175),(168, 172, -174),(195, 197, -174),(227, 227, -174),(244, 245, -174),(257, 260, -174),(272, 272, -174),(326, 328, -174),(337, 339, -174),(346, 347, -174),
(434, 443, -174),(446, 447, -174),(458, 459, -174),(504, 504, -174),(514, 518, -174),(169, 173, -173),(196, 198, -173),(228, 229, -173),(245, 245, -173),(258, 260, -173),
(326, 327, -173),(338, 340, -173),(345, 348, -173),(434, 444, -173),(446, 446, -173),(459, 460, -173),(503, 504, -173),(513, 517, -173),(169, 174, -172),(198, 200, -172),
(228, 228, -172),(245, 245, -172),(258, 259, -172),(325, 327, -172),(337, 339, -172),(346, 348, -172),(434, 446, -172),(459, 460, -172),(502, 502, -172),(513, 517, -172),
(170, 174, -171),(199, 202, -171),(228, 229, -171),(245, 245, -171),(258, 260, -171),(325, 327, -171),(332, 333, -171),(337, 339, -171),(346, 347, -171),(434, 437, -171),
(439, 445, -171),(460, 461, -171),(500, 502, -171),(511, 516, -171),(170, 175, -170),(201, 203, -170),(229, 229, -170),(245, 246, -170),(258, 260, -170),(325, 327, -170),
(331, 334, -170),(337, 339, -170),(346, 348, -170),(434, 437, -170),(440, 445, -170),(461, 463, -170),(467, 469, -170),(499, 500, -170),(511, 515, -170),(171, 176, -169),
(203, 204, -169),(230, 230, -169),(245, 247, -169),(258, 260, -169),(324, 326, -169),(331, 338, -169),(346, 347, -169),(434, 436, -169),(440, 444, -169),(462, 464, -169),
(466, 470, -169),(497, 499, -169),(510, 515, -169),(172, 177, -168),(204, 206, -168),(230, 230, -168),(246, 251, -168),(259, 260, -168),(324, 326, -168),(330, 338, -168),
(346, 347, -168),(434, 436, -168),(441, 444, -168),(463, 467, -168),(469, 472, -168),(496, 497, -168),(509, 514, -168),(172, 179, -167),(205, 207, -167),(231, 231, -167),
(246, 252, -167),(259, 260, -167),(323, 326, -167),(330, 338, -167),(434, 436, -167),(441, 443, -167),(464, 467, -167),(471, 473, -167),(482, 483, -167),(487, 487, -167),
(490, 490, -167),(493, 496, -167),(507, 513, -167),(173, 179, -166),(207, 208, -166),(230, 231, -166),(246, 246, -166),(249, 250, -166),(252, 253, -166),(259, 260, -166),
(323, 325, -166),(330, 332, -166),(334, 338, -166),(434, 435, -166),(441, 443, -166),(472, 474, -166),(482, 486, -166),(489, 492, -166),(507, 512, -166),(174, 181, -165),
(207, 209, -165),(230, 232, -165),(245, 246, -165),(248, 249, -165),(252, 252, -165),(260, 261, -165),(323, 325, -165),(329, 332, -165),(334, 338, -165),(434, 435, -165),
(442, 443, -165),(474, 477, -165),(482, 483, -165),(505, 511, -165),(174, 182, -164),(209, 210, -164),(229, 234, -164),(243, 246, -164),(248, 248, -164),(252, 253, -164),
(259, 261, -164),(323, 324, -164),(329, 331, -164),(334, 337, -164),(434, 434, -164),(442, 444, -164),(475, 483, -164),(504, 509, -164),(175, 184, -163),(210, 211, -163),
(229, 235, -163),(238, 238, -163),(241, 244, -163),(246, 247, -163),(253, 253, -163),(260, 261, -163),(322, 324, -163),(329, 331, -163),(334, 337, -163),(442, 444, -163),
(460, 461, -163),(479, 483, -163),(502, 509, -163),(177, 185, -162),(210, 211, -162),(228, 229, -162),(231, 231, -162),(235, 242, -162),(245, 246, -162),(253, 254, -162),
(261, 261, -162),(322, 324, -162),(329, 331, -162),(335, 338, -162),(442, 444, -162),(459, 463, -162),(500, 507, -162),(178, 187, -161),(210, 212, -161),(228, 234, -161),
(239, 239, -161),(243, 246, -161),(253, 254, -161),(261, 262, -161),(321, 323, -161),(329, 332, -161),(335, 338, -161),(442, 445, -161),(458, 460, -161),(462, 464, -161),
(499, 506, -161),(180, 189, -160),(206, 206, -160),(208, 212, -160),(228, 230, -160),(233, 237, -160),(241, 243, -160),(252, 253, -160),(261, 262, -160),(321, 322, -160),
(329, 331, -160),(336, 338, -160),(443, 444, -160),(458, 459, -160),(463, 466, -160),(497, 505, -160),(179, 191, -159),(206, 212, -159),(229, 230, -159),(236, 239, -159),
(241, 242, -159),(250, 252, -159),(262, 262, -159),(320, 322, -159),(325, 327, -159),(329, 331, -159),(336, 338, -159),(443, 444, -159),(459, 460, -159),(464, 468, -159),
(494, 503, -159),(179, 192, -158),(206, 209, -158),(211, 211, -158),(230, 230, -158),(248, 250, -158),(262, 263, -158),(320, 321, -158),(325, 328, -158),(330, 332, -158),
(337, 338, -158),(443, 444, -158),(460, 461, -158),(466, 469, -158),(490, 501, -158),(180, 191, -157),(208, 210, -157),(230, 232, -157),(248, 249, -157),(262, 263, -157),
(319, 321, -157),(324, 328, -157),(330, 332, -157),(337, 339, -157),(442, 445, -157),(461, 463, -157),(469, 471, -157),(485, 499, -157),(180, 188, -156),(209, 210, -156),
(232, 232, -156),(247, 250, -156),(263, 263, -156),(319, 320, -156),(323, 332, -156),(338, 339, -156),(442, 444, -156),(462, 465, -156),(470, 474, -156),(477, 477, -156),
(479, 498, -156),(182, 188, -155),(210, 212, -155),(232, 233, -155),(246, 250, -155),(263, 264, -155),(318, 320, -155),(324, 333, -155),(339, 340, -155),(442, 444, -155),
(465, 469, -155),(471, 494, -155),(183, 190, -154),(211, 212, -154),(233, 234, -154),(239, 242, -154),(244, 247, -154),(249, 251, -154),(264, 265, -154),(317, 319, -154),
(323, 325, -154),(328, 333, -154),(339, 340, -154),(442, 445, -154),(467, 490, -154),(184, 191, -153),(212, 214, -153),(234, 237, -153),(239, 245, -153),(249, 251, -153),
(264, 265, -153),(317, 318, -153),(323, 325, -153),(328, 334, -153),(441, 445, -153),(471, 474, -153),(476, 487, -153),(185, 193, -152),(213, 214, -152),(241, 243, -152),
(250, 251, -152),(264, 265, -152),(316, 318, -152),(323, 325, -152),(329, 334, -152),(441, 446, -152),(476, 483, -152),(187, 195, -151),(214, 215, -151),(242, 243, -151),
(250, 252, -151),(265, 266, -151),(316, 317, -151),(323, 325, -151),(330, 335, -151),(440, 446, -151),(476, 482, -151),(188, 197, -150),(215, 217, -150),(243, 245, -150),
(251, 252, -150),(266, 267, -150),(315, 316, -150),(323, 324, -150),(331, 336, -150),(441, 443, -150),(445, 446, -150),(476, 481, -150),(190, 202, -149),(204, 204, -149),
(217, 217, -149),(245, 246, -149),(251, 253, -149),(267, 267, -149),(314, 316, -149),(323, 324, -149),(332, 337, -149),(439, 442, -149),(445, 447, -149),(475, 479, -149),
(191, 205, -148),(217, 218, -148),(245, 246, -148),(252, 254, -148),(267, 268, -148),(313, 315, -148),(322, 324, -148),(334, 338, -148),(439, 442, -148),(445, 447, -148),
(474, 479, -148),(193, 207, -147),(217, 219, -147),(247, 248, -147),(253, 254, -147),(268, 268, -147),(313, 314, -147),(322, 325, -147),(335, 339, -147),(438, 442, -147),
(446, 447, -147),(473, 478, -147),(195, 208, -146),(218, 220, -146),(248, 249, -146),(253, 255, -146),(268, 269, -146),(312, 314, -146),(322, 324, -146),(336, 340, -146),
(437, 438, -146),(440, 441, -146),(445, 447, -146),(473, 477, -146),(196, 206, -145),(220, 221, -145),(249, 251, -145),(254, 256, -145),(269, 269, -145),(311, 313, -145),
(322, 324, -145),(338, 341, -145),(436, 437, -145),(439, 440, -145),(446, 447, -145),(472, 477, -145),(195, 204, -144),(206, 206, -144),(221, 222, -144),(251, 253, -144),
(255, 257, -144),(269, 270, -144),(310, 312, -144),(323, 325, -144),(339, 341, -144),(396, 398, -144),(400, 400, -144),(408, 410, -144),(435, 436, -144),(439, 440, -144),
(446, 447, -144),(471, 475, -144),(196, 203, -143),(222, 223, -143),(253, 254, -143),(256, 258, -143),(270, 271, -143),(310, 311, -143),(322, 324, -143),(341, 342, -143),
(394, 399, -143),(401, 403, -143),(407, 413, -143),(434, 435, -143),(438, 439, -143),(446, 447, -143),(469, 475, -143),(196, 205, -142),(223, 224, -142),(253, 254, -142),
(256, 259, -142),(271, 272, -142),(309, 311, -142),(322, 324, -142),(342, 342, -142),(393, 394, -142),(402, 404, -142),(406, 407, -142),(412, 413, -142),(433, 435, -142),
(437, 438, -142),(445, 446, -142),(460, 460, -142),(463, 474, -142),(198, 206, -141),(223, 225, -141),(255, 260, -141),(272, 273, -141),(309, 310, -141),(323, 325, -141),
(386, 386, -141),(393, 394, -141),(403, 406, -141),(413, 414, -141),(432, 433, -141),(436, 438, -141),(446, 446, -141),(458, 473, -141),(199, 207, -140),(224, 226, -140),
(256, 260, -140),(273, 274, -140),(307, 310, -140),(323, 325, -140),(386, 393, -140),(405, 406, -140),(414, 414, -140),(431, 432, -140),(435, 436, -140),(445, 447, -140),
(456, 458, -140),(460, 460, -140),(462, 466, -140),(468, 473, -140),(200, 209, -139),(224, 227, -139),(258, 261, -139),(274, 275, -139),(307, 309, -139),(323, 325, -139),
(384, 387, -139),(390, 392, -139),(405, 407, -139),(414, 414, -139),(431, 431, -139),(435, 436, -139),(445, 446, -139),(455, 456, -139),(462, 462, -139),(467, 472, -139),
(202, 212, -138),(224, 228, -138),(259, 262, -138),(273, 275, -138),(307, 307, -138),(322, 325, -138),(384, 385, -138),(391, 391, -138),(414, 415, -138),(430, 431, -138),
(434, 435, -138),(445, 446, -138),(448, 449, -138),(454, 456, -138),(459, 462, -138),(467, 472, -138),(204, 230, -137),(261, 264, -137),(273, 277, -137),(305, 306, -137),
(321, 325, -137),(383, 384, -137),(391, 391, -137),(399, 402, -137),(415, 415, -137),(429, 430, -137),(432, 434, -137),(445, 449, -137),(454, 460, -137),(466, 470, -137);

INSERT INTO #R2 (first, last, y)
VALUES (206, 231, -136),(262, 264, -136),(274, 274, -136),(276, 278, -136),(304, 305, -136),(322, 326, -136),(383, 383, -136),(390, 391, -136),(397, 400, -136),(402, 404, -136),
(415, 416, -136),(429, 429, -136),(432, 433, -136),(444, 450, -136),(455, 455, -136),(457, 457, -136),(465, 470, -136),(208, 233, -135),(264, 266, -135),(274, 275, -135),
(278, 278, -135),(303, 305, -135),(322, 327, -135),(382, 383, -135),(390, 391, -135),(396, 398, -135),(404, 406, -135),(414, 416, -135),(419, 425, -135),(428, 429, -135),
(432, 432, -135),(443, 450, -135),(465, 469, -135),(211, 235, -134),(267, 268, -134),(274, 275, -134),(279, 280, -134),(301, 303, -134),(321, 327, -134),(382, 383, -134),
(390, 390, -134),(396, 396, -134),(404, 406, -134),(411, 428, -134),(431, 432, -134),(444, 450, -134),(464, 469, -134),(215, 216, -133),(219, 220, -133),(223, 223, -133),
(227, 238, -133),(267, 269, -133),(275, 275, -133),(280, 282, -133),(301, 302, -133),(322, 328, -133),(383, 383, -133),(390, 390, -133),(396, 397, -133),(406, 407, -133),
(409, 417, -133),(423, 428, -133),(430, 432, -133),(443, 446, -133),(448, 450, -133),(463, 468, -133),(228, 241, -132),(243, 243, -132),(268, 271, -132),(275, 276, -132),
(281, 284, -132),(299, 301, -132),(321, 323, -132),(327, 328, -132),(383, 383, -132),(395, 396, -132),(407, 410, -132),(413, 415, -132),(423, 430, -132),(443, 446, -132),
(448, 449, -132),(462, 467, -132),(230, 250, -131),(269, 273, -131),(275, 277, -131),(283, 286, -131),(296, 299, -131),(322, 324, -131),(383, 383, -131),(396, 396, -131),
(406, 409, -131),(413, 413, -131),(425, 425, -131),(427, 431, -131),(442, 445, -131),(449, 450, -131),(461, 466, -131),(233, 260, -130),(262, 263, -130),(265, 265, -130),
(267, 267, -130),(269, 277, -130),(285, 288, -130),(292, 292, -130),(294, 298, -130),(322, 325, -130),(383, 384, -130),(392, 397, -130),(399, 399, -130),(406, 407, -130),
(430, 433, -130),(441, 443, -130),(448, 450, -130),(461, 466, -130),(235, 277, -129),(288, 295, -129),(322, 325, -129),(383, 384, -129),(388, 401, -129),(405, 406, -129),
(431, 434, -129),(442, 442, -129),(448, 449, -129),(459, 465, -129),(240, 278, -128),(290, 290, -128),(323, 325, -128),(384, 385, -128),(387, 389, -128),(393, 394, -128),
(401, 406, -128),(432, 435, -128),(448, 449, -128),(459, 465, -128),(243, 243, -127),(245, 278, -127),(323, 325, -127),(377, 377, -127),(379, 380, -127),(383, 389, -127),
(402, 405, -127),(433, 435, -127),(448, 449, -127),(457, 464, -127),(250, 250, -126),(253, 278, -126),(323, 326, -126),(373, 391, -126),(403, 405, -126),(424, 424, -126),
(433, 436, -126),(448, 449, -126),(457, 463, -126),(274, 279, -125),(324, 326, -125),(371, 378, -125),(387, 391, -125),(404, 405, -125),(421, 430, -125),(434, 436, -125),
(447, 449, -125),(455, 462, -125),(275, 280, -124),(325, 327, -124),(369, 376, -124),(405, 406, -124),(420, 423, -124),(428, 431, -124),(434, 436, -124),(447, 448, -124),
(453, 461, -124),(275, 280, -123),(325, 327, -123),(369, 377, -123),(405, 406, -123),(418, 421, -123),(430, 432, -123),(434, 436, -123),(447, 449, -123),(451, 460, -123),
(275, 280, -122),(326, 328, -122),(367, 369, -122),(373, 377, -122),(406, 409, -122),(417, 419, -122),(432, 436, -122),(447, 459, -122),(276, 281, -121),(326, 329, -121),
(367, 368, -121),(372, 375, -121),(405, 412, -121),(414, 417, -121),(432, 437, -121),(446, 458, -121),(277, 281, -120),(325, 330, -120),(365, 367, -120),(370, 372, -120),
(405, 406, -120),(410, 416, -120),(433, 436, -120),(446, 457, -120),(278, 282, -119),(325, 331, -119),(365, 366, -119),(369, 370, -119),(403, 404, -119),(412, 415, -119),
(433, 436, -119),(445, 455, -119),(278, 283, -118),(325, 332, -118),(364, 365, -118),(369, 370, -118),(403, 404, -118),(413, 415, -118),(434, 435, -118),(445, 453, -118),
(279, 284, -117),(326, 333, -117),(363, 364, -117),(368, 369, -117),(401, 405, -117),(414, 415, -117),(434, 435, -117),(444, 451, -117),(279, 285, -116),(326, 333, -116),
(363, 364, -116),(368, 369, -116),(398, 404, -116),(415, 416, -116),(433, 436, -116),(443, 450, -116),(279, 286, -115),(326, 329, -115),(332, 333, -115),(362, 363, -115),
(367, 368, -115),(381, 387, -115),(389, 389, -115),(392, 392, -115),(395, 400, -115),(415, 416, -115),(433, 435, -115),(443, 450, -115),(281, 287, -114),(327, 330, -114),
(362, 362, -114),(367, 370, -114),(377, 381, -114),(383, 383, -114),(385, 386, -114),(388, 388, -114),(390, 395, -114),(397, 397, -114),(415, 416, -114),(433, 435, -114),
(442, 450, -114),(282, 289, -113),(327, 330, -113),(362, 362, -113),(366, 370, -113),(377, 378, -113),(393, 395, -113),(415, 416, -113),(433, 435, -113),(442, 449, -113),
(282, 290, -112),(328, 331, -112),(361, 362, -112),(367, 370, -112),(375, 377, -112),(393, 394, -112),(415, 416, -112),(433, 435, -112),(441, 449, -112),(284, 293, -111),
(329, 332, -111),(362, 362, -111),(369, 370, -111),(374, 376, -111),(393, 394, -111),(415, 416, -111),(432, 435, -111),(442, 442, -111),(446, 448, -111),(284, 295, -110),
(330, 333, -110),(361, 362, -110),(368, 370, -110),(374, 375, -110),(393, 394, -110),(415, 415, -110),(432, 435, -110),(445, 448, -110),(287, 297, -109),(330, 334, -109),
(361, 361, -109),(369, 369, -109),(373, 374, -109),(394, 397, -109),(414, 415, -109),(432, 434, -109),(444, 447, -109),(287, 300, -108),(332, 335, -108),(362, 362, -108),
(369, 370, -108),(373, 374, -108),(396, 398, -108),(413, 415, -108),(431, 434, -108),(444, 448, -108),(290, 302, -107),(332, 336, -107),(361, 361, -107),(369, 370, -107),
(373, 374, -107),(413, 414, -107),(430, 434, -107),(443, 447, -107),(292, 305, -106),(333, 337, -106),(360, 361, -106),(369, 370, -106),(372, 374, -106),(413, 414, -106),
(431, 433, -106),(442, 447, -106),(294, 307, -105),(332, 339, -105),(361, 361, -105),(370, 371, -105),(373, 374, -105),(413, 413, -105),(431, 433, -105),(442, 446, -105),
(298, 309, -104),(329, 341, -104),(361, 362, -104),(370, 374, -104),(413, 414, -104),(427, 427, -104),(431, 433, -104),(441, 446, -104),(300, 311, -103),(327, 342, -103),
(362, 362, -103),(371, 374, -103),(412, 413, -103),(425, 428, -103),(431, 434, -103),(439, 445, -103),(298, 314, -102),(326, 333, -102),(335, 335, -102),(339, 345, -102),
(361, 362, -102),(371, 375, -102),(412, 414, -102),(418, 418, -102),(420, 420, -102),(422, 429, -102),(431, 434, -102),(437, 444, -102),(297, 316, -101),(325, 329, -101),
(340, 346, -101),(361, 362, -101),(372, 375, -101),(413, 414, -101),(416, 425, -101),(427, 429, -101),(431, 435, -101),(437, 444, -101),(295, 306, -100),(308, 319, -100),
(324, 328, -100),(341, 343, -100),(346, 347, -100),(361, 362, -100),(374, 376, -100),(412, 414, -100),(416, 425, -100),(427, 428, -100),(432, 442, -100),(295, 326, -99),
(341, 342, -99),(348, 348, -99),(362, 363, -99),(375, 377, -99),(412, 413, -99),(415, 416, -99),(419, 428, -99),(433, 441, -99),(294, 301, -98),(304, 326, -98),
(341, 342, -98),(347, 349, -98),(362, 362, -98),(413, 414, -98),(416, 426, -98),(433, 440, -98),(294, 299, -97),(304, 325, -97),(341, 341, -97),(349, 349, -97),
(362, 363, -97),(397, 398, -97),(413, 414, -97),(416, 425, -97),(434, 440, -97),(293, 298, -96),(306, 306, -96),(313, 325, -96),(340, 341, -96),(343, 344, -96),
(348, 349, -96),(362, 362, -96),(397, 399, -96),(413, 415, -96),(417, 424, -96),(435, 439, -96),(293, 297, -95),(315, 328, -95),(330, 330, -95),(341, 341, -95),
(343, 348, -95),(356, 358, -95),(362, 363, -95),(389, 390, -95),(392, 393, -95),(398, 398, -95),(414, 415, -95),(419, 419, -95),(421, 421, -95),(423, 424, -95),
(436, 440, -95),(293, 296, -94),(317, 332, -94),(341, 347, -94),(356, 363, -94),(386, 395, -94),(397, 398, -94),(414, 415, -94),(419, 424, -94),(436, 441, -94),
(292, 296, -93),(317, 333, -93),(341, 341, -93),(343, 345, -93),(356, 362, -93),(385, 386, -93),(388, 400, -93),(415, 416, -93),(419, 424, -93),(437, 441, -93),
(292, 296, -92),(317, 332, -92),(341, 341, -92),(344, 345, -92),(357, 360, -92),(383, 386, -92),(388, 399, -92),(416, 417, -92),(421, 421, -92),(437, 442, -92),
(292, 295, -91),(317, 322, -91),(325, 328, -91),(341, 342, -91),(344, 346, -91),(357, 357, -91),(382, 386, -91),(388, 399, -91),(416, 416, -91),(437, 444, -91),
(291, 295, -90),(319, 321, -90),(325, 328, -90),(340, 341, -90),(345, 346, -90),(358, 359, -90),(383, 398, -90),(435, 444, -90),(291, 295, -89),(320, 322, -89),
(324, 327, -89),(341, 341, -89),(345, 347, -89),(358, 359, -89),(387, 398, -89),(419, 419, -89),(434, 445, -89),(290, 296, -88),(320, 327, -88),(329, 330, -88),
(332, 333, -88),(341, 342, -88),(347, 348, -88),(359, 359, -88),(389, 396, -88),(430, 447, -88),(290, 295, -87),(321, 335, -87),(340, 341, -87),(348, 350, -87),
(359, 360, -87),(391, 394, -87),(423, 425, -87),(428, 433, -87),(435, 440, -87),(442, 448, -87),(450, 450, -87),(290, 296, -86),(321, 336, -86),(340, 341, -86),
(350, 352, -86),(360, 362, -86),(423, 429, -86),(435, 439, -86),(443, 450, -86),(291, 294, -85),(322, 337, -85),(340, 340, -85),(351, 353, -85),(361, 362, -85),
(387, 389, -85),(394, 397, -85),(423, 426, -85),(434, 435, -85),(438, 439, -85),(444, 451, -85),(290, 294, -84),(321, 330, -84),(333, 340, -84),(352, 355, -84),
(362, 364, -84),(389, 394, -84),(424, 426, -84),(434, 436, -84),(439, 440, -84),(446, 452, -84),(290, 294, -83),(322, 328, -83),(333, 340, -83),(352, 355, -83),
(364, 366, -83),(390, 390, -83),(424, 426, -83),(428, 428, -83),(434, 437, -83),(439, 439, -83),(446, 453, -83),(291, 294, -82),(322, 326, -82),(333, 340, -82),
(350, 354, -82),(366, 367, -82),(426, 430, -82),(432, 435, -82),(438, 440, -82),(448, 454, -82),(291, 294, -81),(322, 325, -81),(332, 340, -81),(348, 350, -81),
(367, 368, -81),(427, 427, -81),(429, 433, -81),(438, 439, -81),(448, 455, -81),(291, 296, -80),(321, 325, -80),(330, 337, -80),(339, 340, -80),(348, 351, -80),
(368, 369, -80),(438, 439, -80),(448, 456, -80),(292, 297, -79),(321, 325, -79),(329, 335, -79),(339, 340, -79),(347, 355, -79),(369, 371, -79),(400, 403, -79),
(438, 439, -79),(449, 456, -79),(292, 297, -78),(320, 325, -78),(328, 335, -78),(340, 341, -78),(349, 350, -78),(353, 356, -78),(370, 371, -78),(397, 400, -78),
(402, 405, -78),(437, 438, -78),(449, 450, -78),(452, 456, -78),(294, 299, -77),(320, 324, -77),(328, 335, -77),(340, 341, -77),(353, 358, -77),(371, 372, -77),
(383, 388, -77),(396, 399, -77),(403, 404, -77),(437, 438, -77),(452, 457, -77),(294, 299, -76),(314, 314, -76),(316, 323, -76),(328, 335, -76),(341, 342, -76),
(353, 354, -76),(356, 356, -76),(358, 358, -76),(372, 375, -76),(383, 383, -76),(385, 386, -76),(388, 391, -76),(393, 396, -76),(403, 404, -76),(425, 425, -76),
(436, 439, -76),(453, 456, -76),(294, 299, -75),(313, 324, -75),(328, 334, -75),(341, 342, -75),(353, 353, -75),(358, 359, -75),(372, 378, -75),(381, 383, -75),
(390, 395, -75),(403, 403, -75),(423, 427, -75),(435, 444, -75),(453, 457, -75),(293, 298, -74),(312, 317, -74),(319, 324, -74),(327, 334, -74),(342, 344, -74),
(352, 353, -74),(359, 360, -74),(372, 379, -74),(382, 383, -74),(401, 403, -74),(421, 427, -74),(432, 446, -74),(454, 457, -74),(293, 301, -73),(312, 318, -73),
(321, 334, -73),(343, 346, -73),(351, 353, -73),(359, 360, -73),(373, 374, -73),(376, 377, -73),(379, 380, -73),(382, 385, -73),(401, 403, -73),(419, 422, -73),
(426, 428, -73),(430, 435, -73),(437, 437, -73),(444, 448, -73),(454, 458, -73),(294, 303, -72),(305, 305, -72),(310, 314, -72),(316, 318, -72),(322, 330, -72),
(333, 334, -72),(346, 353, -72),(360, 360, -72),(373, 373, -72),(376, 377, -72),(380, 381, -72),(385, 388, -72),(395, 400, -72),(418, 420, -72),(427, 431, -72),
(440, 440, -72),(443, 449, -72),(454, 457, -72),(296, 314, -71),(316, 319, -71),(324, 330, -71),(349, 349, -71),(351, 353, -71),(357, 358, -71),(360, 361, -71),
(373, 374, -71),(376, 377, -71),(381, 382, -71),(387, 389, -71),(394, 399, -71),(417, 418, -71),(426, 429, -71),(437, 450, -71),(454, 457, -71),(298, 314, -70),
(318, 320, -70),(325, 330, -70),(352, 354, -70),(356, 358, -70),(360, 361, -70),(374, 374, -70),(377, 377, -70),(382, 383, -70),(387, 389, -70),(393, 395, -70),
(415, 417, -70),(427, 427, -70),(436, 439, -70),(443, 451, -70),(455, 457, -70),(299, 315, -69),(318, 321, -69),(326, 330, -69),(353, 358, -69),(361, 361, -69),
(373, 374, -69),(377, 378, -69),(383, 383, -69),(388, 393, -69),(415, 416, -69),(434, 436, -69),(442, 445, -69),(447, 447, -69),(449, 452, -69),(454, 457, -69),
(302, 315, -68),(319, 322, -68),(327, 331, -68),(354, 359, -68),(361, 361, -68),(374, 374, -68),(383, 384, -68),(388, 392, -68),(411, 412, -68),(414, 415, -68),
(432, 434, -68),(442, 443, -68),(450, 458, -68),(308, 309, -67),(311, 316, -67),(320, 322, -67),(328, 330, -67),(354, 354, -67),(357, 358, -67),(361, 361, -67),
(373, 374, -67),(377, 377, -67),(383, 384, -67),(389, 390, -67),(409, 414, -67),(431, 433, -67),(441, 443, -67),(452, 458, -67),(311, 316, -66),(320, 323, -66),
(329, 331, -66),(358, 359, -66),(361, 362, -66),(378, 378, -66),(384, 384, -66),(408, 410, -66),(412, 414, -66),(423, 426, -66),(429, 431, -66),(441, 442, -66),
(452, 459, -66),(312, 316, -65),(321, 323, -65),(329, 331, -65),(358, 359, -65),(361, 362, -65),(374, 375, -65),(377, 377, -65),(384, 385, -65),(407, 408, -65),
(412, 413, -65),(422, 426, -65),(428, 431, -65),(441, 442, -65),(456, 459, -65),(312, 317, -64),(321, 324, -64),(330, 333, -64),(359, 360, -64),(362, 363, -64),
(374, 375, -64),(377, 377, -64),(384, 384, -64),(407, 408, -64),(420, 423, -64),(426, 429, -64),(440, 441, -64),(456, 460, -64),(313, 317, -63),(322, 325, -63),
(331, 333, -63),(359, 360, -63),(363, 364, -63),(374, 377, -63),(384, 384, -63),(406, 407, -63),(419, 421, -63),(426, 427, -63),(439, 441, -63),(456, 460, -63),
(314, 317, -62),(322, 326, -62),(331, 334, -62),(360, 361, -62),(364, 366, -62),(375, 376, -62),(383, 384, -62),(406, 406, -62),(419, 420, -62),(439, 440, -62),
(457, 460, -62),(314, 318, -61),(323, 326, -61),(332, 334, -61),(360, 362, -61),(365, 367, -61),(375, 375, -61),(384, 384, -61),(405, 406, -61),(417, 419, -61),
(438, 440, -61),(457, 460, -61),(314, 318, -60),(323, 326, -60),(333, 335, -60),(361, 362, -60),(366, 367, -60),(384, 385, -60),(404, 405, -60),(416, 418, -60),
(437, 440, -60),(458, 461, -60),(314, 318, -59),(324, 328, -59),(334, 336, -59),(362, 367, -59),(384, 384, -59),(404, 405, -59),(416, 417, -59),(436, 438, -59),
(457, 461, -59),(314, 318, -58),(324, 325, -58),(327, 327, -58),(334, 336, -58),(363, 368, -58),(384, 385, -58),(403, 404, -58),(410, 411, -58),(415, 417, -58),
(434, 438, -58),(457, 461, -58),(315, 319, -57),(325, 325, -57),(327, 328, -57),(334, 336, -57),(365, 368, -57),(385, 385, -57),(403, 403, -57),(410, 412, -57),
(415, 416, -57),(431, 437, -57),(457, 461, -57),(315, 319, -56),(324, 326, -56),(328, 329, -56),(335, 337, -56),(365, 370, -56),(384, 385, -56),(402, 403, -56),
(409, 415, -56),(431, 436, -56),(457, 461, -56),(315, 319, -55),(325, 326, -55),(328, 329, -55),(336, 338, -55),(368, 370, -55),(385, 385, -55),(401, 402, -55);

INSERT INTO #R2 (first, last, y)
VALUES (409, 414, -55),(431, 436, -55),(455, 461, -55),(315, 319, -54),(325, 326, -54),(328, 329, -54),(336, 338, -54),(370, 373, -54),(377, 380, -54),(385, 386, -54),
(400, 402, -54),(408, 409, -54),(430, 434, -54),(455, 462, -54),(316, 319, -53),(326, 326, -53),(329, 330, -53),(337, 338, -53),(371, 381, -53),(385, 386, -53),
(399, 400, -53),(407, 408, -53),(429, 434, -53),(454, 461, -53),(315, 320, -52),(326, 327, -52),(330, 331, -52),(336, 339, -52),(373, 382, -52),(386, 387, -52),
(399, 400, -52),(407, 408, -52),(427, 432, -52),(454, 460, -52),(315, 320, -51),(327, 327, -51),(330, 330, -51),(337, 339, -51),(375, 384, -51),(387, 388, -51),
(397, 399, -51),(405, 407, -51),(425, 431, -51),(454, 459, -51),(316, 319, -50),(326, 327, -50),(330, 331, -50),(338, 339, -50),(376, 385, -50),(387, 390, -50),
(394, 398, -50),(405, 406, -50),(422, 429, -50),(453, 457, -50),(316, 319, -49),(327, 331, -49),(338, 340, -49),(379, 380, -49),(383, 385, -49),(390, 396, -49),
(402, 405, -49),(417, 426, -49),(453, 457, -49),(316, 320, -48),(327, 330, -48),(339, 341, -48),(385, 386, -48),(391, 393, -48),(401, 404, -48),(417, 425, -48),
(453, 457, -48),(316, 320, -47),(328, 328, -47),(339, 342, -47),(398, 403, -47),(416, 423, -47),(452, 456, -47),(316, 319, -46),(340, 342, -46),(398, 406, -46),
(409, 410, -46),(412, 412, -46),(415, 423, -46),(452, 456, -46),(316, 319, -45),(340, 343, -45),(400, 421, -45),(452, 456, -45),(316, 320, -44),(341, 345, -44),
(404, 417, -44),(451, 456, -44),(317, 320, -43),(342, 346, -43),(411, 411, -43),(413, 413, -43),(451, 455, -43),(316, 320, -42),(342, 348, -42),(352, 353, -42),
(450, 454, -42),(317, 320, -41),(343, 345, -41),(347, 348, -41),(351, 354, -41),(450, 454, -41),(317, 320, -40),(343, 345, -40),(348, 355, -40),(449, 453, -40),
(317, 320, -39),(343, 346, -39),(351, 351, -39),(354, 356, -39),(445, 445, -39),(449, 453, -39),(317, 320, -38),(344, 347, -38),(355, 356, -38),(445, 452, -38),
(317, 320, -37),(345, 347, -37),(356, 357, -37),(443, 451, -37),(318, 321, -36),(345, 348, -36),(357, 358, -36),(442, 451, -36),(317, 321, -35),(346, 348, -35),
(358, 359, -35),(442, 451, -35),(318, 321, -34),(347, 349, -34),(359, 361, -34),(441, 449, -34),(318, 321, -33),(347, 349, -33),(360, 361, -33),(368, 368, -33),
(440, 449, -33),(318, 322, -32),(348, 350, -32),(361, 363, -32),(367, 369, -32),(439, 448, -32),(318, 322, -31),(349, 351, -31),(362, 364, -31),(366, 371, -31),
(430, 431, -31),(438, 447, -31),(318, 322, -30),(349, 352, -30),(364, 373, -30),(429, 431, -30),(437, 446, -30),(319, 323, -29),(332, 334, -29),(350, 353, -29),
(365, 368, -29),(372, 374, -29),(429, 432, -29),(435, 442, -29),(445, 445, -29),(319, 324, -28),(332, 335, -28),(350, 354, -28),(374, 376, -28),(383, 386, -28),
(427, 441, -28),(319, 324, -27),(332, 337, -27),(351, 355, -27),(375, 377, -27),(379, 379, -27),(383, 388, -27),(426, 427, -27),(429, 429, -27),(432, 440, -27),
(320, 325, -26),(333, 337, -26),(352, 356, -26),(377, 390, -26),(416, 418, -26),(424, 425, -26),(432, 439, -26),(320, 325, -25),(333, 337, -25),(353, 357, -25),
(380, 385, -25),(390, 395, -25),(415, 418, -25),(423, 424, -25),(431, 438, -25),(321, 326, -24),(334, 339, -24),(354, 359, -24),(383, 383, -24),(393, 393, -24),
(395, 400, -24),(402, 403, -24),(405, 407, -24),(413, 418, -24),(422, 423, -24),(430, 437, -24),(322, 328, -23),(335, 339, -23),(355, 360, -23),(398, 405, -23),
(409, 409, -23),(411, 414, -23),(416, 418, -23),(420, 421, -23),(429, 436, -23),(322, 328, -22),(335, 340, -22),(356, 362, -22),(401, 411, -22),(416, 420, -22),
(428, 435, -22),(323, 330, -21),(336, 341, -21),(356, 358, -21),(360, 364, -21),(401, 408, -21),(416, 419, -21),(427, 433, -21),(323, 331, -20),(337, 342, -20),
(358, 360, -20),(362, 365, -20),(403, 404, -20),(426, 433, -20),(325, 343, -19),(360, 361, -19),(364, 367, -19),(424, 431, -19),(326, 344, -18),(361, 363, -18),
(365, 367, -18),(423, 430, -18),(327, 345, -17),(363, 366, -17),(422, 430, -17),(330, 346, -16),(365, 365, -16),(421, 428, -16),(333, 333, -15),(336, 336, -15),
(339, 348, -15),(420, 427, -15),(341, 348, -14),(418, 426, -14),(342, 350, -13),(417, 425, -13),(344, 352, -12),(415, 423, -12),(344, 353, -11),(414, 421, -11),
(346, 356, -10),(412, 420, -10),(348, 359, -9),(410, 419, -9),(349, 368, -8),(370, 370, -8),(409, 418, -8),(351, 375, -7),(377, 377, -7),(406, 417, -7),
(352, 382, -6),(404, 415, -6),(356, 385, -5),(387, 388, -5),(397, 398, -5),(400, 414, -5),(359, 359, -4),(362, 413, -4),(369, 369, -3),(371, 410, -3),
(375, 375, -2),(377, 410, -2),(384, 405, -1),(407, 407, -1),(388, 388, 0),(392, 402, 0),(405, 405, 0);

----

DECLARE @p VARCHAR(MAX);

WITH CTE
AS
(
	SELECT 0 AS x
	UNION ALL
	SELECT x + 1
	FROM CTE
	WHERE x < 700
)
SELECT @p = (
		SELECT ',' AS "*",
			CAST(c.x AS CHAR(5)) AS "data()",
			CAST(r1.y AS CHAR(5)) AS "data()"
		FROM #R2 r1
		INNER JOIN CTE c
			ON c.x BETWEEN r1.first AND r1.last
		FOR XML PATH('')
	)
OPTION (MAXRECURSION 0);

DECLARE @card geometry = geometry::STMPointFromText('MULTIPOINT(' + CAST(SUBSTRING(@p, 2, 214783647) AS VARCHAR(MAX)) + ')', 0);

SELECT @card;

Você deve conseguir ver alguma coisa assim:

You´ll see some like:

T-SQL Tuesday #025 – Truques


Este mês o Sr. Allen White (Blog | Twitter)  pediu para as pessoas dizerem quais truques elas utilizam para deixar o trabalho mais fácil…

Nós temos muitos códigos em powershell que ajudam a melhorar o dia, mas, powershell,,, aahh,,, se você usar o google, poderá encontrar muita gente escrevendo bons códigos que podem ajudá-lo.

Eu escrevi uma coisa legal, mas em T-SQL, para criar bases em mirror,,, Sim, eu sei, você pode encontrar um monte de blogs falando sobre como criar esse tipo de ambiente,,, mas eu vou fazer isso usando SQLCMD dentro do Management Studio,,, por quê? só pela diversão…

Eu vou pular a parte da criação dos end-poins porque você já sabe…

A parte legal está logo depois da versão em inglês,,,

Hi, i try translate all the text above, sorry if have some mistakes,,,

This month Mr. Allen White (Blog | Twitter) ask people to say what tricks we use to make our job easier…

We have a lot of code in powershell helping to improve the day, but, powershell,,, aahh,,, if you use the google will find a lot of people writing good scripts to help you.

I going to write some nice,, but in T-SQL, just to create a database mirror,,,, Yes, I know, you can find a lot of blogs talking about who to create a database mirror,,, but I will do this using the SQLCMD inside the Management Studio,, why? just for fun…

I´ll skip the creation of end-points because you already know…

The good part is here:


/* Change the principal server name and instance */
:SETVAR principal_server "SERVERNAME\INSTANCE1"
/* Change the mirror server name and instance */
:SETVAR mirror_server "SERVERNAME\INSTANCE2"
/* in this case I use the same server, but you can add one more setvar and add the other server */
:SETVAR server "SERVERNAME"
/* Database name to mirror */
:SETVAR db "DB_NAME"

:connect $(principal_server)

alter database $(db) set recovery full

backup database $(db)
to disk = 'D:\DB01\inst01\$(db).bak'
with compression, stats = 5

backup log $(db)
to disk = 'D:\DB01\inst01\$(db).trn'
with compression, stats = 5

go
:connect $(mirror_server)

restore database $(db)
from disk = 'D:\DB01\inst01\$(db).bak'
with file = 1,
move '$(db)' to 'D:\DB01\local\$(db).mdf',
move '$(db)_log' to 'D:\DB01\local\$(db).ldf',
norecovery, nounload, stats = 5

restore database $(db)
from disk = 'D:\DB01\inst01\$(db).trn'
with norecovery, nounload, stats = 5

alter database $(db)
set partner = 'TCP://$(server):5022'
go

:connect $(principal_server)

/* In this part you can change the setvar if was created other one */
alter database $(db)
set partner = 'TCP://$(server):5023'

 

The Log scan in database model is not valid


Um pouco da história antes….

Dia 08/12/2011 choveu muito aqui em sampa,,, tivemos problemas com a elétrica aqui no prédio, ocasionando diversas quedas de energia,,,

Tenho instalado no desktop um SQL Server 2008 R2 Express, onde tenho algumas bases para testes,, até ai nenhuma novidade,,,

Quando cheguei no dia seguinte (09/12/2011) percebi que um sistema que uso para testar algumas bases não estava funcionando,,, a mensagem era simples: “Não consigo acessar o SQL”

Tentei iniciar o serviço do SQL e, claro, não consegui,,, Acessei os eventos do sistema e achei a seguinte mensagem:

event model

Interessante,,, o transaction log do model foi corrompido… isso é legal…

Iniciei o SQL em modo de segurança e rodei um DBCC CHECKDB, não fez diferença…

Como a base Model não é uma das bases mais vitais do SQL e eu não tenho backup dela,,, fui no diretório de Templates e copiei a base de lá para o diretório onde estava a base de “produção”. Iniciei o SQL e ele carregou sem problemas….

templates

Lembrando que, não é porque existem outras bases de sistema por aqui que você pode sobre-escrever a Master ou a MSDB…

Aí vem uma pergunta,,, por que o SQL não subiu com a base em suspect ou offiline? ou qualquer outro aviso? simples… a base Model, por mais simples que seja serve como base para criar o TempDB,,, sem ela,, o SQL não consegue criar o mínimo para o TempDB… eu consegui iniciar o SQL em modo de segurança porque usei a traceflag 3609 onde ele não recriou o tempdb…

The Current SKU is invalid ?!?! WhataHELL ?!?!


Estou montando um ambiente para fazer uns testes de migração de versão de cluster e me deparei com um erro no mínimo grotesco,,,

Antes de falar do erro, meu ambiente de testes é formado por:

  • 1 Windows Server 2008 Std sem Hyper-V (para AD)
  • 2 Windows Server 2008 Ent sem Hyper-V (para cluster)
  • E duas instâncias do SQL Server 2008 Enterprise. (Não são R2)
  • Nenhum desses ambientes tem SP ou qualquer atualização

1º erro grotesco, alguém já tentou fazer um cluster com o Windows Server 2008 sem Hyper-V ? se sim, já se deparou com um erro informando que as versões do Windows são incompatíveis com o SKU? tem um KB que disponibiliza um path para resolver esse problema…

2º erro grotesco, depois de instalar as 2 instâncias, cada qual em sua maquina, fui fazer o processo de adicionar o segundo nó nesse cluster. Depois de confirmar o serial recebi a seguinte mensagem de erro:

sku

Existe esse KB indicando que esse erro é conhecido e que precisa ser instalado o CU1 do SQL Server 2008.

Mas tem uma forma mais fácil de resolver o problema,,,

Na tela onde você escolhe a licença, coloque a opção de versão Trial, clique em avançar, você vai para a tela de aceitar a licença, clique em voltar e selecione a opção que contém a chave de ativação.

Pronto, sua instalação vai prosseguir sem problemas…

Quais planos de execução estão na memória?


Em sua maioria, a memória utilizada pelo SQL Server é utilizada para armazenar dados (buffer) e planos de execução (cache de procedure). Nesse post vou mostrar quanta memória está alocada para cache de procedures

O SQL Server armazena o cache usando 8kb por página de dados. Usando a dynamic view sys.dm_os_memory_cache_counters podemos ver um resumo do que está alocado:

SELECT TOP 6
LEFT([name], 20) as [NOME],
LEFT(]TYPE], 20) as [TIPO],
[single_pages_kb] + [multi_pages_kb] as [cache_kb],
[entries_count]
FROM sys.dm_os_memory_cache_counters
order by single_pages_kb + multi_pages_kb DESC

Vou focar nos 3 principais resultados dessa query:

  • CACHESTORE_OBJCP – Esse são planos compilados para stored procedures, triggers e functions
  • CACHESTORE_SQLCP – São os planos que não fazem parte de procedures, functions e triggers, inclui basicamente SQL dinâmico.
  • CACHESTORE_PHDR – Esse é responsável por verificar a sintaxe de views, constrains, também resolve o nome de tabelas e colunas

Você pode monitorar o numero de páginas no cache usando o Performance Monitor usando SQLServer:Plan Cache que armazena os contadores de Páginas de Cache. SQL Plans (CACHESTORE_SQLCP), Object Plans (CACHESTORE_OBJCP) e Bound Trees (CACHESTORE_PHDR).

Nos podemos ver individualmente as entradas no cache usando a dynamic view sys.dm_exec_cached_plans

SELECT usercounts, cacheobjtype, objtype, plan_handle
FROM sys.dm_exec_cached_plans

A query lista os planos de execução mais utilizados. Ela inclui os planos para stored procedures, adhoc ou SQL dinâmico, triggers, views. Se você quiser ver o SQL associado ao plano (que no final das contas é o que realmente queremos) será necessário usar o sys.dm_exec_sql_text:

SELECT TOP 100
objtype,
p.size_in_bytes
LEFT([sql].[text], 150) as [SQL]
from sys.dm_exec_cached_plans p
outer apply sys.dm_exec_sql_text (p.plan_handle) sql
order by usercount desc

SQLPASS – Keynote D2


08h10 – Hoje é o kilt day,,,,

08h18 – Hoje tem um monte de agradecimento para as pessoas que ajudam o evento a ser realizado

08h25 – O Pessoal apresentou um vídeo sobre as qualidades mais interessante para as pessoas sobre o sql,,, muitas das pessoas são de instituições bancárias,,,,

08h30 – O VP está falando sobre as novidades do SQL Server 2012, começou falando sobre as novidades de alta disponibilidade, que por sinal realmente é bem interessante

Agora o VP da MSC está falando sobre a utilização deles do SQL, comentando a necessidades deles de nunca poder parar de acessar os dados.

08h40 – O pessoal esta mostrando como configurar o modo Always-On do SQL 2012,,, isso é simplesmente muito bom,,,,

08h53 – Até que enfim alguém está fazendo exemplos sem usar Excel,,, e pra ajudar a mina vira e manda uma: “Da pra fazer pelo GUI, mas sou da velha guarda, então olhem o código aqui,,,”

09h00 – Agora vamos ver o appliance com SQL,,, um hardware tunado para rodar banco,,,, só banco,,,, e mais nada além de banco,,,, isso é um sonho? SQL Server Parallel Data warehouse,,,, agora não é só HP,,, a DELL também tem hardware pra isso,,, é uma pena que isso, se um dia chegar ao Brasil, vai ser muito caro,,,,

09h16 – Anuncio do driver de ODBC para linux,,,, já que tem um monte de gente desenvolvendo para linux, pelo menos acessem uma base decente sem usar a droga do jdbc,,,

09h30 – trouxemos a chuva para Seattle,,, afinal,,, muito SQL Azure  da nisso,,,,

09h40 – O pessoal anunciou que o SQL Azure vai aceitar bases até 150gb,,, e em qualquer collation,,, vamos ver se ele começa a fazer alguma sombra no Brasil,,,

Um bom programa para quebra galho


Estava revirando uns arquivos no meu HD externo e achei um programa muito legal para

conexão ODBC.

Antes de falar do programa,,, a historinha…

Conheci uma vez uma empresa que o pessoal não deixava acessar o servidor com SQL por TS nem SSMS,,,

Perguntei pra eles como eu iria ajudar a identificar os problemas se não podia fazer muita coisa… me explicaram que era política da empresa, eu poderia acessar de qualquer outra forma, mas não poderia conectar meu note da rede nem instalar qualquer aplicativo na estação…

Foi com essa necessidade que conheci o ODBC QueryTool,,, ele é um programinha bem legal… de graça e funciona sem precisar instalar nada…

1_app

Você pode usar uma conexão existente de ODBC ou criar uma na hora…

2_connect

Como um quebra-galho para esse tipo de situação,,, acho que ele server para dar uma ajuda…

3_query

Você pode usar ele também para testar as conexões das estações cliente, com as restrições de usuário, restrições do SQL,,,

configurando o ODBC com as devidas informações, eu mostrei para um cliente como a aplicação iria se comportar com o fail-over das bases mirror.

Você pode baixar no site do SourceForge, ou no meu Skydrive, esse é um dos programas que vale a pena ter no pendrive.

T-SQL Tuesday #23 – Joins


Para o pessoal não ficar corrido entre escrever uns posts meia boca e se preocupar com os preparativos para o SQLPASS, o pessoal resolveu dar uma adiantada no T-SQL Tuesday desse mês,,,

Este mês ele é hospedado por Stuart Ainsworth (Blog | Twitter) e fala sobre joins..

Quer saber mais sobre Joins?

Vamos lá,,,

meu exemplo é bem simples,,, mostra os waits que estão acontecendo no SQL…

select
w.session_id,
w.wait_duration_ms,
w.wait_type,
w.blocking_session_id,
w.resource_description,
s.program_name,
t.text,
t.dbid,
s.cpu_time,
s.memory_usage
from sys.dm_os_waiting_tasks w
inner join sys.dm_exec_sessions s on
w.session_id = s.session_id
inner join sys.dm_exec_requests r on
s.session_id = r.session_id
outer apply sys.dm_exec_sql_text (r.sql_handle) t
where s.is_user_process = 1

Ele vai tentar associar a requisição ao wait.

Malditos SQL Aliases


Estava em um cliente montando uma estratégia para migração de 2 instâncias de SQL 2000 para uma única instância de SQL 2005… até aí tranquilo,,, certo?

Listamos os linked servers, jobs, usuários e senhas, bases, collation,,, etc,,, tudo quase pronto pra migração….

Ai, lembrei de um detalhe… algumas bases estavam em uma instância default do SQL,,, e vamos migrar todas para um SQL em uma instância,,, ai vem o problema:

  1. Aplicações antigas
  2. Algumas não possuem código fonte
  3. Outras precisam de projeto para alterar o fonte
  4. Muitas estações com o aplicativo
  5. etc..

Legal,,, iai? Só criar o SQL Aliases (Iniciar>Executar>Cliconfg)? boa,,, pena que tem que criar em maquina a maquina,,, Redirecionar DNS? até funcionaria se o outro SQL não tivesse instância. Poderíamos alterar o DNS e “adicionar o servidor” com o sp_addserver (sp_addserver ‘nome_do_host’, local, duplicate_ok) o problema é que a instância tem que escutar a 1433, até ai nenhum grande problema, adiciona como porta secundária.

como fazer o deploy de aliases rápido? Policy… cria uma chave de registro e adiciona o aliases…

  • “HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\MSSQLServer\Client\ConnectTo”
  • Nome:”Nome_do_alias”
  • Tipo: Sequencia
  • Valor: “DBMSSOCN,ServidorX\Instancia,1433”

Outra forma, utilizar um “proxy” de SQL,,, tipo F5, Green SQL,,,

TableDiff


Imagine a situação do post Corrompendo um Banco SQLmas na vida real,,,

Você chega um belo dia na empresa e, lê nos seus emails que, o SQL apresentou falha na estrutura de dados e algumas páginas de dados podem ter sido corrompidas,,,

Como um bom DBA, você corre para ver se o backup da noite foi feito, se os backups de transaction log também estão sendo feitos e descobre que sim,,,, todos os arquivos necessários para restaurar o banco estão lá,,,

Legal,,, mas,,, e agora? dependendo da utilização do banco você pode restaurar o backup da madrugada, os de log até o horário do problema e dali pra frente o que der pra fazer…

Em outros casos,,, você não pode se dar ao luxo de perder informação,,,,

Uma das formas seria executar o restore do banco em outro lugar, ou na mesma instância mas com outro nome, executar o checkdb e remover a página com problema e trazer a diferença dos dados,,, até aqui nada tão complicado,,, tirando o fato de se a tabela for muito grande, ou muito complexa e a query para mostrar essa diferença for muito complicado…

Para ajudar a resolver esse problema, o SQL possui uma ferramenta bem interessante chamada TableDiff.

O conceito dela é bem simples: Instância de origem, base de origem, tabela de origem, Instância de destino, base de destino, tabela de destino e o que você quer fazer…

Ex:

"C:\Program Files\Microsoft SQL Server\90\COM\tablediff.exe" -sourceserver MyServer1
                                                             -sourcedatabase MyDatabase1
                                                             -sourcetable MyTable1
                                                             -destinationserver MyServer1
                                                             -destinationdatabase MyDatabase1
                                                             -destinationtable MyTable2
                                                             -et DiffsTable

 

Nesse outro exemplo ele gera um arquivo com INSER/UPDATE/DELETE

"C:\Program Files\Microsoft SQL Server\90\COM\tablediff.exe" -sourceserver MyServer1
                                                             -sourcedatabase MyDatabase1
                                                             -sourcetable MyTable1
                                                             -destinationserver MyServer1
                                                             -destinationdatabase MyDatabase1
                                                             -destinationtable MyTable2
                                                             -et DiffsTable
                                                             -f d:\MyTable1_MyTable2_diff.sql

 

Simples certo? em teoria não é muito complicado…

Da pra deixar mais fácil? sim,,, com certeza…

O Sr. Mladen Prajdic (Blog | Twitter) desenvolveu uma interface bem interessante para ajudar na utilização do executável…

O link para download pode ser encontrado no post aqui, ou diretamente aqui.

O aplicativo é bem simples de usar, o ponto de atenção é que você precisa indicar onde está o executável do TableDiff.exe.

tablediffgui

Ele é bem auto-explicativo, pequeno e o principal,,, é de graça !!!

Vale gastar uns minutos para aprender a usar ele, vai que em um dia de emergência você precisa de uma ajuda rápida para solucionar um problema, ou ver a diferenças nas tabelas do seu logshipping….

Catalogar objetos


Esse código faz parte daquele tipo de código para gerar documentação.

Não faz nada muito complexo, apenas mostra o objeto, quem é dono, que tipo e quando foi criado.

SELECT   [NAME]          AS OBJECT_NAME,
           USER_NAME(UID)  AS OWNER,
           TYPE = CASE
                    WHEN XTYPE = 'u' THEN 'table'
                    WHEN XTYPE = 'c' THEN 'check constraint'
                    WHEN XTYPE = 'd' THEN 'default constraint'
                    WHEN XTYPE = 'f' THEN 'foreign key constraint'
                    WHEN XTYPE = 'fn' THEN 'scalar function'
                    WHEN XTYPE = 'if' THEN 'inline table function'
                    WHEN XTYPE = 'p' THEN 'stored procedure'
                    WHEN XTYPE = 'pk' THEN 'primary key'
                    WHEN XTYPE = 'tf' THEN 'table function'
                    WHEN XTYPE = 'tr' THEN 'trigger'
                    WHEN XTYPE = 'uq' THEN 'unique constraint'
                    WHEN XTYPE = 'v' THEN 'view'
                  END,
           CRDATE          AS CREATION_DATE
  FROM     SYSOBJECTS
  WHERE    XTYPE IN ('u','c','d','f',
                     'fn','if','p','pk',
                     'tf','tr','u','uq',
                     'v')
ORDER BY XTYPE

 

Estou fazendo index scan sim, idaí?


Complementando o Post Procurando por conversão implícita sobre a apresentação do Marcos Freccia (Blog | Twitter)  “10 coisas que todo desenvolvedor deveria saber sobre SQL Server

Um dos grandes problemas dessa conversão é o SQL utilizar index scan ao invés de index seek.

Esse código mostra consultas que estão executado Index Scan por motivos de Conversões Implícitas.

with XMLNAMESPACES
('http://schemas.microsoft.com/sqlserver/2004/07/showplan' as sql)
select
total_worker_time/execution_count AS AvgCPU
, total_elapsed_time/execution_count AS AvgDuration
, (total_logical_reads+total_physical_reads)/execution_count AS AvgReads
, execution_count
, SUBSTRING(st.TEXT, (qs.statement_start_offset/2)+1 , ((CASE
qs.statement_end_offset WHEN -1 THEN datalength(st.TEXT) ELSE
qs.statement_end_offset END - qs.statement_start_offset)/2) + 1) AS txt
, qs.max_elapsed_time
, db_name(qp.dbid) as database_name
, quotename(object_schema_name(qp.objectid, qp.dbid)) + N'.' +
quotename(object_name(qp.objectid, qp.dbid)) as obj_name
, qp.query_plan.value(
N'(/sql:ShowPlanXML/sql:BatchSequence/sql:Batch/sql:Statements/sql:StmtSimple[@StatementType = "SELECT"]/sql:QueryPlan/sql:RelOp/descendant::*/sql:ScalarOperator[contains(@ScalarString, "CONVERT_IMPLICIT")])[1]/@ScalarString', 'nvarchar(4000)' ) as scalar_string
, qp.query_plan
from sys.dm_exec_query_stats as qs
cross apply sys.dm_exec_query_plan(qs.plan_handle) as qp
cross apply sys.dm_exec_sql_text(qs.sql_handle) st
where qp.query_plan.exist(
N'/sql:ShowPlanXML/sql:BatchSequence/sql:Batch/sql:Statements/sql:StmtSimple[@StatementType = "SELECT"]/sql:QueryPlan/sql:RelOp/sql:IndexScan/descendant::*/sql:ScalarOperator[contains(@ScalarString, "CONVERT_IMPLICIT")]' ) = 1;

Gerador de Senhas


Esse é um código antigo que estava escondido no HD.

Bem simples e usual.

/*
Versao: 1.0
Data: 20100302
Por: Ricardo Leka
Site: http://leka.com.br
email: ricardo@leka.com.br
twitter: @bigleka
*/
/*
Gerador de Senhas
Pode gerar senhas com quantidades minima e maxima de caracteres
com numeros ou complexidade
*/
DECLARE
  @complex tinyint
  , @minlen tinyint
  , @maxlen tinyint  

SET @minlen = 4 --tamanho minimo da senha
SET @maxlen = 8 --tamanho maximo da senha
SET @complex = 4
-- 1 todas as letras minusculas
-- 2 inclui letras maiusculas
-- 3 inclui numeos
-- 4 inclui caracteres especiais

DECLARE
  @password varchar(12)
  , @len tinyint
  , @type  tinyint
  , @type2 tinyint

SET @len = 0
SET @password = ''
WHILE @len NOT BETWEEN @minlen and @maxlen
  BEGIN
    SET @len = ROUND(1 + (RAND(CHECKSUM(NEWID())) * @maxlen), 0) + 1
  END
WHILE @len > 0
  BEGIN
    DECLARE @newchar CHAR(1)
    SET @type = ROUND(1 + (RAND(CHECKSUM(NEWID())) * (@complex - 1)), 0)
    IF @type = 1
      SET @newchar = CHAR(ROUND(97 + (RAND(CHECKSUM(NEWID())) * 25), 0))
    IF @type = 2
      SET @newchar = CHAR(ROUND(65 + (RAND(CHECKSUM(NEWID())) * 25), 0))
    IF @type = 3
      SET @newchar = CHAR(ROUND(48 + (RAND(CHECKSUM(NEWID())) * 9), 0))
    IF @type = 4
      BEGIN
        SET @type2 = ROUND(1 + (RAND(CHECKSUM(NEWID())) * 3), 0)
        IF @type2 = 1
          SET @newchar = CHAR(ROUND(33 + (RAND(CHECKSUM(NEWID())) * 14), 0))
        IF @type2 = 2
          SET @newchar = CHAR(ROUND(58 + (RAND(CHECKSUM(NEWID())) * 6), 0))
        IF @type2 = 3
          SET @newchar = CHAR(ROUND(91 + (RAND(CHECKSUM(NEWID())) * 5), 0))
        IF @type2 = 4
          SET @newchar = CHAR(ROUND(123 + (RAND(CHECKSUM(NEWID())) * 3), 0))
      END
-- remove caracteres que podem ser confundidos com outros
    IF @newchar NOT IN ('b', 'l', 'o', 's', 'I', 'O', 'S', '0', '1', '!', '''', '.', ',', '/', '`', '\', '|')
      BEGIN
        SET @password = @password + @newchar
        SET @len = @len - 1
      END
  END
SELECT @password as Senha

[Vídeo] Instant File Initialization


Já vou logo avisando:

  • Não assista esse vídeo depois das 22h,,, não me responsabilizo por pesadelos,,,
  • Não assista perto dos seus filhos,,, é mais feio que o bicho papão,,,
  • Não assista no trabalho,,, seus colegas já sofrem tendo que trabalhar com você,,,,
  • Meu primeiro vídeo,,, Gravei o vídeo as 4am,,, estava com muito sono,,,

Se, depois de tudo isso, clicar em Play não me responsabilizo por absolutamente nada,,,

Instant file initialization from Ricardo Leka on Vimeo.

1807


Atualmente meu notebook (também conhecido como desktop porque a bateria já era) não tem muita capacidade de suportar alguns testes,,, (Acer Aspire 5050 – AMD Turion 1 core, 1.9GB RAM, 35GB HD),,,

Então tentei fazer uma coisa interessante,,,, criar um banco e apontar os arquivos para meu storage (QNAP TS-110),,,

Tenho 2 instâncias de SQL instaladas nesse note, 1 SQL Server 2008 R2 e 1 SQL Server 2005.

Claro que no 2008 R2 funcionou e no 2005 não…

yep2008

nop

Ai lembrei que para o SQL 2005 (e para o 2008 sem ser R2) criar uma base em local UNC eu precisava habilitar a trace flag 1807. Feito isso conseguir criar a base sem problema.

yep

Achei interessante relembrar isso, pois vai que uma hora qualquer alguém precisa, ou para fazer um LAB ou por falta de espaço (meu caso) você sempre tem uma alternativa… e muita gente nem lembra dessa possibilidade…

T-SQL Tuesday #21 – Depois arrumo esse código,,,


Dessa vez o anfitrião do T-SQL Tuesday é o próprio idealizador Adam Machanic (Blog | Twitter).

E de uma forma diferente, não é na Terça-feira,,, por quê?

Porque não importa, desde que funcione pode ser zuado mesmo,,, o tópico desse mês é sobre “mostrar seu código lixo para o mundo”,,,

Todo mundo já escreveu um código uma vez ou outra,,,, todo o DBA tem aquele conjunto de scripts que o ajudam a identificar alguns problemas, fazer um tunning, arrumar alguma coisa,,, E com certeza todo mundo tem aquele código que hoje, pega para olha e começa a dar risada de como é que teve coragem de fazer uma coisa como aquela…

Meu exemplo é bem simples, O código é horrível, demora demais mas, funciona,,,

Ele troca os dados de posição de uma coluna específica.

WITH cteTableTel AS (
    SELECT
        ROW_NUMBER() OVER (ORDER BY NEWID()) AS n,
        SOBRENOME
    FROM CLIENTES
    )
UPDATE CLIENTES
   SET ENDERECO = (
       SELECT ENDERECO
       FROM cteTableTel
       WHERE cteTableTel.n = CLIENTES.ID)
Esse código funciona, não é nada bonito, não é performático, mas para a necessidade de uma base de treino com dados reais ele ajuda bastante,,,
Se você percebeu ele tem um problema,,, sabe qual é?
Como você garante que todas as linhas da tabela de clientes realmente estão em uma sequencia? Você pode ter apagado algum registro uma hora ou outra,,, Logo, haverá cliente que o endereço não vai ser atualizado,,
Já sei, você nem reparou nesse problema,,, você deve estar pensando: “por que ele esta fazendo um update na tabela de clientes se ele está usando uma CTE?”, ou também, “Legal, ele está fazendo isso em uma tabela que tem algum tipo de ID e quando tem aquelas tabelas que não da pra usar nada de referencia?”
Como eu disse, ele não é performático, e eu nem tinha me atentado nesses detalhes na época,,,  Houveram duas situações que me refizeram rever esse código: o primeiro caso dos usuários que não tinham os dados alteradores e o último… ai com muita vontade resolvi reescrever,,,
E ele ficou mais ou menos assim:
;WITH cte AS (
    SELECT
        ROW_NUMBER() OVER (ORDER BY NEWID()) AS n1,
        ROW_NUMBER() OVER (order by SOBRENOME) AS n2,
        SOBRENOME
    FROM CLIENTES
    )
UPDATE c1
   SET SOBRENOME = c2.SOBRENOME
   from cte as c1
   inner join cte as c2
   on c1.n1 = c2.n2

Dessa vez não tem problema com o usuário sem o dado alterado, performance melhorada em quase 90% e pouco importa se a tabela em algum registro para referencia,,,

Eu comparei a execução dos 2 códigos em uma tabela com um pouco mais de  3 milhões de linhas e o segundo código demorou quase 4 horas para finalizar,,, já o primeiro código eu parei a execução dele depois de 2 SEMANAS executando.

Tenho códigos piores no meu repositório? claro que sim. Esse é apenas um exemplo de um dos piores que já fiz…

Qual é o seu? tem coragem mostrar?

Procurando por conversão implícita


Assistindo ontem a apresentação do Marcos Freccia (Blog | Twitter) sobre “10 coisas que todo desenvolvedor deveria saber sobre SQL Server” alguém perguntou como ver as conversões implícitas que estão sendo executadas no SQL,,, ou alguma coisa assim,,,

Então, segue um script rapidão que mostra as conversões,,, o chato desse script é que ele tem que ser executado por banco,,,

Vou tentar montar um outro que traga a informação de todos os bancos,,,

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITTED 

DECLARE @dbname SYSNAME
SET @dbname = QUOTENAME(DB_NAME()); 

WITH XMLNAMESPACES
   (DEFAULT 'http://schemas.microsoft.com/sqlserver/2004/07/showplan')
SELECT
   stmt.value('(@StatementText)[1]', 'varchar(max)'),
   t.value('(ScalarOperator/Identifier/ColumnReference/@Schema)[1]', 'varchar(128)'),
   t.value('(ScalarOperator/Identifier/ColumnReference/@Table)[1]', 'varchar(128)'),
   t.value('(ScalarOperator/Identifier/ColumnReference/@Column)[1]', 'varchar(128)'),
   ic.DATA_TYPE AS ConvertFrom,
   ic.CHARACTER_MAXIMUM_LENGTH AS ConvertFromLength,
   t.value('(@DataType)[1]', 'varchar(128)') AS ConvertTo,
   t.value('(@Length)[1]', 'int') AS ConvertToLength,
   query_plan
FROM sys.dm_exec_cached_plans AS cp
CROSS APPLY sys.dm_exec_query_plan(plan_handle) AS qp
CROSS APPLY query_plan.nodes('/ShowPlanXML/BatchSequence/Batch/Statements/StmtSimple') AS batch(stmt)
CROSS APPLY stmt.nodes('.//Convert[@Implicit="1"]') AS n(t)
JOIN INFORMATION_SCHEMA.COLUMNS AS ic
   ON QUOTENAME(ic.TABLE_SCHEMA) = t.value('(ScalarOperator/Identifier/ColumnReference/@Schema)[1]', 'varchar(128)')
   AND QUOTENAME(ic.TABLE_NAME) = t.value('(ScalarOperator/Identifier/ColumnReference/@Table)[1]', 'varchar(128)')
   AND ic.COLUMN_NAME = t.value('(ScalarOperator/Identifier/ColumnReference/@Column)[1]', 'varchar(128)')
WHERE t.exist('ScalarOperator/Identifier/ColumnReference[@Database=sql:variable("@dbname")][@Schema!="[sys]"]') = 1

T-SQL Tuesday #20 – Melhores Práticas


Neste mês o tema escolhido pelo Sr. Amit Banerjee (blog | twitter) foi: Melhores Práticas,,,

A algum tempo atrás escrevi um post com “Dicas para otimizar suas funções SQL”,,, vou adicionar algumas coisas que acho interessante com este post aqui.

  • Comentários,,,,

Lembra daquela procedure que fazia uma validação de alguma coisa em algum lugar ??? Lembra por que você declarou aquele campo bit no começo ??? Não? tem certeza que sabe? acha que era para alguma coisa importante?

Uma coisa que acho muito importante em todo o código, mas são poucas as pessoas que fazem direito e menos ainda as que fazem, é comentar o que ele faz,,,

Não custa muito adicionar algumas linhas com algum tipo de descritivo do que aquilo deveria fazer, quem fez, quando fez, qual a versão, algum exemplo,,,

Lembre-se: Uma hora ou outra o código pode precisar de manutenção,,, ela pode ser feita por você ou outra pessoa,,, em todo o caso,,, é sempre bom ter alguma coisa para te ajudar a lembrar,,,

Ex:

/*
Nome: usp_mostra_nome_base
Versão: 2.0
Data de criação: 11-07-2011
Data da última modificação: 12-07-2011

Autor: Ricardo Leka Roveri
Últuma modificação executada por: Ricardo Leka Roveri

Script:
Esta procedure server para listas o nome das bases existentes no sistema.

Exemplo
exec usp_mostra_nome_base

Versão 1:
Autor: Ricardo Leka Roveri

nesta versão a proc faz XYZ

Versão 2:
Autor: Ricardo Leka Roveri

nesta versão a proc faz XYZ ordenado por data de criação

*/

Outra coisa interessante seria comentar partes do código,,, não precisa escrever um livro do motivo que você está fazendo aquele join entre 20 tabelas mas, de uma forma clara, escrever o objetivo dessa bagunça,,,

  • NOLOCK,,,

Você é um fanático por NOLOCK? Legal,,, nada contra,,, mas se vai usar isso umas 40 vezes dentro de uma procedure porque você não declara ele como:

SET TRANSACTION ISOLATION LEVEL READ UNCOMMITED;

é legal, ajuda, mais simples pra você e para qualquer outra pessoa que veja seu código…

  • Lembrete,,,

Lembre-se:

A maior parte de vocês não desenvolve coisas pra vocês,,, vocês desenvolvem coisas pra outras pessoas usarem…

Não é porque na sua maquina tudo funciona direitinho que quando for para produção tem que funcionar,,, Você precisa testar,,, faça teste de carga… stresse sua aplicação até ela parar,,, 10,,, 100,,, 1000,,, acessos simultâneos,,,

Existem muitas ferramentas que fazem teste de carga. Ex.: JMeter, o próprio SQL Profiler, etc..

Corrompendo um Banco SQL


Qual a necessidade de criar uma base corrompida?

Pra que você precisa desse tipo de coisa?

Você precisa treinar…

Mesmo que saiba o que fazer, é importante treinar para situações complicadas…

É melhor fazer muita tentativa em erro em um ambiente controlado do que no ambiente de produção,,, certo?

Então,,, antes de mais nada… eu sei que você sabe,,, mas não custa nada relembrar,,,

NUNCA FAÇA ISSO EM PRODUÇÃO !!!

Bom,,, com isso em mente,,, vamos começar,,,

1. Vamos criar uma base:

CREATE DATABASE [corrompeu]
GO

2. Vamos alterar o modo de recovery da base:

alter database corrompeu
set recovery full
GO

3. Agora vamos colocar uma tabela:

use corrompeu
GO

create table vendas
(
vendasID int identity,
clienteID int default convert(int, 100000 * RAND()),
vendaData datetime default getdate(),
vendaTotal money
)
GO

4. Adicionamos um índice pra dar gosto…

create clustered index vendaCI on vendas (vendasID)
GO

5. Colocamos uns dados,,,

set nocount ON
GO

declare @conta INT
select @conta = 0
while (@conta < 50000)
begin
    insert into
vendas (vendaTotal)
    values (100*RAND())
    select @conta = @conta +1
end
GO

7. E vamos fazer uns backups

use master
GO

backup database corrompeu
to disk = ‘d:\db01\local\corrompeu_1.bak’
with init
go

backup log corrompeu
to disk = ‘d:\db01\local\corrompeu_2.trn’
go

8. Bom,,, com os backups feitos,,, vamos ver as páginas que foram criadas,,,

dbcc ind (‘corrompeu’,‘vendas’,1)
GO

9. Escolha uma página e coloque no lugar do XXXXX

DBCC TRACEON (3604)
GO
dbcc page
(‘corrompeu’,1,XXXXX,3)

Você deve ver alguma coisa do tipo:

dbcc

A página que eu escolhi foi a 1:493. Meu vendasID vai do registro 24256 até 245000.

Agora começa a ficar legal….

10. Vamos colocar a base offline:

alter database corrompeu
set offline
GO

11. Agora um simples cálculo…

select 493*8192
GO

Temos o número em decimal da localização da página no arquivo .mdf

12. Com esse número vamos utilizar um editor Hexadecimal para achar a linha dentro do arquivo .mdf.

  • Dentro do editor de Hexadecimal, abra o arquivo .mdf (neste caso D:\DB01\Corrompeu.mdf).
  • Clique em “Localizar” e escolha “Ir Para”.
  • Escolha a opção “DEC”, digite ou cole o resultado do cálculo acima e depois cliente em “HEX”, ele vai converter o valor para Hexadecimal.

localizar

  • clique em “OK”
  • Altere a linha onde o cursor esta piscando para 00 (zero-zero), ela vai ficar em vermelho.

alterado

  • Salve o arquivo.

13. Agora dentro do SQL vamos voltar com a base online:

alter database corrompeu
set online
GO

14. Usando o DBCC CHECKDB, vamos ver se a base está realmente corrompida…

dbcc check

Legal,,, temos uma base corrompida…

15. vamos tentar um select na tabela,,, e olha lá o erro,,,

select

Bom,,, legal… temos uma base corrompida,,, e agora?

Agora fica legal… o objetivo é deixar a base operacional sem perder informação… imagine que essa é sua base de produção e justamente essa tabela é a folha de pagamento,,, olha que legal…

Uma dica: tentei fazer o processo de restore no SQL Server Denali CTP 1 e não consegui restaurar apenas a página, tive que remover ela e reinserir os dados através de outra base, fiz o mesmo processo de restore apenas da página no SQL Server 2008 R2 e funcionou sem problema.

Se alguém precisar de ajuda é só deixar o comentário…

ATUALIZAÇÃO:

Segue o link do SkyDrive com a base, backup e o script desse exemplo:

https://skydrive.live.com/?cid=5145b04265f2979d&sc=documents&id=5145B04265F2979D%21171#

TOP 5 – Ferramentas grátis


ATUALIZAÇÃO !!! – 20/09/2012

Esse post é para falar de ferramentas gratuitas,,, é com muito pesar que estou retirando o SSMS Tools Pack do primeiro lugar, a partir da versão 2.5.0.0 ele deixou de ser de graça, logo, vai contra o intuito do post…

Estou substituindo pela ferramenta SSMSBoost

Tem gente que gosta de fazer as coisas na marra,,, sem ajuda de nada,,, script de baixo de script,,, Isso é muito legal, tem muita coisa que só se resolve assim,,,

O importante é conhecer o que o mercado oferece quando você quer “uma ajuda” ou pra realmente facilitar o dia a dia,,,

O meu TOP 5 de ferramentas gratuitas são:

  1. Pra quem gosta de trabalhar com o SSMS, um add-on bem legal é o SSMS Tools Pack desenvolvido por Mladen Prajdić. Ele adiciona algumas funções bem legais como: histórico, snippets, gerador de código… Acho uma ferramenta pequena e legal… Uma ferramenta muito interessante para adicionar funcionalidades ao SSMS é o SSMSBoost ele adicionar recursos muito bons como snippets, localizador de objetos, alterador de barra de titulo e uma coisa bem legal que é o cadastro de conexão onde você pode colocar alerta de ambiente de produção,,, ai ele avisa, dependendo do comando que você precisa prestar atenção antes de dar um truncate table por exemplo…. Ele é de graça, mas naquelas, você precisa reinstalar ele a cada 45 dias (não é trial, é só uma coisa chata que o desenvolvedor colocou),,,
  2. Quem nunca passou raiva com o gerador de plano de execução do SSMS que drop um banco?,,, Se você usar o SQL Sentry Plan Explorer pelo menos uma vez, não vai querer deixar de usar,,, ele mostra de uma forma fácil de entender qual parte do plano estásendo mais custoso para a operação… fora outras coisas legais…
  3. Não pode faltar de jeito nenhum o Who is Active desenvolvido por Adam Machanic e por falar nele, existe um add-on da Schema Solutionsque adiciona uma interface gráfica para a execução de procedure.
  4. Na primeira vez que vi essa ferramenta não achei que seria tão útil, mas o SQL Trace Analyzeré bem interessante. Ele analisa o Profiler capturado em arquivo ou banco e gera um relatório consolidado mostrando o impacto, tempo, processamento, IO, etc.. E de brinde ele instala um monitorador de Locks/Blocks. O problema dessa ferramenta é a parafernália que ele instala, mas você pode remover o resto das coisas e ficar só com o programa principal.
  5. E não podia faltar alguma forma de monitorar o que acontece com o banco,,, para isso achei o IgniteFree, uma ferramenta muito simples de configurar e com muita informação relevante. Claro que a versão Trial/Full tem mais opções, mas mesmo na versão free é uma ótima ferramenta. Ela é leve, não ocupa muito espaço, não gera pressão na máquina que está sendo monitorada e de quebra ainda consegue monitorar uns Oracles que você tenha perdido no ambiente…

Quando foi que trocaram a senha?


Quando estamos no SQL Server (2005 ou superior), existem uma função que mostra algumas propriedades interessante sobre o login do SQL chamada LoginProperty.

Não conheço muitas aplicações que possuem interface que permite o usuário trocar a senha dele no SQL,,, mas achei interessante ter essa opção para saber quando alguém trocou a senha e “esqueceu” de avisar,,, ai tem aplicação que não abre,,, usuário que não loga,,, e quase sempre ninguém nunca fez nada….

Aqui vão alguns selects interessantes….

Mostra todos os logins que tiveram a senha trocada a mais de 30 dias:

 1: SELECT name, LOGINPROPERTY([name], 'PasswordLastSetTime') AS 'SenhaTrocada'
 2: FROM sys.sql_logins
 3: WHERE LOGINPROPERTY([name], 'PasswordLastSetTime') < DATEADD(dd, -60, GETDATE());

Mostra todos os logins que tiveram a senha trocada no último dia:

 1: SELECT name, LOGINPROPERTY([name], 'PasswordLastSetTime') AS 'SenhaTrocada'
 2: FROM sys.sql_logins
 3: WHERE LOGINPROPERTY([name], 'PasswordLastSetTime') > DATEADD(dd, -1, GETDATE());

T-SQL Tuesday #18 – CTEs


Bom,,, para este mês o Sr. Bob Pusateri (twitter | Blog) escolheu o tópico Common Table Expressions (CTE).

Você não sabe o que é? Não faz ideia? Isso é mais comum do que você imagina,,, vejo muitos códigos por ai onde o pessoal de dev poderia utilizar este recurso, mas como ainda estão presos em conceitos antigos do SQL 2000 ou as vezes até mais velhos não fazem ideia de alguns novos recursos interessantes…

Para uma leitura interessante sobre este assunto acesse:

Você vai achar muita coisa voltada pra dev… mas,,, como sou mais um cada de infra,,, achei interessante este código no Site do Sr. Paul Randal (twitter | Blog) sobre wait statistics usando a sys.dm_os_wait_stats, nada muito complexo.

 1: WITH Waits AS
 2:     (SELECT
 3:         wait_type,
 4:         wait_time_ms / 1000.0 AS WaitS,
 5:         (wait_time_ms - signal_wait_time_ms) / 1000.0 AS ResourceS,
 6:         signal_wait_time_ms / 1000.0 AS SignalS,
 7:         waiting_tasks_count AS WaitCount,
 8:         100.0 * wait_time_ms / SUM (wait_time_ms) OVER() AS Percentage,
 9:         ROW_NUMBER() OVER(ORDER BY wait_time_ms DESC) AS RowNum
 10:     FROM sys.dm_os_wait_stats
 11:     WHERE wait_type NOT IN (
 12:         'CLR_SEMAPHORE', 'LAZYWRITER_SLEEP', 'RESOURCE_QUEUE', 'SLEEP_TASK',
 13:         'SLEEP_SYSTEMTASK', 'SQLTRACE_BUFFER_FLUSH', 'WAITFOR', 'LOGMGR_QUEUE',
 14:         'CHECKPOINT_QUEUE', 'REQUEST_FOR_DEADLOCK_SEARCH', 'XE_TIMER_EVENT', 'BROKER_TO_FLUSH',
 15:         'BROKER_TASK_STOP', 'CLR_MANUAL_EVENT', 'CLR_AUTO_EVENT', 'DISPATCHER_QUEUE_SEMAPHORE',
 16:         'FT_IFTS_SCHEDULER_IDLE_WAIT', 'XE_DISPATCHER_WAIT', 'XE_DISPATCHER_JOIN', 'BROKER_EVENTHANDLER',
 17:         'TRACEWRITE', 'FT_IFTSHC_MUTEX', 'SQLTRACE_INCREMENTAL_FLUSH_SLEEP',
 18:         'BROKER_RECEIVE_WAITFOR', 'ONDEMAND_TASK_QUEUE', 'DBMIRROR_EVENTS_QUEUE',
 19:         'DBMIRRORING_CMD', 'BROKER_TRANSMITTER', 'SQLTRACE_WAIT_ENTRIES',
 20:         'SLEEP_BPOOL_FLUSH', 'SQLTRACE_LOCK')
 21:     )
 22: SELECT
 23:     W1.wait_type AS WaitType,
 24:     CAST (W1.WaitS AS DECIMAL(14, 2)) AS Wait_S,
 25:     CAST (W1.ResourceS AS DECIMAL(14, 2)) AS Resource_S,
 26:     CAST (W1.SignalS AS DECIMAL(14, 2)) AS Signal_S,
 27:     W1.WaitCount AS WaitCount,
 28:     CAST (W1.Percentage AS DECIMAL(4, 2)) AS Percentage,
 29:     CAST ((W1.WaitS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgWait_S,
 30:     CAST ((W1.ResourceS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgRes_S,
 31:     CAST ((W1.SignalS / W1.WaitCount) AS DECIMAL (14, 4)) AS AvgSig_S
 32: FROM Waits AS W1
 33:     INNER JOIN Waits AS W2 ON W2.RowNum <= W1.RowNum
 34: GROUP BY W1.RowNum, W1.wait_type, W1.WaitS, W1.ResourceS, W1.SignalS, W1.WaitCount, W1.Percentage
 35: HAVING SUM (W2.Percentage) - W1.Percentage < 95;
 36: GO

T-SQL Tuesday #17–Apply


O tópico deste mês para o T-SQL Tuesday é o operador apply,,,

Caso você não faça ideia de pra que serve o apply leia aqui.

Para este post vou coloca um script simples usando o apply.

Ele não faz nada muito importante, apenas mostra as 20 querys que mais gerão stress de disco:

SELECT TOP 20 SUBSTRING(qt.text, (qs.statement_start_offset/2)+1,
((CASE qs.statement_end_offset
WHEN -1 THEN DATALENGTH(qt.text)
ELSE qs.statement_end_offset
END – qs.statement_start_offset)/2)+1),
qs.execution_count,
qs.total_logical_reads, qs.last_logical_reads,
qs.min_logical_reads, qs.max_logical_reads,
qs.total_elapsed_time, qs.last_elapsed_time,
qs.min_elapsed_time, qs.max_elapsed_time,
qs.last_execution_time,
qp.query_plan
FROM sys.dm_exec_query_stats qs
CROSS APPLY sys.dm_exec_sql_text(qs.sql_handle) qt
CROSS APPLY sys.dm_exec_query_plan(qs.plan_handle) qp
WHERE qt.encrypted=0
ORDER BY qs.total_logical_reads DESC

Sou alguém importante no SQL?


Algumas vezes acontece de você prestar serviço para alguma empresa/usuário/amigo e o pessoal cria um usuário para acesso ao ambiente SQL, como em muitos casos não precisamos de acesso direto no servidor podemos usar o SSMS/Enterprise Manager ou qualquer outra ferramenta que esteja disponível. Apenas precisamos saber qual o nível de acesso do nosso usuário…

Continuar lendo

Não instale o VS2010 SP1 se você usa o Intellisense no SSMS


Se você gosta e usa o Intellisense (aquele opção que ajuda a preencher alguns itens quando você está digitando alguma query) no SSMS NÃO instale o Visual Studio 2010 SP1…

Isso acontece com o SSMS do 2008 R2, de acordo com o time da Microsoft a solução vai estar disponível no CU7 do SQL Server 2008R2 e no SP1 do SQL 2008 R2,,,

https://connect.microsoft.com/SQLServer/feedback/details/650569/ssms-2008-r2-is-losing-intellisense-after-installing-visual-studio-2010-sp1

Quanto tempo vai demorar para…


Você já passou por aquela situação de ter que fazer um backup de uma base que não é imagepequena e não ter ideia de quanto tempo vai demorar? Você fica olhando aquela circulo maldito do SSMS rodando e rodando e nada, quando ele mostra alguma coisa é de 10% em 10%,,, Ou quando executa um script ele também fica nos 10% em 10%,,,

Isso é muito chato,,,

Continuar lendo

Logon automático para o w2k8


Acabei de colocar um post escrevendo como faz o logon automático para o w2k3 ai fui testar a mesma coisa no w2k8 e percebi que não havia a opção do Users must enter a user name and password to use this computer não aparecer mais,,, aahh isso só acontece depois que você coloca a maquina w2k8/7 no domínio…

Continuar lendo