SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Execution of Subscribed report through Stored procedure


Execution of Subscribed report through Stored procedure

Author
Message
v.maneesh11
v.maneesh11
SSC-Enthusiastic
SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)

Group: General Forum Members
Points: 121 Visits: 172
Hi,

I have a requirment where reports which are subscribed needs to executed through the Stored procedure

I mean for eg My Subscription Id
is 18EC9ADE-E538-46C0-AB78-2D1FF950CE85

so what i want to do is
EXEC 18EC9ADE-E538-46C0-AB78-2D1FF950CE85 along with passing the parameters required to generate the report

can any please help me out...
Thanking You
Daniel Bowlin
Daniel Bowlin
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4090 Visits: 2629
All SSRS subscriptions are SQL Server Agent Jobs. Use the following script to figure out which Agent job corresponds to which subscription. Run this against your reporting services database

SELECT
cat.[Name] AS RptName
, U.UserName
, cat.[Path]
, res.ScheduleID AS JobID
, sub.LastRuntime
, sub.LastStatus
, LEFT(CAST(sch.next_run_date AS CHAR(8)) , 4) + '-'
+ SUBSTRING(CAST(sch.next_run_date AS CHAR(8)) , 5 , 2) + '-'
+ RIGHT(CAST(sch.next_run_date AS CHAR(8)) , 2) + ' '
+ CASE WHEN LEN(CAST(sch.next_run_time AS VARCHAR(6))) = 5
THEN '0' + LEFT(CAST(sch.next_run_time AS VARCHAR(6)) , 1)
ELSE LEFT(CAST(sch.next_run_time AS VARCHAR(6)) , 2)
END + ':'
+ CASE WHEN LEN(CAST(sch.next_run_time AS VARCHAR(6))) = 5
THEN SUBSTRING(CAST(sch.next_run_time AS VARCHAR(6)) , 2 , 2)
ELSE SUBSTRING(CAST(sch.next_run_time AS VARCHAR(6)) , 3 , 2)
END + ':00.000' AS NextRunTime
, CASE WHEN job.[enabled] = 1 THEN 'Enabled'
ELSE 'Disabled'
END AS JobStatus
, sub.ModifiedDate
, sub.Description
, sub.EventType
, sub.Parameters
, sub.DeliveryExtension
, sub.Version
FROM
dbo.Catalog AS cat
INNER JOIN dbo.Subscriptions AS sub
ON cat.ItemID = sub.Report_OID
INNER JOIN dbo.ReportSchedule AS res
ON cat.ItemID = res.ReportID
AND sub.SubscriptionID = res.SubscriptionID
INNER JOIN msdb.dbo.sysjobs AS job
ON CAST(res.ScheduleID AS VARCHAR(36)) = job.[name]
INNER JOIN msdb.dbo.sysjobschedules AS sch
ON job.job_id = sch.job_id
INNER JOIN dbo.Users U
ON U.UserID = sub.OwnerID
ORDER BY
U.UserName
, RptName



Once you know what the appropriate agent job is, disable it. Then you can create another agent job that executes the agent job using sp_start_job. The only issue here is you will have to build your reports with default parameters.
v.maneesh11
v.maneesh11
SSC-Enthusiastic
SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)SSC-Enthusiastic (121 reputation)

Group: General Forum Members
Points: 121 Visits: 172
Hi Daniel

Thanks for your reply
But in my requirment the parameters are bound to change at runtime
so is not possible to pass the parameters to the report at runtime
if i want to execute the subscribed report through stored procedure
Daniel Bowlin
Daniel Bowlin
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4090 Visits: 2629
Then try passing your run time parameters to a database table, and make your subscription a data driven subscription that can read that table for the current parameters
philcart
philcart
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4106 Visits: 1436
Firstly, I'd ask what is behind the requirement to run the subscription using T-SQL? That really defeats the purpose of setting up the subscription in the first place. When you create a subscription you're saying "run this report, with these parameter values, at this time".

Using a data-driven subscription, you're making the parameter values dynamic, but you would still have the SQL Agent job running the subscription at the specified time.

