Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase 123»»»

Subscriptions from Reporting Services get unintelligable job names in SQL Server Agent Expand / Collapse
Author
Message
Posted Friday, January 27, 2006 3:45 AM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, December 17, 2013 10:10 AM
Points: 16, Visits: 32

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...

Post #254010
Posted Saturday, January 28, 2006 6:03 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: Moderators
Last Login: Wednesday, October 22, 2014 10:02 AM
Points: 1,824, Visits: 3,497

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.
Post #254276
Posted Saturday, January 28, 2006 1:56 PM
Grasshopper

GrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopperGrasshopper

Group: General Forum Members
Last Login: Tuesday, December 17, 2013 10:10 AM
Points: 16, Visits: 32

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

Post #254287
Posted Sunday, January 29, 2006 8:49 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: Moderators
Last Login: Wednesday, October 22, 2014 10:02 AM
Points: 1,824, Visits: 3,497
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.
Post #254315
Posted Thursday, March 23, 2006 8:58 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, February 7, 2014 5:35 AM
Points: 51, Visits: 103

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?

Post #267942
Posted Thursday, March 23, 2006 4:08 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: Moderators
Last Login: Wednesday, October 22, 2014 10:02 AM
Points: 1,824, Visits: 3,497
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.
Post #268093
Posted Friday, March 24, 2006 2:58 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, February 7, 2014 5:35 AM
Points: 51, Visits: 103

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.

Post #268151
Posted Sunday, March 26, 2006 6:50 PM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: Moderators
Last Login: Wednesday, October 22, 2014 10:02 AM
Points: 1,824, Visits: 3,497
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 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'



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.
Post #268500
Posted Monday, March 27, 2006 3:23 AM
Valued Member

Valued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued MemberValued Member

Group: General Forum Members
Last Login: Friday, February 7, 2014 5:35 AM
Points: 51, Visits: 103

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.

Post #268549
Posted Wednesday, March 29, 2006 3:49 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: Moderators
Last Login: Wednesday, October 22, 2014 10:02 AM
Points: 1,824, Visits: 3,497

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.
Post #269302
« Prev Topic | Next Topic »

Add to briefcase 123»»»

Permissions Expand / Collapse