Skip to content

Instantly share code, notes, and snippets.

@zv0r
Created December 19, 2013 08:08
Show Gist options
  • Save zv0r/8035932 to your computer and use it in GitHub Desktop.
Save zv0r/8035932 to your computer and use it in GitHub Desktop.
Переносит исповедные росписи из mdb church в АИС Архив. Выводит список заголовков, не попавших в базу АИС Архив.
SET IDENTITY_INSERT [AISArchive].[dbo].[tblThemeCards] ON
/*
*
* ID тематической БД исповедных росписей
*
*/
DECLARE @CatId INT
SET @CatId = 3
/*
*
* ID архивного учреждения, в БД которого заливаются данные
*
*/
DECLARE @ArchId INT
SET @ArchId = 1
DECLARE @whole_results TABLE(
Id INT
,ItemId INT
,ThemeCatalogId INT
,Content VARCHAR(740)
,FundNumber NVARCHAR(255)
,InventoryNumber NVARCHAR(255)
,ArchiveFileNumber NVARCHAR(255)
,CreationTime DATETIME
,DeletionTime DATETIME
,Deleted BIT
,ArchiveId INT
,SortCode VARCHAR(160)
,nvarchar1 NVARCHAR(255)
,nvarchar2 NVARCHAR(255)
,nvarchar3 NVARCHAR(255)
,nvarchar7 NVARCHAR(255)
,nvarchar8 NVARCHAR(255)
,nvarchar9 NVARCHAR(255)
,nvarchar10 NVARCHAR(255)
)
/*
* Сбор данных в одну кучу во временную таблицу.
* Потом раскидается по нужным таблицам
*
*/
INSERT INTO @whole_results (
Id
,ItemId
,ThemeCatalogId
,Content
,FundNumber
,InventoryNumber
,ArchiveFileNumber
,CreationTime
,DeletionTime
,Deleted
,ArchiveId
,SortCode
,nvarchar1
,nvarchar2
,nvarchar3
,nvarchar7
,nvarchar8
,nvarchar9
,nvarchar10
)
SELECT
(IDENT_CURRENT('AISArchive.dbo.tblThemeCards') + ROW_NUMBER() OVER(ORDER BY Fond)) as Id,
(IDENT_CURRENT('AISArchive.dbo.tblThemeCards') + ROW_NUMBER() OVER(ORDER BY Fond)) as ItemId,
@CatId as ThemeCatalogId,
('Населенный пункт: ' + ISNULL(NULLIF(pt.[PoTypeName], '***'), '')
+ ' ' + ISNULL(NULLIF(p.[PointName], '***'), '-')
+ '. Уезд: ' + ISNULL(NULLIF(u.[UezdName], '***'), '-')
+ '. Церковь: ' + ISNULL(NULLIF(t.[TempleName], '***'), '-')) as Content,
ch.[Fond] as FundNumber,
ch.[Volume] as InventoryNumber,
ch.[Nom] as ArchiveFileNumber,
CURRENT_TIMESTAMP as CreationTime,
NULL as DeletionTime,
0 as Deleted,
@ArchId as ArchiveId,
('ф.' + RIGHT('000000000000000000000000000000000000000000000000' + CONVERT(VARCHAR, ch.[Fond]), 50)
+ ' оп.' + RIGHT('000000000000000000000000000000000000000000000000' + CONVERT(VARCHAR, ch.[Volume]), 50)
+ ' д.' + RIGHT('000000000000000000000000000000000000000000000000' + CONVERT(VARCHAR, ch.[Nom]), 50)) as SortCode,
(ISNULL(NULLIF(pt.[PoTypeName], '***'), '-')) as nvarchar1,
(ISNULL(NULLIF(p.[PointName], '***'), '-')) as nvarchar2,
(ISNULL(NULLIF(u.[UezdName], '***'), '-')) as nvarchar3,
(ISNULL(NULLIF(t.[TempleName], '***'), '-')) as nvarchar7,
ch.[Year] as nvarchar8,
ch.[Lists] as nvarchar9,
ISNULL(sv.[name], '-') as nvarchar10
FROM
[Church].[dbo].[Ispoved] ch
LEFT JOIN [Church].[dbo].[Points] p ON
p.[PointID] = ch.[PointID]
LEFT JOIN [Church].[dbo].[PointsType] pt ON
pt.[PoTypeID] = p.[PointType]
LEFT JOIN [Church].[dbo].[Uezd] u ON
u.[UezdID] = ch.[UezdID]
LEFT JOIN [Church].[dbo].[Temples] t ON
t.[TempleID] = ch.[TempleID]
LEFT JOIN [Church].[dbo].[svyasch] sv ON
sv.[ID] = ch.[svID]
WHERE
ch.[status] = 1
AND NOT EXISTS (
SELECT *
FROM
[AISArchive].[dbo].[tblThemeCards] tc
WHERE
tc.FundNumber = ch.Fond
AND tc.InventoryNumber = ch.Volume
AND tc.ArchiveFileNumber = ch.Nom
AND tc.ThemeCatalogId = @CatId
AND tc.Deleted = 0
AND tc.ArchiveId = @ArchId
AND tc.Content =
('Населенный пункт: ' + ISNULL(NULLIF(pt.[PoTypeName], '***'), '')
+ ' ' + ISNULL(NULLIF(p.[PointName], '***'), '-') + '. Уезд: '
+ ISNULL(NULLIF(u.[UezdName], '***'), '-')
+ '. Церковь: ' + ISNULL(NULLIF(t.[TempleName], '***'), '-'))
)
AND ch.[Fond] IS NOT NULL
AND ch.[Fond] NOT LIKE '0%'
AND ch.[Volume] > 0
AND ch.[File] > 0
AND ch.[UezdID] > 0
AND ch.[TempleID] > 0
AND p.[PointType] > 0
ORDER BY
p.[PointName] ASC,
pt.[PoTypeName] ASC,
u.[UezdName] ASC,
t.[TempleName] ASC,
ch.[Fond] ASC,
ch.[Volume] ASC,
ch.[File] ASC,
ch.[Leter] ASC
/*
*
* Вставить тематические карточки
*
*/
INSERT INTO [AISArchive].[dbo].[tblThemeCards] (
Id
,ThemeCatalogId
,Content
,FundNumber
,InventoryNumber
,ArchiveFileNumber
,CreationTime
,DeletionTime
,Deleted
,ArchiveId
,SortCode
)
SELECT
Id
,ThemeCatalogId
,Content
,FundNumber
,InventoryNumber
,ArchiveFileNumber
,CreationTime
,DeletionTime
,Deleted
,ArchiveId
,SortCode
FROM @whole_results
/*
*
* Вставить дополнительную информацию по тематическим карточкам
*
*/
INSERT INTO [AISArchive].[dbo].[tblItemsAdditionalFieldsValues] (
ItemId
,ItemType
,nvarchar1
,nvarchar2
,nvarchar3
,nvarchar7
,nvarchar8
,nvarchar9
,nvarchar10
)
SELECT
ItemId
,9 as ItemType
,nvarchar1
,nvarchar2
,nvarchar3
,nvarchar7
,nvarchar8
,nvarchar9
,nvarchar10
FROM @whole_results
/*
*
* Вывести список невошедших в базу записей.
*
*/
SELECT
('Населенный пункт: ' + ISNULL(NULLIF(pt.[PoTypeName], '***'), '')
+ ' ' + ISNULL(NULLIF(p.[PointName], '***'), '-')
+ '. Уезд: ' + ISNULL(NULLIF(u.[UezdName], '***'), '-')
+ '. Церковь: ' + ISNULL(NULLIF(t.[TempleName], '***'), '-')) as Content,
ch.[Fond] as FundNumber,
ch.[Volume] as InventoryNumber,
ch.[Nom] as ArchiveFileNumber,
ch.[Lists] as Lists,
ch.[Year] as [Year],
ch.[UezdID] as UezdID,
ch.[TempleID] as TempleID,
ch.[PointID] as PointID,
p.[PointType] as PointType
FROM
[Church].[dbo].[Ispoved] ch
LEFT JOIN [Church].[dbo].[Points] p ON
p.[PointID] = ch.[PointID]
LEFT JOIN [Church].[dbo].[PointsType] pt ON
pt.[PoTypeID] = p.[PointType]
LEFT JOIN [Church].[dbo].[Uezd] u ON
u.[UezdID] = ch.[UezdID]
LEFT JOIN [Church].[dbo].[Temples] t ON
t.[TempleID] = ch.[TempleID]
LEFT JOIN [Church].[dbo].[svyasch] sv ON
sv.[ID] = ch.[svID]
WHERE
(ch.[status] = 1
AND NOT EXISTS (
SELECT *
FROM
[AISArchive].[dbo].[tblThemeCards] tc
WHERE
tc.FundNumber = ch.Fond
AND tc.InventoryNumber = ch.Volume
AND tc.ArchiveFileNumber = ch.Nom
AND tc.ThemeCatalogId = @CatId
AND tc.Deleted = 0
AND tc.ArchiveId = @ArchId
AND tc.Content =
('Населенный пункт: ' + ISNULL(NULLIF(pt.[PoTypeName], '***'), '')
+ ' ' + ISNULL(NULLIF(p.[PointName], '***'), '-')
+ '. Уезд: ' + ISNULL(NULLIF(u.[UezdName], '***'), '-')
+ '. Церковь: ' + ISNULL(NULLIF(t.[TempleName], '***'), '-'))
))
AND (ch.[Fond] IS NULL
OR ch.[Fond] LIKE '0%'
OR ch.[Volume] < 1
OR ch.[File] < 1
OR ch.[UezdID] < 1
OR ch.[TempleID] < 1
OR p.[PointType] < 1)
ORDER BY
p.[PointName] ASC,
pt.[PoTypeName] ASC,
u.[UezdName] ASC,
t.[TempleName] ASC,
ch.[Fond] ASC,
ch.[Volume] ASC,
ch.[File] ASC,
ch.[Leter] ASC
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment