SSISDB Bug: Package Parameter Mapping

I have recently posted a new SSISDB bug at Microsoft Connect relating to Package Parameter mapping.  Running an SSIS project where the previous deployed version had an issue with the mapping of child package parameter, will carry forward the issue to the future deployed versions (even though it has been remapped properly in the future versions).

The unexpected error message will look like this:

Call Child Package:Error: Error 0×80131500 while executing package from project reference package “Child.dtsx”. There is no appropriate variable in the current environment to map to the parameter “paramChild”..

After a bit of investigation, it seems that the underlying stored procedure is looking at package parameters (mapped or unmapped) of all deployed versions of the project. Meaning that:

  1. If you accidentally delete an environment variable that was previously mapped to a previous version, any deployed SSIS project version will fail.
  2. If your previous version had incorrect mapping and failed, the current and future deployed versions will always fail, unless you deploy a change to ensure the previous version will run properly.
SSMS Integration Services Project Versions Dialog Box

Project Versions Dialog Box in SSMS

Workarounds

I have come up with a couple of workarounds, should you face a similar scenario (unless this issue is fixed in the future).

Workaround #1

1. Revert back to the old SSIS project version that is having the issue, and fix the mapping of the child package to the environment variable.

2. Repeat the above step for all SSIS projects that may have the issue.

3. Revert back to the latest version of SSIS project.

Caveat: if the variable is deleted from the environment for a reason, this needs to be kept instead; for the sake of rectifying the issue with older versions of the project AND to retain the history of older versions. This will make it harder for administering and managing SSIS project deployment and maintenance.

 

Workaround #2

1. Abandon / delete the SSIS project that is having issue.

2. Redeploy the project with the same name, and reconfigure the child package parameter to the environment variable properly.

Drawback: History of the SSIS project versions is not retained in the Integration Services Catalog.

 

Permanently Fixing This Bug

I think this is a real problem that most people will run into. Unless the solution is “don’t use package parameter” – which is not ideal – this problem should be fixed.

How?

Well, first, Microsoft SSIS team should hire me so I can help fixing it! ;) Or, you could just vote for the bug at Microsoft Connect here, and wait until it gets fixed.

In the mean time, I have come up with an alternative solution which I have to put a strong disclaimer so you should use this at your own risk. I will not be responsible if you deploy this in production. Here are the steps to permanently fix the issue:

1. Create a backup of your SSISDB.internal.get_project_parameter_values by scripting it out from the SSISDB database. Save this as a file somewhere safe.

2. Open my version of SSISDB.internal.get_project_parameter_values.

3. Comment out the CREATE PROCEDURE line.

4. Uncomment the ALTER PROCEDURE.

(Step 3 and 4 are deliberately put in place here, so you won’t accidentally overwrite the original stored procedure).

 

Wrap Up

Package parameter that is to be mapped to an environment variable should be use with caution. Deleting an environment variable that is mapped to a previous deployed version and running the properly mapped parameter of a new version will cause an unexpected error “There is no appropriate variable in the current environment to map to the parameter”. I have stated a number of workarounds above, please use them wisely. The fix that I have proposed on altering internal.get_project_parameter_values is not 100% tested and should only be used in development environment.

To have this bug fixed properly, please vote at Microsoft Connect site.

Comments and feedbacks are welcomed!

Hybrid Mode in Tabular BI Semantic Model – Part 1

During my presentation on “DirectQuery vs Vertipaq Modes in SSAS Tabular Model” at PASS BI/DW VC and SQL Rally in Dallas this year, I briefly explained the Hybrid Mode in Tabular BI Semantic Model (BISM). I would like to discuss Hybrid Mode further in two parts. Here is the first part, which contains a basic walkthrough of Hybrid Mode in Tabular BISM.

On a side note, DirectQuery vs Vertipaq Modes in SSAS Tabular Model slide deck can be downloaded from here: http://www.mssqlgirl.com/slide-deck-directquery-vs-vertipaq-for-pass-dwbi-vc.html

 

Introduction

The default mode of SSAS Tabular Model is the In-Memory (also known as Vertipaq Mode), where the data from various types of data source are processed and loaded into the in-memory Tabular databases. Any queries executed on the Tabular database will be served based on the data in Memory (cache). Due to the state of the art compression algorithm and multi-threaded query processors, the xVelocity in-memory analytics engine can provide fast access to the tabular model objects and data. In-Memory mode supports both DAX and MDX query types.

