kohera-logo-regular.svg

Using Azure Blob storage in SSRS reports

Attractive reports are not only showing the hard material statistics and numbers. Visualization of your data leads more and more to graphical decision making. One particular part of your reports are images for logo’s, product images etc. All this data and images were stored on-premise in the past. But when moving to the cloud, where do we need to store and find our data and images? How do we connect to it how do we use it?

New dashboards are made with powerBI, where you can connect to whatever kind of data stored on whatever kind of storage provider. You can embed pictures in your dashboard or get pointed to them by some URI you specify. But what do you do with existing SSRS reports? Do you convert them all to a powerBI dashboard? There are a lot of reasons why you will stay put on them in the current SSRS reporting serving for now, waiting to transform…

Next, I’ll explain what you can do when your data and images are transformed to the cloud.

Case description:

  • Azure SQL database containing application data
  • Azure blob-storage (hot or cold storage account) where all images are stored in a virtual directory
  • On-premise SSRS 2017 report server
  • Existing reports with logo’s and images used

Case purpose:

  • Use the same reports deployed to on-premise SSRS report in a HYBRID-cloud infrastructure solution
  • Using the images stored in Azure blob-storage on the report

Case solution:

1: Create SAS-token for your Blob-container:

In the azure portal, create a SAS token

This results in a long string, something like,
https://myaccount.blob.core.windows.net/sascontainer/sasblob.txt?sv=2015-04-05&st=2015-04-29T22%3A18%3A26Z&se=2015-04-30T02%3A23%3A26Z&sr=b&sp=rw&sip=168.1.5.60-168.1.5.70&spr=https&sig=Z%2FRHIX5Xcg0Mq2rqI3OlWTjEg2tYkboXr1P9ZUXDtkk%3D

2: Define external data source in your Azure SQL DB:

If not already done, create mater key:

CREATE MASTER KEY ENCRYPTION BY PASSWORD='****’;

Create database scoped credential: (use part from sas token beginning from ‘sv=…’)

create DATABASE SCOPED CREDENTIAL RW_hotblobcontainer
WITH IDENTITY = 'SHARED ACCESS SIGNATURE'
,SECRET='sv=********************************'
GO

Create external data source:

CREATE EXTERNAL DATA SOURCE HotBlobContainer WITH
(
TYPE = BLOB_STORAGE,
LOCATION = https://myaccount.blob.core.windows.net/sascontainer',
CREDENTIAL = RW_hotblobcontainer
)
GO

3: Define Azure SQL DB connection in your REPORT solution

 

4: Create shared or non-shared dataset for a get image byte stream data request

 

Stored procedure:

CREATE proc [SSRS].[up_GetLogoImage]
(@id int
)
as
begin
set nocount on;
/*grant
grant execute on [SSRS].[up_GetLogoImage] to [SSRS_user];
Grant ADMINISTER DATABASE BULK OPERATIONS TO [SSRS_user];
--*/
declare @SQLstmt nvarchar(max);
select top (1) @SQLstmt=N'select imagedocument.BulkColumn as BinaryData from openrowset(BULK '''+lofi.logoimagepath+''', DATA_SOURCE=''HotBlobContainer'', SINGLE_BLOB) as imagedocument;'
from dbo.vwLogoFiles lofi
where lofi.id=@id
;
declare @tblImageData TABLE(binarydata varbinary(max) );
begin TRY
insert into @tblImageData(binarydata)
exec sp_executesql @SQLstmt;
end TRY
begin CATCH
insert into @tblImageData(binarydata) values(NULL);
end CATCH
select top(1) binarydata from @tblImageData;
end
GO

 

The view vwLogoFiles contains:

CREATE VIEW [dbo].[vwLogoImages]
AS
SELECT baseT.[LogoImagePath]
FROM [dbo].[Establishment] as BaseT
;
GO

 

Result:

[LogoImagePath]='pathlevel1/pathlevel2/logo/squarelogo.png'

 

Resultset:

5: Create image object on the report

And that’s it.

The logo image is viewed on the report.

Enjoy…

Parameter sniffing solved with new Parameter Sensitive Plan Optimization feature

If you’re someone that works a lot with Microsoft SQL Server, there’s no doubt that you’ve had issues with an issue called “Parameter sniffing” before. Up until now, you had...

Creating maps with R and Power BI

The possibilities are infinite when it comes to creating custom visuals in Power BI. As long as you have creativity and knowledge about the right programming language, you can let...

Sending monitoring alerts through Telegram

What if you could get the ease of phone notifications for whatever monitoring alerts you need? Then we have a solution for you with the app Telegram. Some of you...

Send mails with Azure Elastic Database Jobs

The DatabaseMail feature in SQL Server and Managed Instance is widely used by many professionals. But what if you want a similar functionality in Azure SQL Database? There are options,...

Sorting matrices in Power BI

Recently I worked on a Power BI project for a client. They had a SharePoint site where they regularly published articles and wanted to pour view data into a report...

The world of data is evolving

The data landscape has changed dramatically over recent years. In the past, we mainly heard that we needed to do as much as possible “cloud-only”—but this trend has become more...