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


scheduling job


scheduling job

Author
Message
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Hi friends,

We need to monitor a user session for locks to troubleshoot a problem in the program. When the program is started we would like to schedule a job to check for the locks every 5 minutes and the output should be saved into a new text file for each run.. I use sql query to check the locks and I run this as T-SQL script in a scheduled job but every time the job runs output file is being overwritten.. not sure how to output the results into a new seperate text file when the job runs every 5 minutes...

Any help is greatly appreciated... Thanks a lot for all your help
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Below is the sql query I'm using to check the locks as a scheduled job to run every 5 minutes.. But I would need to create a new seperate output file for every run every 5 minutes..
BCP errors that the query is too long


SELECT
spid = Lock.request_session_id,
HostName = Session.host_name,
ProgramName = Session.program_name,
Cmd = Request.Command,
LoginName = Session.login_name,
dbid = Lock.resource_database_id,
DatabaseName = DB_NAME(Lock.resource_database_id),
Type = Lock.resource_type,
LockType = Lock.request_type,
Mode = Lock.request_mode,
Status = request_status,
UserTable.Name

FROM
sys.dm_tran_locks AS Lock

LEFT JOIN
sys.dm_exec_sessions AS Session ON
Session.session_id = Lock.request_session_id

LEFT JOIN
sys.dm_exec_requests AS Request ON
Request.session_id = Session.session_id

LEFT JOIN
sys.tables AS UserTable ON
UserTable.object_id = Lock.resource_associated_entity_id
AND
type = 'U'

WHERE
Lock.resource_type = 'OBJECT'
go



Please help.. thanks a lot
JeremyE
JeremyE
SSCarpal Tunnel
SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)SSCarpal Tunnel (4.3K reputation)

Group: General Forum Members
Points: 4250 Visits: 4057
Under the advanced tab for the job step where you specified the output file, there is a checkbox for "Append output to existing file". Without this box checked the output file will be overwritten each time.
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Hi Jeremy,

I do not want to append it the existing file either.. We would want a new seperate file created when the job runs every 5 minutes... not sure if it can be done may be with a time stamp included in the file name or if there is any other way to do this.. Also is it possible to output the result in a xls/csv format? Please help thanks again
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14839 Visits: 14396
You can use Agent Tokens in your log name.

Using Tokens in Job Steps- SQL Server 2008 R2

Change the log name to something like this:

X:\...path to log files...\filename_$(ESCAPE_NONE(STRTDT))_$(ESCAPE_NONE(STRTTM)).log

And you'll get a file name like this on each run:

filename_20130305_231247.log

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Thanks a lot. Using tokens worked
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14839 Visits: 14396
You're welcome. Thanks for the feedback.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Hi Friends,

Thanks for all the help so far.. Is there a way to schedule the job every 20 seconds? I see the default starts from 1 minute and up.. THanks again
Orlando Colamatteo
Orlando Colamatteo
SSChampion
SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)SSChampion (14K reputation)

Group: General Forum Members
Points: 14839 Visits: 14396
You can in 2008 and up, and maybe in later service packs of 2005, but in any case you may not want to do that. In 2005, and in some scenarios still in 2008 and up, queries issued by SQL Agent against msdb bloat the cache significantly. The more often you run jobs, the worse the problem becomes.

http://connect.microsoft.com/SQLServer/feedback/details/526485/dm-exec-cached-plans-bloat

Instead of only scheduling the job to run every 20 seconds, maybe it would be better to have the proc that does the checking use WAITFOR DELAY inside a loop to check the condition every 20 seconds allowing the job to run continuously. The proc would only take action when the condition was detected and would always loop back to the WAITFOR DELAY.

__________________________________________________________________________________________________
There are no special teachers of virtue, because virtue is taught by the whole community. --Plato
newbieuser
newbieuser
SSC Eights!
SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)SSC Eights! (831 reputation)

Group: General Forum Members
Points: 831 Visits: 915
Hi friends,

We have a scheduled job set to run every 4 seconds from the time the job is enabled. The below sql in the job runs and appends the results every 4 seconds in the output file. Once the program ends we disable the job.

Would like to know if this can be done in a stored procedure so that it can be called from the program itself and it can be easier to track down when the error occurs.. Please give me your suggestions



SELECT
spid = Lock.request_session_id,
HostName = Session.host_name,
ProgramName = Session.program_name,
Cmd = Request.Command,
LoginName = Session.login_name,
dbid = Lock.resource_database_id,
DatabaseName = DB_NAME(Lock.resource_database_id),
Type = Lock.resource_type,
LockType = Lock.request_type,
Mode = Lock.request_mode,
Status = request_status,
UserTable.Name

FROM
sys.dm_tran_locks AS Lock

LEFT JOIN
sys.dm_exec_sessions AS Session ON
Session.session_id = Lock.request_session_id

LEFT JOIN
sys.dm_exec_requests AS Request ON
Request.session_id = Session.session_id

LEFT JOIN
sys.tables AS UserTable ON
UserTable.object_id = Lock.resource_associated_entity_id
AND
type = 'U'

WHERE
Lock.resource_type = 'OBJECT'
go



Thanks a lot
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