Another mode available for SSAS Tabular Model is DirectQuery. DirectQuery translates all DAX queries at run time to SQL statements, allowing real time access to the SQL Server source database. Unlike the In-Memory mode, DirectQuery only works with one SQL Server data source. The main advantage of using DirectQuery is the real time access and scalability. This comes with a price of restrictions on a number of DAX functions and missing Calculated Column feature. Only client tools that issues DAX queries can access Tabular Model with DirectQuery mode.

Hybrid Mode combines the design aspect of DirectQuery and Client Tool flexibility of In-Memory. Essentially, Tabular Database Model with Hybrid Mode is designed/developed with DirectQuery enabled, and is published with both DirectQuery access mode and In-Memory access mode. When published, the metadata is deployed and data will be processed into memory for the InMemory access. Hence, Hybrid Mode also requires processing mechanism of In-Memory and also supports both In-Memory partition type and DirectQuery partition type.

Querying in Hybrid Mode

There are two options of querying a Tabular database with Hybrid mode enabled.

The following diagram shows how Hybrid Mode can serve DAX issuing client tools (PowerView, SSRS) and MDX issuing client tools (Excel, Tableau, SSRS).

SSAS_Tabular_Hybrid Mode_Query Flow

 

When a client tool issues a DAX query via the DirectQuery access mode, the DAX query is passed and then converted into an equivalent SQL query that accesses the source SQL Server database directly. The result returned to the DAX issuing client tool will be straight from the source SQL Server data source.

When executing an MDX query via In-Memory access mode, the query is served from the cache (the tabular database). There is no conversion and the results returned to the MDX issuing client tool will be based on the data that is in the cache.

Note: PowerView is a DAX issuing client tool that can work with both DirectQuery and In-Memory. If the primary/default Query Mode of a hybrid Tabular database is DirectQuery, the result is served straight from the source SQL Server data source. If the primary/default mode is In-Memory, the result is served from the cache. More about the two hybrid modes this later.

 

Enabling Hybrid Mode – the Basics

1. Design phase

When creating a Tabular Model solution using SSDT, ensure that DirectQueryMode value is set to On. This will ensure that the solution will conform to DirectQuery design features.

Model.bim Properties on SSDT

Enable DirectQueryMode on tabular model via SSDT

2. Deployment phase

Prior to deploying the solution, change the Query Mode to “In-Memory with DirectQuery” or “DirectQuery with In-Memory”. These are the two available Hybrid modes.

Project Properties of Tabular Model in SSDT

Change Query Mode of Tabular Project in SSDT

 

 

Query Mode: In-Memory with DirectQuery

In-Memory with DirectQuery option means that In-Memory is the primary (or default) connection. Howevever, when needed and if the client tool supports this, the secondary Query Mode, i.e DirectQuery, can be used instead.

This query mode is ideal for the following scenarios

  1. Users are mainly using Excel to perform analysis on the tabular model.
  2. The processed data in memory will be used to serve Excel queries.
  3. The processed data in memory will be used to serve PowerView report.
  4. Only occasional real-time queries required for accessing the real time data, using SSRS as an example.

Query Mode: DirectQuery with In-Memory

DirectQuery with In-Memory option means that DirectQuery is the primary (or default) connection. Howevever, when needed and if the client tool supports this, the secondary Query Mode, i.e In-Memory, can be used instead.

This query mode is ideal for the following scenarios

  1. Users are mainly using PowerView (or DAX issuing Client Tool) to perform analysis on the tabular model.
  2. By default, always returns real time data.
  3. Only occasional processed in memory data is required to be retrieved from Excel.

 

Connecting to Hybrid Mode tabular database

Connecting to a tabular database with Hybrid Mode is the same as connecting to either InMemory or DirectQuery – that is, if you would like to use the primary mode. For example, if a tabular database is published with Query Mode of “DirectQuery with In-Memory”, the default connection via a client tool will always be made through to the DirectQuery, with no extra steps required. Similarly, if the Query Mode is “In-Memory with DirectQuery”, the default connection will use the In-Memory.

