How To Schedule SQL Scripts On SQL Server Express Edition

By:   |   Updated: 2019-01-02   |   Comments (1)   |   Related: > Express Edition


Problem

You need to automate running some SQL, but the is you need to run it directly on an Express Edition of SQL Server that doesn't have the SQL Server Agent we know and love. How can you automate tasks for SQL Server Express?

Solution

PowerShell provides an easy way to script SQL tasks and the native Windows Task Scheduler, while not as capable as the SQL Server Agent will work quite nicely for us.

Example Query - Find Latest Backup for All Databases

For example, say we want to get an automated report of the last database backup for each database on a server automatically emailed in a format that can be opened with Excel. We'll start with a SQL query to gather the data, demonstrate three different ways to run the query with the Invoke-SqlCmd PowerShell cmdlet, redirect the output to a .csv file, email the .csv and finally run all of it against more than one SQL Servers.

This query from this blog will show us what we need. I've just added one field to show the server name which will come in handy later.

SELECT @@SERVERNAME AS ServerName, sdb.Name AS DatabaseName, COALESCE(CONVERT(VARCHAR(12), MAX(bus.backup_finish_date), 101),'-') AS LastBackUpTime
FROM sys.sysdatabases sdb
LEFT OUTER JOIN msdb.dbo.backupset bus ON bus.database_name = sdb.name
GROUP BY sdb.Name

Running it from SQL Server Management Studio (SSMS) shows a nice clean output like this:

query results

The next step is to call it with the PowerShell cmdlet Invoke-SqlCmd.

First example, we'll call the SQL query from the input file C:\scripts\GetLatestBackupDates.sql with the Invoke-SqlCmd -InputFile switch.

# pass sql script
$sqlserver = "JGAVIN-L\SQL2016"

Invoke-Sqlcmd -ServerInstance $sqlserver -Database msdb -InputFile "C:\scripts\GetLatestBackupDates.sql"

Second example, we'll call the SQL directly on the command line Invoke-SqlCmd -Query switch.

# call sql direct on command line
$sqlserver = "JGAVIN-L\SQL2016"

Invoke-Sqlcmd -ServerInstance $sqlserver -Database msdb -Query "SELECT sdb.Name AS DatabaseName, COALESCE(CONVERT(VARCHAR(12), MAX(bus.backup_finish_date), 101),'-') AS LastBackUpTime FROM sys.sysdatabases sdb LEFT OUTER JOIN msdb.dbo.backupset bus ON bus.database_name = sdb.name GROUP BY sdb.Name"

Third example, still using -Query but the SQL is declared in a PowerShell variable that is passed to it.

# declare sql in a variable and pass it to -Query switch
$sqlserver = "JGAVIN-L\SQL2016"

$sql="
SELECT sdb.Name AS DatabaseName,
COALESCE(CONVERT(VARCHAR(12), MAX(bus.backup_finish_date), 101),'-') AS LastBackUpTime
FROM sys.sysdatabases sdb
LEFT OUTER JOIN msdb.dbo.backupset bus ON bus.database_name = sdb.name
GROUP BY sdb.Name
"
Invoke-Sqlcmd -ServerInstance $sqlserver-Database msdb -Query $sql

Running each of these shows all three methods give us the same output.

powershell results

Email SQL Server Backup Query Results as an Attachment

Next, before we can email an attached file we must create it. The output is piped to a .csv with the Export-Csv, then attach it to an email and send it with Send-MailMessage. We'll stay with our third example to keep it more readable.

  1. Add variables to define a file name, mail server, email from and email to
  2. Pipe the output to a .csv thru the Export-Csv cmdlet
  3. Use the cmdlet Send-MailMessage to email it as an attachment
# declare sql in a variable and pass it to -Query switch
$sqlserver = "JGAVIN-L\SQL2016"

$outfile = "$env:TEMP\LastBackupTimes.csv" # name of file to email
$PSEmailServer = "smtp.domain.ext"         # mail server name
$emailfrom = "[email protected]"             # doesn't have to be real email, just in the form [email protected]
$emailto = "[email protected]"             

$sql="
SELECT sdb.Name AS DatabaseName,
COALESCE(CONVERT(VARCHAR(12), MAX(bus.backup_finish_date), 101),'-') AS LastBackUpTime
FROM sys.sysdatabases sdb
LEFT OUTER JOIN msdb.dbo.backupset bus ON bus.database_name = sdb.name
GROUP BY sdb.Name
"
# delete old out file if it exists
If (Test-Path "$outfile"){Remove-Item "$outfile"}

