Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Only send DBMail when query results are present


Only send DBMail when query results are present

Author
Message
namrata773
namrata773
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 38
I had been struggling with this ...Exactly what i was looking for...Thanks a ton Adu Dina .. :-)
Jeff Moden
Jeff Moden
SSC-Forever
SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)SSC-Forever (45K reputation)

Group: General Forum Members
Points: 45398 Visits: 39942
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.
Although they tell us that they want it real bad, our primary goal is to ensure that we dont actually give it to them that way.
Although change is inevitable, change for the better is not.
Just because you can do something in PowerShell, doesnt mean you should. Wink

Helpful Links:
How to post code problems
How to post performance problems
Forum FAQs
bprov
bprov
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 40
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?
Rudyx - the Doctor
Rudyx - the Doctor
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3290 Visits: 2476
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."
bprov
bprov
Forum Newbie
Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)Forum Newbie (3 reputation)

Group: General Forum Members
Points: 3 Visits: 40
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?
ZZartin
ZZartin
Ten Centuries
Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)Ten Centuries (1.4K reputation)

Group: General Forum Members
Points: 1423 Visits: 7487
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.
Rudyx - the Doctor
Rudyx - the Doctor
Hall of Fame
Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)Hall of Fame (3.3K reputation)

Group: General Forum Members
Points: 3290 Visits: 2476
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."
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