205 lines
6.5 KiB
Transact-SQL
205 lines
6.5 KiB
Transact-SQL
SET NOCOUNT ON
|
|
Select RODBID, ROName, FolderPath
|
|
, (Select Count(*) from ROUSAGES UU where UU.RODBID = DB.RODBID) Usages
|
|
, (Select Count(*) from DROUSAGES UU where UU.RODBID = DB.RODBID) DocUsages
|
|
, (Select Count(*) from ROFSTs FS where FS.RODBID = DB.RODBID) ROFSTs
|
|
, (select Count(*) from Associations AA
|
|
Join ROFSTs RF On RF.ROFstID=AA.ROFstID where RF.RODBID = DB.RODBID) Associations
|
|
, (select Count(*) from Figures FF
|
|
Join ROFSTs RF On RF.ROFstID=FF.ROFstID where RF.RODBID = DB.RODBID) Figures
|
|
from RODBS DB
|
|
GO
|
|
EXECUTE [vesp_TurnChangeManagerOFF]
|
|
GO
|
|
PRINT ' 1 Purge Multiple Associations'
|
|
begin
|
|
with cte as (
|
|
Select *, Row_Number() over (partition by VersionID order by associationID ) MyRank from Associations
|
|
)
|
|
delete CTE where MyRank > 1
|
|
end
|
|
|
|
DECLARE @FstRanks as TABLE
|
|
(
|
|
ROFSTID int primary key,
|
|
UniqueRow int,
|
|
Duplicate int
|
|
)
|
|
PRINT ' 2 Find Duplicate ROFSTs'
|
|
Insert into @FstRanks
|
|
Select ROFSTID
|
|
, DENSE_RANK() Over (order by ROLOOKUP) UniqueRow
|
|
, ROW_NUMBER() Over (partition by ROLOOKUP order by ROLOOKUP) Duplicate
|
|
From ROFSTs
|
|
|
|
DECLARE @Trans as TABLE
|
|
(
|
|
ROFSTID int,
|
|
VersionID int
|
|
)
|
|
|
|
PRINT ' 3 Create a Translation Table'
|
|
|
|
Insert Into @Trans
|
|
Select (Select Min(ROFSTID) From @FstRanks where UniqueRow = RNK.UniqueRow) ROFSTID,
|
|
AA.VersionID
|
|
from ROFSTs RF
|
|
Join @FstRanks RNK ON RF.ROFSTID = RNK.ROFSTID
|
|
Join Associations AA on AA.RofstID = RF.ROFstID
|
|
|
|
PRINT ' 4 Translate RO Associations'
|
|
|
|
Update AA set ROFSTID = TT.ROFSTID
|
|
From Associations AA
|
|
Join @Trans TT ON AA.VersionID = TT.VersionID
|
|
|
|
|
|
PRINT ' 5 Contents - replacing rodbid''s in content records'' link text'
|
|
|
|
update cc set text = replace(text, ' ' + cast(ru.rodbid as varchar(2)) + '[END>', ' 1[END>')
|
|
from Contents CC
|
|
Join ROUsages RU ON CC.ContentID = RU.ContentID
|
|
where RU.rodbid !=1
|
|
|
|
PRINT ' 6 Grids - replacing rodbid''s in grid records'' link text'
|
|
|
|
update GG set data = cast(replace(cast(data as nvarchar(max)), ' ' + cast(ru.rodbid as varchar(2)) + '[END>', ' 1[END>') as xml)
|
|
from Grids GG
|
|
Join ROUsages RU ON GG.ContentID = RU.ContentID
|
|
where RU.rodbid !=1
|
|
|
|
PRINT ' 7 Update ROUsages to use the same RODBID'
|
|
update tblROUsages set rodbid = 1
|
|
where rodbid != 1
|
|
|
|
PRINT ' 8 Update DROUsages to use the same RODBID'
|
|
update DROUsages set rodbid = 1
|
|
where rodbid != 1
|
|
|
|
DECLARE @TransImageID table
|
|
(
|
|
ImageID int primary key,
|
|
TransImageID int
|
|
)
|
|
begin
|
|
with cte as (
|
|
select dense_rank() over (order by content) MyRank
|
|
,row_number() over (partition by content order by RODBID ) Duplicate,*
|
|
from roimages)
|
|
Insert Into @TransImageID
|
|
select CT1.ImageID , CT2.ImageID TransID from CTE CT1
|
|
Join (select ImageID, MyRank From CTE where Duplicate = 1) CT2 ON CT1.MyRank = CT2.MyRank
|
|
--Where CT1.ImageID != CT2.ImageID
|
|
end
|
|
--Select * from @TransImageID order by TransImageID
|
|
|
|
--Remove Duplicate Figures
|
|
delete from Figures where FigureID IN(
|
|
select FigureID from (
|
|
Select dense_rank() over (order by ROFstID, TransImageID) MyRank
|
|
,row_number() over (partition by ROFstID, TransImageID order by ROFstID, TransImageID ) Duplicate,FF.*, TT.TransImageID From FIgures FF
|
|
Join @TransImageID TT ON FF.ImageID = TT.ImageID
|
|
) T1 where Duplicate > 1)
|
|
|
|
--
|
|
|
|
/*--select * from (
|
|
Select dense_rank() over (order by ROFstID, TransImageID) MyRank
|
|
,row_number() over (partition by ROFstID, TransImageID order by ROFstID, TransImageID ) Duplicate,FF.*, TT.TransImageID From FIgures FF
|
|
Join @TransImageID TT ON FF.ImageID = TT.ImageID
|
|
--) T1 where Duplicate > 1
|
|
*/
|
|
|
|
PRINT ' 9 Translate RO ImageIDs'
|
|
|
|
Update FF Set FF.ImageID = TT.TransImageID
|
|
From FIgures FF
|
|
Join @TransImageID TT ON FF.ImageID = TT.ImageID
|
|
|
|
PRINT '10 Remove duplicate ROImages'
|
|
|
|
Delete from ROImages where ImageID in (Select ImageID from @TransImageID where ImageID != TransImageID)
|
|
|
|
PRINT '11 Point ROImages at RODBID = 1'
|
|
Update RoImages Set RODBID = 1 where RODBID != 1
|
|
|
|
PRINT '12 Add Missing Figures'
|
|
|
|
DECLARE @LastROFstID int
|
|
select @LastROFstID=max(ROFstID) from ROFSTs
|
|
DECLARE @LastFigureCount int
|
|
select @LastFigureCount=count(*) from Figures where ROFstid = @LastROFstID
|
|
DECLARE @LastRODBID int
|
|
select @LastRODBID= RODBID from ROFSTs where ROFstID = @LastROFstID
|
|
DECLARE @tbl TABLE
|
|
(
|
|
ROFSTID int,
|
|
HowMany int
|
|
)
|
|
insert into @tbl
|
|
select RF.ROFSTID, Count(FF.ROFSTID) HowMany from ROFSTs RF
|
|
Join Figures FF ON FF.ROFstID=RF.ROFSTID
|
|
Where RODBID = @LastRODBID group by RF.ROFSTID
|
|
DECLARE @MaxFigures int
|
|
select @MaxFigures=max(HowMany) from @Tbl
|
|
DECLARE @RecentGoodROFSTID int
|
|
select @RecentGoodROFSTID = Max(ROFSTID) from @tbl where HowMany = @MaxFigures
|
|
--select * from @tbl
|
|
--Print '
|
|
--Latest ROFSTID ' + cast(@LastROFstID as varchar(25)) + '
|
|
--Latest Figure Count ' + cast(@LastFigureCount as varchar(25)) + '
|
|
--Maximum Figure Count ' + cast(@MaxFigures as varchar(25)) + '
|
|
--Latest Good ROFSTID ' + cast(@RecentGoodROFstID as varchar(25)) + '
|
|
--'
|
|
|
|
INSERT INTO [dbo].[Figures]
|
|
([ROFstID],[ImageID],[Config],[DTS],[UserID])
|
|
select AA.ROFstID, FF.ImageID, FF.Config ,FF.DTS,FF.UserID from (select Distinct ROFSTID from Associations) AA
|
|
Join (select ImageID,Config,DTS,UserID from Figures Where ROFstID = @RecentGoodROFSTID) FF ON AA.ROFstID=aa.ROFstID
|
|
Left Join Figures F2 ON AA.ROFstID = f2.ROFstID and ff.ImageID = F2.ImageID
|
|
Where F2.FigureID is null
|
|
|
|
|
|
|
|
--begin
|
|
--with CTE as (
|
|
--select AA.ROFstID, FF.ImageID, FF.Config ,FF.DTS,FF.UserID from (select Distinct ROFSTID from Associations) AA
|
|
--Join (select ImageID,Config,DTS,UserID from Figures Where ROFstID = @RecentGoodROFSTID) FF ON AA.ROFstID=aa.ROFstID
|
|
--Left Join Figures F2 ON AA.ROFstID = f2.ROFstID and ff.ImageID = F2.ImageID
|
|
--Where F2.FigureID is null
|
|
--)
|
|
--select ROFSTID, Count(*) NewFigures , (select Count(*) from Figures FF where CTE.ROFSTID = FF.ROFSTID) OldFigures from CTE Group By ROFSTID
|
|
--end
|
|
|
|
|
|
PRINT '13 Remove unused Figures'
|
|
|
|
Delete From Figures where ROFstID not in(Select ROFSTID from Associations)
|
|
|
|
PRINT '14 remove unused ROFSTs'
|
|
|
|
Delete From ROFSTS where ROFstID not in(Select ROFSTID from Associations)
|
|
|
|
PRINT '15 Point ROFSTs at RODBID=1'
|
|
|
|
Update ROFSTs Set RODBID = 1
|
|
Where RODBID != 1
|
|
|
|
PRINT '16 Remove unused RODBs'
|
|
|
|
Delete RODBs Where RODBID != 1
|
|
|
|
PRINT '17 Rename RODB'
|
|
Update RODBs Set ROName='RO'
|
|
GO
|
|
EXECUTE [vesp_TurnChangeManagerON]
|
|
GO
|
|
Select RODBID, ROName, FolderPath
|
|
, (Select Count(*) from ROUSAGES UU where UU.RODBID = DB.RODBID) Usages
|
|
, (Select Count(*) from DROUSAGES UU where UU.RODBID = DB.RODBID) DocUsages
|
|
, (Select Count(*) from ROFSTs FS where FS.RODBID = DB.RODBID) ROFSTs
|
|
, (select Count(*) from Associations AA
|
|
Join ROFSTs RF On RF.ROFstID=AA.ROFstID where RF.RODBID = DB.RODBID) Associations
|
|
, (select Count(*) from Figures FF
|
|
Join ROFSTs RF On RF.ROFstID=FF.ROFstID where RF.RODBID = DB.RODBID) Figures
|
|
from RODBS DB |