When using “DirectQuery with In-Memory” Query Mode, a client tool can connect to the tabular database using the In-Memory mode, by specifying it in the connection. Below is an example for connecting via SQL Server Management Studio, to the In-Memory part to a tabular database that has been published with “DirectQuery with In-Memory” .

SQL Server Management Studio Additional Connection Parameters

Specify "DirectQueryMode" parameter in SSMS

 

Below is a sample of specifying the DirectQueryMode in Excel:

Excel Connection String Dialog Box

Specifying DirectQueryMode in Excel Connection String Property

 

Note: As at the time of writing, the DirectQueryMode connection property cannot be specified on PowerView. So, PowerView will use the primary (default) of the Hybrid Mode of the tabular database.

Wrap Up

Above is the basic walk-through of Hybrid Mode in SSAS Tabular. Hybrid Mode Tabular Databases come in two Query Modes, “DirectQuery with In-Memory” or “In-Memory with DirectQuery”. The first Query Mode in the name is the “primary” Query Mode of the tabular database. Tabular databases with Hybrid mode are designed in DirectQuery, but published with either of the two Query Modes.  Some client tools provide the option to switch to the secondary Query Mode by specifying “DirectQueryMode” connection parameter.

Stay tuned for Part 2 of this series for more information on the design tips and important factors to consider when implementing Tabular solution with Hybrid Mode.


Process Full on Tabular Model Database via SSMS

The past few months I have been working with SSAS Tabular Model introduced in SQL Server 2012. Generally, I automate my Tabular Model Processing using XMLA via SQL Server job. However, I have recently come across SQL Server Management Studio (SSMS) bug whereby performing “Process Full” on the Tabular Model database would incorrectly show “Process Recalc” instead . If it did, the data in tabular model would not be as expected. The underlying behaviour however seems to be correct.

Steps To Reproduce The Issue

I run Process Full on Tabular Model database, by Right clicking on the tabular model database in SSMS, and choose “Process Database” as shown below.

Process Database Menu Item

This brings up the “Process Database” dialog box, which I then choose ”Process Full” on the Mode drop down list as illustrated below.

Process Database dialog box in SSMS

Choose Process Full mode

The “Data Processing” dialog box will appear showing the progress. Once it’s finished you can click on the “Details” link which will show “Processing Details” with an unexpected “Type” in the Process XMLA command.

Data Processing Dialog Box

Data Processing Dialog Box

Processing Details dialog box showing ProcessRecalc instead of ProcessFull

Processing Details showing ProcessRecalc instead of ProcessFull

The Underlying Behaviour

Process Full and Process Recalc on Tabular Model database are different. As mentioned by Cathy Dumas in “Processing tabular models 101” on her MSDN blog:

Process Full Loads data into all selected partitions or tables. Any affected calculated columns, relationships, user hierarchies, or internal engine structures (except table dictionaries) are recalculated.
Process Recalc For all tables in the database, recalculates calculated columns,  rebuilds relationships. rebuilds user hierarchies, and rebuilds other internal engine structures. Table dictionaries are not affected.

This means that if the data is modified in the source database(s), Process Recalc will not be getting this modified data. Process Full, on the other hand, will.

Not convinced that invoking Process Full on the Tabular Model database via SSMS would indeed invoke Process Recalc as shown on the dialog box, I decided to run SQL Profiler.

According to SQL Profiler – on Line 61 or so on my trace – I noticed that the Command executed looks as follows.

The XMLA command looks like below (copied and pasted to Notepad):

After running a couple of tests, it seems that the Process Full on Database via SSMS in SQL Server 2012 RTM version, does actually perform Process Full despite reporting it as Process Recalc. My tabular model database is refreshed with the new data.

Related Posts

Looking at Microsoft Connect after I encountered this issue, there was a fairly old post that was not directly reporting this issue. However, in the response, Cathy Dumas mentioned that she found the above bug in a SQL Server 2012 version pre RTM. Check her comment in this link below.

https://connect.microsoft.com/SQLServer/feedback/details/685325/processing-ssas-in-tabular-mode-not-refreshing-data#details

Wrap Up

SQL Server Management Studio User Interface invokes Process Full properly on the Tabular Model database in SQL Server 2012 RTM version despite the misleading “Process Recalc” info on the Details. This is confirmed by using SQL Profiler and checking the outcome of the Process Database execution. When in doubt, always inspect the underlying behaviour.

 

 

