Skip to content

Commit 931b88c

Browse files
authored
Update and rename test.txt to save_report_snapshots.ps1
1 parent e4596aa commit 931b88c

File tree

2 files changed

+74
-1
lines changed

2 files changed

+74
-1
lines changed
Lines changed: 74 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,74 @@
1+
<#
2+
Description: Save SSRS Report Snapshots
3+
4+
#>
5+
6+
$sql = "
7+
DECLARE @ReportName NVARCHAR(200) = 'Daily Report';
8+
DECLARE @FileFormat NVARCHAR(50) = 'CSV'; --HTML5,PPTX,ATOM,HTML4.0,MHTML,IMAGE,EXCEL (for .xls),EXCELOPENXML (for .xlsx),WORD (for .doc),WORDOPENXML (for .docx),CSV,PDF,XML
9+
DECLARE @FileExtn NVARCHAR(50) = 'csv';
10+
DECLARE @ServerName NVARCHAR(100) = 'https://REPORTS';
11+
DECLARE @DateFrom DATE = CAST(DATEADD(DAY, -1, GETDATE()) AS DATE); --change to NULL for every snapshot
12+
DECLARE @ExportPath NVARCHAR(200) = 'C:\Temp\';
13+
14+
SELECT
15+
--[ReportID] = [c].[itemid]
16+
-- , [ReportName] = [c].[name]
17+
-- , [ReportPath] = [c].[path]
18+
-- , [SnaphsotDate] = FORMAT([h].[snapshotdate], 'dd-MMM-yyyy')
19+
-- , [SnapshotDescription] = [s].[DESCRIPTION]
20+
-- , [SnapshotEffectiveParams] = [s].[effectiveparams]
21+
-- , [SnapshotQueryParams] = [s].[queryparams]
22+
-- , [ScheduleName] = [sc].[name]
23+
-- , [ScheduleNextRunTime] = CONVERT(VARCHAR(20), [sc].[nextruntime], 113)
24+
[ExportFileName] = @ExportPath + REPLACE([c].[name], ' ', '_') + '_' + FORMAT([h].[snapshotdate], 'yyyyMMdd_HHmm') + '.' + @FileExtn
25+
, [SnapshotUrl] =
26+
@ServerName
27+
+ '/ReportServer/Pages/ReportViewer.aspx?'
28+
+ [c].[path] + '&rs:Command=Render&rs:Format='
29+
+ @FileFormat + '&rs:Snapshot='
30+
+ FORMAT([h].[snapshotdate], 'yyyy-MM-ddTHH:mm:ss')
31+
FROM
32+
[ReportServer].[dbo].[History] AS [h] WITH(NOLOCK)
33+
INNER JOIN [ReportServer].[dbo].[SnapshotData] AS [s] WITH(NOLOCK) ON [h].[snapshotdataid] = [s].[snapshotdataid]
34+
INNER JOIN [ReportServer].[dbo].[Catalog] AS [c] WITH(NOLOCK) ON [c].[itemid] = [h].[reportid]
35+
INNER JOIN [ReportServer].[dbo].[ReportSchedule] AS [rs] WITH(NOLOCK) ON [rs].[reportid] = [h].[reportid]
36+
INNER JOIN [ReportServer].[dbo].[Schedule] AS [sc] WITH(NOLOCK) ON [sc].[scheduleid] = [rs].[scheduleid]
37+
WHERE
38+
1=1
39+
AND [rs].[reportaction] = 2
40+
AND [c].[Name] = @ReportName
41+
AND (@DateFrom IS NULL OR [h].[snapshotdate] >= CAST(DATEADD(DAY, -1, GETDATE()) AS DATE))
42+
ORDER BY
43+
[c].[name]
44+
, [h].[snapshotdate];
45+
;"
46+
47+
$server = 'REPORTS';
48+
$dbs = 'MASTER';
49+
$dsn = "Data Source=$server; Initial Catalog=$dbs; Integrated Security=SSPI;";
50+
$cn = New-Object System.Data.SqlClient.SqlConnection($dsn);
51+
52+
#execute merge statement here with parameters
53+
$cn = New-Object System.Data.SqlClient.SqlConnection($dsn);
54+
$cn.Open();
55+
56+
$cmd = $cn.CreateCommand();
57+
$cmd.CommandText = $sql
58+
$SqlAdapter = New-Object System.Data.SqlClient.SqlDataAdapter
59+
$SqlAdapter.SelectCommand = $cmd
60+
$cmd.Connection = $cn
61+
$ds = New-Object System.Data.DataSet
62+
$SqlAdapter.Fill($ds)
63+
$cn.Close()
64+
$Result = $ds.Tables[0]
65+
#$Result
66+
67+
Foreach ($item in $Result)
68+
{
69+
#Write-Host $item.name
70+
71+
$SnapshotUrl = $item.SnapshotUrl
72+
$ExportFileName = $item.ExportFileName
73+
(Invoke-WebRequest -Uri $SnapshotUrl -OutFile $ExportFileName -UseDefaultCredentials -TimeoutSec 240);
74+
}

Miscellaneous/Scripts/PowerShell/test.txt

Lines changed: 0 additions & 1 deletion
This file was deleted.

0 commit comments

Comments
 (0)