If you disable the SQL Agent job and run the subscription yourself, you're saying "I don't want to run the report at the time I specified". You'd also have to make sure that the job stays disabled in case someone inadvertantly enables it.

Personally, I'd put some effort into running the reports programatically via the web service. That removes the subscription, its stored parameters and the associated SQL Agent job.

This article has an example of rendering a report via the web service and saving the results to a file,
http://msdn.microsoft.com/en-us/library/reportexecution2005.reportexecutionservice.render(v=SQL.100).aspx

Also, @Daniel Bowlin, saying "All SSRS subscriptions are SQL Server Agent Jobs" is not entirely correct. The SQL Agent job is purely the triggering mechanism for the subscription. All the job does is put the subscription ID into the EventData table in the ReportServer database. Once that is done the job is complete. The Reporting Services service polls that table to find the subscriptions that need to run.

Use this instead of linking directly to the sysjobschedules table and you avoid returning duplicate rows when the SQL Agent job has many schedules,

SELECT
[job_id]
,MIN(CASE
WHEN next_run_time > 0
THEN DATEADD(ss, (CAST(next_run_time/10000 AS INT)* 3600
+ (CAST(next_run_time/100 AS INT)%100)*60
+ (next_run_time%100))
, CAST(CAST(next_run_date AS VARCHAR(8)) AS DATETIME))
WHEN next_run_date > 0
THEN CAST(CAST(next_run_date AS VARCHAR(8)) AS DATETIME)
ELSE '1900-01-01'
END
) AS NextRunTime
FROM msdb.dbo.sysjobschedules
GROUP BY [job_id]



Hope this helps
Phill Carter
--------------------
Colt 45 - the original point and click interface

Australian SQL Server User Groups - My profile
Phills Philosophies
Murrumbeena Cricket Club
jfogel
jfogel
SSChasing Mays
SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)

Group: General Forum Members
Points: 647 Visits: 1168
philcart (7/6/2011)
Firstly, I'd ask what is behind the requirement to run the subscription using T-SQL? That really defeats the purpose of setting up the subscription in the first place. When you create a subscription you're saying "run this report, with these parameter values, at this time".


Lack of a version other than Standard is the most likely cause. If you have a single report that has to be run for 10-20 "groups" via a different value for a parameter you you find yourself in the position the OP is or was in. I'm facing the same thing and I don't want to write a web-based front end because we already have something like that to setup all the details about what the report should run for and where it should go.

Cheers
philcart
philcart
SSCarpal Tunnel
SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)SSCarpal Tunnel (4.1K reputation)

Group: General Forum Members
Points: 4106 Visits: 1436
jfogel (6/17/2013)
philcart (7/6/2011)
Firstly, I'd ask what is behind the requirement to run the subscription using T-SQL? That really defeats the purpose of setting up the subscription in the first place. When you create a subscription you're saying "run this report, with these parameter values, at this time".


Lack of a version other than Standard is the most likely cause. If you have a single report that has to be run for 10-20 "groups" via a different value for a parameter you you find yourself in the position the OP is or was in. I'm facing the same thing and I don't want to write a web-based front end because we already have something like that to setup all the details about what the report should run for and where it should go.


Rendering the reports via the web service isn't a "web-based front end". Generally it's a console application that calls the appropriate methods as shown in the example url I posted.

If your requirement is to render and distribute, not display, the reports, then the web service is what you should be using.

Hope this helps
Phill Carter
--------------------
Colt 45 - the original point and click interface

Australian SQL Server User Groups - My profile
Phills Philosophies
Murrumbeena Cricket Club
jfogel
jfogel
SSChasing Mays
SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)SSChasing Mays (647 reputation)

Group: General Forum Members
Points: 647 Visits: 1168
I'll check it out. Right now I'm thinking of a different method but I really don't want to close the door to other and possibly better options.

Cheers
meerack11
meerack11
Valued Member
Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)Valued Member (65 reputation)

Group: General Forum Members
Points: 65 Visits: 219
I have same requirement
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search