# run sql and export to .csv
Invoke-Sqlcmd -ServerInstance $sqlserver -Database msdb -Query $sql | Export-Csv $outfile -NoTypeInformation

# email report file
Send-MailMessage -To $emailto -From "$emailfrom" -Subject "Latest Backup Dates" -Attachments $outfile

Before we schedule it let's make it a little more useful by adding the capability to run this on more than one SQL Server. We just need to do a couple of more things.

  1. Change the $sqlserver variable to an array called $sqlservers and enter the SQL Server names to it quoted and comma separated
  2. Add a -Append to the Export-Csv so we don't overwrite the file
  3. Save the script as GetLatestBackupDates.ps1
# declare sql in a variable, pass it to -Query switch, export to .csv and send as mail attachment
Param ([array]  $sqlservers = @("JGAVIN-L\SQL2016","JGAVIN-L\SQL2017")) 
$outfile = "$env:TEMP\LastBackupTimes.csv" # name of file to email
$PSEmailServer = "smtp.domain.ext"    # mail server name
$emailfrom = "[email protected]"             # doesn't have to be real email, just in the form [email protected]
$emailto = "[email protected]"

$sql="
SELECT @@SERVERNAME AS ServerName, sdb.Name AS DatabaseName, COALESCE(CONVERT(VARCHAR(12), MAX(bus.backup_finish_date), 101),'-') AS LastBackUpTime
FROM sys.sysdatabases sdb
LEFT OUTER JOIN msdb.dbo.backupset bus ON bus.database_name = sdb.name
GROUP BY sdb.Name
"

# delete old out file if it exists
If (Test-Path "$outfile"){Remove-Item "$outfile"}

# run sql and export to .csv
Foreach ($sqlserver in $sqlservers) 
{
Invoke-Sqlcmd -ServerInstance $sqlserver -Database msdb -Query $sql | Export-Csv $outfile -NoTypeInformation -Append #
}

# email report file
Send-MailMessage -To $emailto -From "$emailfrom" -Subject "Latest Backup Dates" -Attachments $outfile

And here is the Excel file that we will email.

excel file contents

Schedule Task Scheduler Job for SQL Server Express

Finally, we can get to the point of this tip and automate the task without SQL Server Agent with Windows Task Scheduler.

Open Windows Task Scheduler

  1. Actions
  2. Create Basic Task
task scheduler
  1. Name task
  2. Document the jobs purpose
  3. Click Next
task scheduler
  1. Choose Trigger
  2. Click Next
task scheduler
  1. Start date
  2. Start time
  3. Frequency
  4. Click Next
task scheduler
  1. Click Next
task scheduler
  1. Enter the script command (using correct file location): powershell.exe -File C:\scripts\GetLatestBackupDates.ps1
  2. Click Yes
  3. Click Next
task scheduler
  1. Change User or Group…
  2. Search for service account to that will run job
  3. Select ‘Run whether user is logged on or not' radio button
  4. Click OK
task scheduler

Right click on the job and click Run.

task scheduler

When status goes to Ready (may have to hit F5 to refresh) make sure the "Last Run Result" is "The operation completed successfully" and verify you received the emailed attachment.

task scheduler

Summary

To review, we've seen three ways to call SQL from PowerShell, direct the output to a .csv file, run it against more than one SQL Server, email the .csv as an attachment and automate it without SQL Server Agent.

There are several other uses for the PowerShell, Invoke-SqlCmd cmdlet.

Next Steps


sql server categories

sql server webinars

subscribe to mssqltips

sql server tutorials

sql server white papers

next tip



About the author
MSSQLTips author Joe Gavin Joe Gavin is from the Greater Boston area. He started working with SQL Server and Sybase in 1998 in the financial services industry and has been a SQL Server Database Administrator for a dairy cooperative since 2011. He graduated from Northeastern University in Boston with a Bachelor of Science in Engineering Technology (BSET) degree in Computer Technology. Joe has spoken at the Boston and Providence SQL Saturday events.

This author pledges the content of this article is based on professional experience and not AI generated.

View all my tips


Article Last Updated: 2019-01-02

Comments For This Article




Thursday, September 3, 2020 - 7:19:44 PM - Sir Poon Back To Top (86411)
This article missing a critical piece of information: The account that runs the scheduled task MUST have the Log On as a Batch permission in the local policy. Otherwise, the task will fire but not succeed.














get free sql tips
agree to terms