Retrieving SQL Server 2012 Evaluation Period Expiry Date

SQL Server 2012 RTM Evaluation edition was made available on March 7, 2012. Some of us may have installed this on the date or later for evaluation, some of us may still be using the RC0 or an even an earlier version of SQL Server 2012. If you have SQL Server 2012 currently installed, have not purchased and installed the licensed key, the evaluation period may have expired or will be very soon. To avoid nasty surprises, it is a good idea to plan ahead and make a note of the expiry date of the evaluation period.

 

SQL Server 2012 Evaluation Period has expired

 

There are a number of ways to retrieve SQL Server 2012 Evaluation Period Expiry Date. In SQL Server 2012, the evaluation expiry date is not listed on the About dialog box of SQL Server Management Studio any more unlike previous versions.

 

SQL Server 2012 SSMS About Dailog Box

SQL Server Management Studio Dialog Box does not show Evaluation Expiry Date

 

The Evaluation period is 180 days, which we can calculate if we know the installation date. The three options of determining Evaluation Expiry Date are:

  • Running a simple T-SQL query
  • Inspecting Summary.txt in the installation log directory
  • Inspecting RegEdit configuration

 

Option 1: Running a simple T-SQL query

Run the following query to retrieve the installed and expiry date on an Evaluation edition of SQL Server 2012 instance.

SELECT
	create_date AS 'SQL Server Install Date',
	DATEADD(DD, 180, create_date) AS 'SQL Server Expiry Date'
FROM sys.server_principals
WHERE name = 'NT AUTHORITY\SYSTEM'

“NT AUTHORITY\SYSTEM” account on the database server is a Local System Account and by default gets created at the time of installation. Therefore we can rely on inspecting its creation date to safely determine the installation date of SQL Server.

See more definition of “NT AUTHORITY\SYSTEM” account here: http://msdn.microsoft.com/en-us/library/ms191543.aspx

Note: to check if you are running Evaluation edition, you can do this simply by checking the SQL Server database instance properties via SQL Server Management Studio (SSMS) as shown below.

SQL Server 2012 Database Server Properties

The following query will also return the Product Version, Product Level and Edition.

SELECT
	SERVERPROPERTY('ProductVersion') AS ProductVersion,
	SERVERPROPERTY('ProductLevel') AS ProductLevel,
	SERVERPROPERTY('Edition') AS Edition;
GO

 

Option 2: Inspecting Summary.txt

When SQL Server 2012 instance is installed, a Summary.txt file is created. This file is typically located at “C:\Program Files\Microsoft SQL Server\110\Setup Bootstrap\LOG\Summary.txt“.

Summary.txt contains important values pertaining to the instance installation, including the version being installed and when it is being installed. The Evaluation edition is valid for 180 days, so with simple arithmetic on the install date, we can determine the expiry date as exhibited below.

Summary.txt

In the above example, The install date is on 29 April 2012, so the expiry date is 26 October 2012 (180 days + 29 April 2012).

Option 3: Inspecting REGEDIT

  1. Open REGEDIT and navigate the following structure:
    HKEY_LOCAL_MACHINE\SOFTWARE\Microsoft\Windows\CurrentVersion\Installer\UserData\S-1-5-18\Products
  2. Here you will see a long list of folders in form of a sequence of alphanumeric characters (GUID). Ensure the “Products” folder is highlighted/selected.
  3. From the Edit menu, click Find and type in “SQL Server 2012 Database Engine Services”. Clicking “Find Next” will open the [GUID] > InstallProperties folder which should look like this:

InstallProperties of SQL Server 2012 Database Engine Services

The InstallDate lists the date of installation in YYYYMMDD format, i.e. in this example, it is 29 April 2012. The expiry date for this instance is 180 days from the install date, which is 26 October 2012.

 

I hope this post has been useful for you. If there are other ways that you can think of, please don’t hesitate to let me know by leaving a comment.

 

Other related posts on SQL Server Evaluation Period Expiry Date:

Edit (June 4th, 2012):

On a side note, if you are using Evaluation edition for development purposes, it would be best to upgrade this instance to the Developer edition of SQL Server 2012. More information about the Developer edition and other license information on SQL Server 2012, please visit: http://www.microsoft.com/sqlserver/en/us/get-sql-server/how-to-buy.aspx