Subscriptions from Reporting Services get unintelligable job names in SQL Server Agent

  • I am running Reporting Services in SQL Server 2000.

    Is there any way of giving a subscription job a decent name, other than the automatic ED33F142-1F6B-4618-9B2F-7BD3FD63CC34 etc? Not exactly an easy name to remember, nor one which helps to identify which job does what. (You can rename Backup jobs with no problem).

    Having submitted several jobs for scheduled running from within Reporting Services, SQL Server Agent shows a list of coded Names. I don't seem to be able to give the job a recognisable name within the subscription. If I rename the job in SQL Server Agent to something recognisable, I end up with 2 jobs running when the schedule time appears - the original Reporting Services generated one reappears, and the one I've previously renamed runs as well . This would obviously be no good if it was an update job, or a report got sent.

    Any help would be appreciated...

  • It looks like the sqlagent job name is the guid actually used for the schedule stored within the database.  Since the app (i.e. RS itself) will be relying on this, you can't chnge this. 

    But, you could use a view like below to produce a quick reference of what each guid (sql agent job) is doing.   Note that because you're going directly against the app tables, these fields (types, names, relationships etc etc) could change in the future with no requirement on m$ft to inform anyone.  ie if you do a sp upgrade and this stops working, chances are they changed something

    SELECT     Schedule.ScheduleID AS SQLAgent_Job_Name, Subscriptions.Description AS sub_desc, Subscriptions.DeliveryExtension AS sub_delExt,

                          [Catalog].Name AS ReportName, [Catalog].Path AS ReportPath

    FROM         ReportSchedule INNER JOIN

                          Schedule ON ReportSchedule.ScheduleID = Schedule.ScheduleID INNER JOIN

                          Subscriptions ON ReportSchedule.SubscriptionID = Subscriptions.SubscriptionID INNER JOIN

                          [Catalog] ON ReportSchedule.ReportID = [Catalog].ItemID AND Subscriptions.Report_OID = [Catalog].ItemID

     

    cheers,

    Steve.

  • Thanks Steve. That view is perfect

    Perhaps a future release of RS may allow us to use the Subscription Description as the SQLAgent Job Name instead of that guid. I can't be the only one to moan....

    Cheers,

    Andrew

  • you could always post it to sqlwish (i think its sqlwish@microsoft.com).  Possible probs with this are that whoever is administering your sql may not have admin rights on your RS, so with guids they can't tell anything about the job and what it's for, with clear names they could.  Plus i guess the guid allows you to have schedules with the same name without creating jobs with the same name.

    Steve.

  • I've used that view - it's really helpful, thanks.

    However, it looks like the subscriptions.descriptions field only appears to give a description including the first email address on the 'to' list. Is there any way to get all of the email addresses returned including the 'cc' and 'bcc' addresses? where are they held as they don't seem to be in any of the tables?

  • If you look in the ExtensionSettings column of the Subscriptions table, there is an XML string that contains the relevant settings for the delivery extension. In this (email) case, there should be a To element with sub element of Value which contains the string of (semi-colon seperated) email addresses. With a little XML manipulation or perhaps even some regex (regular expressions) you could pull this out quite easily. You would probably want to look at the field DeliveryExtension and filter to ensure you're only looking at ReportServerEmail subscriptions.

    HTH,

    Steve.

  • Thanks for the input. All I can see in this field is "<long text>". I don't know anything about xml or regex, so I don't know how to get started with this at all. Can anyone help with more detail?

    Are there any applications available to help manage subscriptions? I'm using them more and more frequently.

  • Hi Paul,

    The following should work

    SELECT

    Schedule.ScheduleID AS SQLAgent_Job_Name,

    Subscriptions.Description AS sub_desc,

    Subscriptions.DeliveryExtension AS sub_delExt,

    [Catalog].Name AS ReportName,

    [Catalog].Path AS ReportPath,

    SUBSTRING(ExtensionSettings, LEN('TO') + CHARINDEX('TO', ExtensionSettings), CHARINDEX('', ExtensionSettings, CHARINDEX('TO', ExtensionSettings) + 1) - (LEN('TO') + CHARINDEX('TO', ExtensionSettings))) AS 'To Email recipient List'

    FROM

    ReportSchedule

    INNER JOINSchedule

    ON ReportSchedule.ScheduleID = Schedule.ScheduleID

    INNER JOINSubscriptions

    ON ReportSchedule.SubscriptionID = Subscriptions.SubscriptionID

    INNER JOIN[Catalog]

    ON ReportSchedule.ReportID = [Catalog].ItemID

    AND Subscriptions.Report_OID = [Catalog].ItemID

    WHERE

    Subscriptions.DeliveryExtension = 'Report Server Email'

    Note that this SQL has some assumptions:

    1. that the ExtensionSettings field (a text field) won't be longer than 8000 characters;

    2. that you're only interested in the 'To' email address, it doesn't look for 'CC' or 'BCC' but with some minor manipulation of the search you could add this.

    HTH,

    Steve.

  • Steve,

    Many thanks for your help with this. I'm getting an error message I don't undertsand though: "Invalid length parameter passed to the substring function". Can that be solved?

    Also, the 'CC' and 'BCC' fields would be very useful for me - many of my reports are CC'd to various recipients.

    Any further help greatly appreciated; I'm sure this must also be useful for some other Reporting Services 'amateurs' like me

    Cheers!

    Paul.

  • Yep, the quick reply (ie *not* using WYSIWYG) escapes out all the xml/html tags

    Here's another try, have included the CC and BCC.

     

    USE ReportServer

    GO

      SELECT    

     Schedule.ScheduleID AS SQLAgent_Job_Name,

     Subscriptions.Description AS sub_desc,

      Subscriptions.DeliveryExtension AS sub_delExt,

      [Catalog].Name AS ReportName,

      [Catalog].Path AS ReportPath,

     SUBSTRING(ExtensionSettings, LEN('<Name>TO</Name><Value>') + CHARINDEX('<Name>TO</Name><Value>', ExtensionSettings), CHARINDEX('</Value>', ExtensionSettings, CHARINDEX('<Name>TO</Name><Value>', ExtensionSettings) + 1) - (LEN('<Name>TO</Name><Value>') + CHARINDEX('<Name>TO</Name><Value>', ExtensionSettings))) AS 'To Email recipient List',

    CASE CHARINDEX('<Name>CC</Name><Value>', ExtensionSettings) WHEN 0 THEN

      ''

     ELSE

       SUBSTRING(ExtensionSettings, LEN('<Name>CC</Name><Value>') + CHARINDEX('<Name>CC</Name><Value>', ExtensionSettings), CHARINDEX('</Value>', ExtensionSettings, CHARINDEX('<Name>CC</Name><Value>', ExtensionSettings) + 1) - (LEN('<Name>CC</Name><Value>') + CHARINDEX('<Name>CC</Name><Value>', ExtensionSettings)))

    END AS 'CC Email recipient List',

    CASE CHARINDEX('<Name>BCC</Name><Value>', ExtensionSettings) WHEN 0 THEN

     ''

     ELSE

     SUBSTRING(ExtensionSettings, LEN('<Name>BCC</Name><Value>') + CHARINDEX('<Name>BCC</Name><Value>', ExtensionSettings), CHARINDEX('</Value>', ExtensionSettings, CHARINDEX('<Name>BCC</Name><Value>', ExtensionSettings) + 1) - (LEN('<Name>BCC</Name><Value>') + CHARINDEX('<Name>BCC</Name><Value>', ExtensionSettings)))

    END AS 'BCC Email recipient List'

    FROM        

      ReportSchedule

    INNER JOIN Schedule  ON   ReportSchedule.ScheduleID = Schedule.ScheduleID

    INNER JOIN Subscriptions  ON   ReportSchedule.SubscriptionID = Subscriptions.SubscriptionID

    INNER JOIN [Catalog]  ON   ReportSchedule.ReportID = [Catalog].ItemID

    AND Subscriptions.Report_OID = [Catalog].ItemID

    WHERE

      Subscriptions.DeliveryExtension = 'Report Server Email'

     

    Steve.

  • Steve,

    Thanks again for your help - you are a star!

    Couple of questions, forgive me, I'm still learning.

    If I copy and paste all of the above into the SQL pane to create a view I get a couple of messages back:

    First I got "The Query Designer does not support the USE ReportServer SQL construct." If I OK that I get "Line 1: Incorrect syntax near 'GO'"

    So I experimented and took out the "USE ReportServer

    GO" bit. I got another message saying SQL does not support the CASE construct - I've seen this before, I think, so ignored it. It returned the 8 fileds of data - yay! (I thought...)

    However, when I go to save my view I get "View definition includes no output columns or no items in the FROM clause". Bummer. So I fiddled a bit, putting "dbo." in front of all the from bits (as you had this in your previous statement). Still no luck... I notice that no daigram of tables links is created like in the previous example - presume this is related to the error message.

    Can you (or anyone) spare the time to help a bit more? Thanks again!

     

    Paul.

  • Hey Paul,

    You might want to try creating the view within Query Analyser, saves you from the graphical designer errors.  The first error was raised because the graphical designer doesn't require the USE DATABASE statement - you've already specified the DB because you were in one and selected 'create new view'.  The second error is as you guessed - the graphical designer doesn't support case statements graphically but it doesn't stop you from using them - you just don't get a 'picture' ofyour query (ie the tables and the joins aren't shown like in a straight select).

    THe last error is strange, every column has an alias in the query i posted, so i'm not sure how/where the columns lost their aliases.  You may want to take the entire script and paste it into query analyser.  To create the view, between tthe USE DATABASE ... GO statement and the start of the select, add the create view statement like CREATE VIEW vwMySnazzyView AS

    so a short version of creating the view to give you an idea of the entire structure read s like ->

    use database ReportServer

    go

    create view mySnazzyView AS

    select top 5 * from ReportSchedule

     

    Steve.

  • All sorted now, thanks Steve.

  • FYI: I just tried this on SSRS 2005 (no SP) and it still works. Saved me a ton of time, too!

    Thanks..

    ..jeremy.

  • I humbly submit this link to my article. This is one methiod that allows you to name and manage your subscriptions, as well as adding the ability to have Data Driven subscriptions.

     

    http://www.sqlservercentral.com/columnists/jselburg/2824.asp

    ______________________________________________________________________

    Personal Motto: Why push the envelope when you can just open it?

    If you follow the direction given HERE[/url] you'll likely increase the number and quality of responses you get to your question.

    Jason L. Selburg

Viewing 15 posts - 1 through 15 (of 29 total)

You must be logged in to reply to this topic. Login to reply