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 ««12

Only send DBMail when query results are present Expand / Collapse
Author
Message
Posted Thursday, November 28, 2013 4:15 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, November 24, 2014 10:45 PM
Points: 2, Visits: 29
I had been struggling with this ...Exactly what i was looking for...Thanks a ton Adu Dina ..
Post #1518316
Posted Friday, November 29, 2013 8:41 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Yesterday @ 8:51 PM
Points: 35,606, Visits: 32,190
sqlrd22 (10/15/2012)
Abu Dina (10/15/2012)
Okay so something like the below might work for you:


IF (select count(*) from [e009]) > 0
begin

exec msdb.dbo.sp_send_dbmail
@profile_name = 'Default',
@recipients = 'me@example.com',
@subject = 'warning',
@query = 'select * from [e009]',
@attach_query_result_as_file = 1,
@query_attachment_filename = 'warning.csv'

end



Thanks, this will be hard to test as I have no control over whether the data comes in or not as it is sent into our database by an external source and this type of data only comes in when there is something wrong (hence the name warning) but I'll try it out.


There's a small tweek that I'd make to that. As written above, both the COUNT(*) and the @query each make a table scan of the e009 table (or view). While I do understand that there's usually nothing in the table/view and that it runs only twice a day and there's not much in the table/view when it actually contains something, there's no need for any extra reads/cpu time on the system if you can avoid them. It also helps folks that look for code for their particular different problem.

With that thought in mind, if you change the IF in Abu Dina's good code to just check for the presence of at least 1 row, you accomplish the same thing but with fewer reads/cpu time.
IF EXISTS(SELECT TOP 1 1 FROM [e009])
begin

exec msdb.dbo.sp_send_dbmail
@profile_name = 'Default',
@recipients = 'me@example.com',
@subject = 'warning',
@query = 'select * from [e009]',
@attach_query_result_as_file = 1,
@query_attachment_filename = 'warning.csv'

end



--Jeff Moden
"RBAR is pronounced "ree-bar" and is a "Modenism" for "Row-By-Agonizing-Row".

First step towards the paradigm shift of writing Set Based code:
Stop thinking about what you want to do to a row... think, instead, of what you want to do to a column."

(play on words) "Just because you CAN do something in T-SQL, doesn't mean you SHOULDN'T." --22 Aug 2013

Helpful Links:
How to post code problems
How to post performance problems
Post #1518563
Posted Monday, October 27, 2014 2:18 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, November 4, 2014 11:52 AM
Points: 3, Visits: 39
That solution works fine.

But I have the following error message:
Message
Executed as user: MYDOMAIN\MYUSER.
NbError: 631
[SQLSTATE 01000] (Message 0) File attachment or query results size exceeds allowable value of 1000000 bytes.
[SQLSTATE 42000] (Error 22050). The step failed.


How would you look if the query result is exceeding the maximum?
Post #1628904
Posted Tuesday, October 28, 2014 2:20 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Saturday, November 22, 2014 7:46 PM
Points: 3,220, Visits: 2,361
you'll need to up the attachment size in your database main configuration.

exec msdb.dbo.sysmail_configure_sp 'MaxFileSize', '10000000'




Regards
Rudy Komacsar
Senior Database Administrator

"Ave Caesar! - Morituri te salutamus."
Post #1629310
Posted Wednesday, October 29, 2014 12:19 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, November 4, 2014 11:52 AM
Points: 3, Visits: 39
That's exactly what I don't want to do.

Is there a way to leave it like that, and check if the query result is too big and take only the top X rows?
Post #1629618
Posted Wednesday, October 29, 2014 1:02 PM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Yesterday @ 3:22 PM
Points: 374, Visits: 1,222
Not that I know of, but if you're cool with losing data from the result set you can just pick a top X row count you know won't exceed the limit.

Or export the file to someplace on a shared drive and just distribute a link to it.
Post #1629631
Posted Wednesday, October 29, 2014 1:29 PM
Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Saturday, November 22, 2014 7:46 PM
Points: 3,220, Visits: 2,361
Try this:


declare @max_attachment_size int, -- in bytes
@average_rowsize int, -- in bytes
@number_of_rows int, -- used for the TOP in the dynamic select
@dynamic_select varchar(8000) -- dynamic select statement

select @max_attachment_size=paramvalue
from msdb.dbo.sysmail_configuration
where paramname = 'MaxFileSize'

select @average_rowsize=used_page_count*1024/row_count
from sys.dm_db_partition_stats
where object_id=object_id('sysmaintplan_log')

select @number_of_rows=@max_attachment_size/@average_rowsize

IF EXISTS(SELECT TOP 1 1 FROM [e009])
begin

select @dynamic_select='select top ' + convert(varchar(16),@number_of_rows) + ' * from [e009]'

exec msdb.dbo.sp_send_dbmail
@profile_name = 'Default',
@recipients = 'me@example.com',
@subject = 'warning',
@query = @dynamic_select,
@attach_query_result_as_file = 1,
@query_attachment_filename = 'warning.csv'

end




Regards
Rudy Komacsar
Senior Database Administrator

"Ave Caesar! - Morituri te salutamus."
Post #1629640
« Prev Topic | Next Topic »

Add to briefcase ««12

Permissions Expand / Collapse