Monthly Archives: April 2017

Exporting Power Query tables to SQL Server

Power Query is a great tool for data mashup, however when it comes to really show its powers as a desktop ETL tool, you realise that no matter how powerful at E an T it is, the L is falling behind, as you can only load the data into the embedded tabular data model that comes with Power BI.

Ignoring R, local cubes and HTTP POST requests, I wanted to showcase a few other methods for exporting data from Power Query and loading it to SQL Server.

The logic I follow is very simple — because there is no obvious limitation to the type of queries you can run against OleDb or ADO.NET datasets — a SELECT query will be executed with same success as an INSERT query.

As a prerequisite, on the SQL Server side I’ve created a table which I populate initially with single records, then with 1M records.

OleDb

Following the logic described above, inserting a single entry into Demo table via OleDb looks fairly trivial.

However if you try to follow this approach you’ll soon notice that in addition to fiddling around with Text.Format to get your INSERT statement righ, you will also have to approve each parameter variation from your SQL statement. Which makes this approach unfeasible unless you construct your INSERT statement to include all of the millions of records in a single string.

ADO.NET

On the other hand an ADO.NET connection wrapped in a Value.NativeQuery function provides a more familiar approach to performing data INSERT. This method has the convenience of passing query parameters as a record or list inside the SQL statement. As a result you need to approve the firewall rule for the SQL query only once.

Changing the scale

The methods I’ve described so far work reasonably well for times when you need to insert a few hundred records in a SQL table. However when the problem explodes to millions of rows, you need to do some prep work before sending over all of that data. I’ll detail 3 techniques for exporting datasets with millions of records: Table Valued Parameters, XML and JSON.

As an example I use a 1M records table I generate from a list with an incremental sequence Key and GUID generated Value field. Table dummy.

TVP

When doing bulk inserts in ADO.NET, the most recommended approach is to use a Table Valued Parameter to send data to a Stored Procedure which performs the INSERT. As a prerequisite on SQL Server side I had to add a table type and a stored procedure that accepts this table type as a READONLY parameter.

Although sending a TVP into an SP is a straightforward task in .NET, it requires casting the data reader (table) to a SqlDbType.Structured data type. 

I wanted to rely on Power Query internal data type conversion and sent a table as a parameter to my newly created SP. Needless to say I was greeted with the error below


After giving up on the idea of casting a Power Query table into a SQL Structured data type, I’ve decided to replicate the internal call during of an  exec SP with @TVP. Thus I’ve built a rather lengthy 1002 row SQL statement that declares an internal table, inserts all the records from the dummy table and calls the SP with internal table as a parameter.

XML

Back in the days when XML was still cool, sending some tabular data to SQL Server was the matter of serializing a recordset into an XML document and sending it to a stored procedure that parsed it back into a recordset. Nothing has changed since on the SQL Server side.

Since Power Query lacks any functions for constructing XML documents, I found it very difficult to come up with an approach for building binary XML documents that performs on par to JSON serialization. I’ve tried various combinations of looping through the records of a table via List.Generate and List.Accumulate, nevertheless Table.TransformRows and avoiding making any calls to Text.Format seemed to deliver best performance.

On calling Value.NativeQuery, Power Query converts the binary string into SQL varbinary(max) data type, thus for the final call it requires only mapping the placeholder to the binary XML document.

JSON 

Since SQL Server 2016 introduction of JSON support, sending and receiving data to/from SQL Server got a lot easier. Power BI is no exception, sending data to a SQL Server table requires addition of a SP with JSON parameter and on Power Query side serializing the dataset as a text bases JSON object with Json.FomValue.

Because of native JSON support on both SQL and Power BI sides, this was by far the most easy and fast way of sending data across.

4 ways to get USERNAME in Power Query

Regardless of what are you requirements, be that providing some user context during slicing of data or a filtering mechanism for data querying, having a function like USERNAME() in Power Query toolbox  can greatly simplify your data mashup scripts. While trying to build a more robust approach for self referencing queries in M, I’ve managed to collect 4 methods on getting the current username in Power BI. These methods rely on a variety of dependencies — R, NTFS, LocalDB and PowerShell, and come with their own advantages and disadvantages. Based on your setup you might find some of the methods more appropriate than the others, however they are not a universal replacement for a native supported function like USERNAME().

1. R.Execute()

Once again the Swiss Army knife of Power Query — R with its hook function R.Execute, never fails at extending Power BI capabilities. Here is an example of how I call the system command whoami via R function system2 and use its output as a data source in Power Query.

Pros: The advantage of this approach is that it can be adapted to get the STOUT of other system commands as well.

Cons: It depends on calling R, which is currently supported only by Power BI Desktop.

2. NTFS

The output table of Folder.Contents in Power Query contains the field Access Date which records the timestamp of when a file/folder was moved, opened, or access by any other means. Assuming that the NTFS Access Date records for C:/Users sub-folders are up to date, then the folder with the latest Access Date should be the current user.

A note of caution here, NTFS might take up to an hour to update the file times. Which makes this method unreliable in certain scenarios. Nevertheless I’ve recommended this shortcut in the past, and it is still my preferred way of getting to msmdsrv.port.txt file.

Pros: Simple

Cons: Unreliable as NTFS can take up to 1 hour to update the Access Date records of a folder. The Antivirus and other background processes can interfere with correctness of Access Date ⇒ Current User. Also the output of this function doesn’t contain the domain name.

3. LocalDB or any other SQL source

If you happen to have a SQL Server instance lying around or by some curious accident you’ve installed SQL Server Express with support for LocalDB, you can make a trivial SQL query to get SYSTEM_USER. You don’t even need an assigned database for that.

There is always the option of installing only LocalDB feature of SQL Server Express.

install

Make sure to select the version that is relevant to your setup as the connection strings for LocalDB have changed over the years

username

Pros: You might already have LocalDB installed.

Cons: Requires access to a SQL Server instance or installation of LocalDB.

4. HTTP API for Executing PowerShell Scripts

This method relies on a lightweight service which listens to port 8888 and executes PowerShell commands sent over HTTP. The PowerShell team has released this script/service as an alternative to the SOAP heavy Windows Remote Management, for more details please read the associated blog post: Simple HTTP api for Executing PowerShell Scripts. The service itself is written in PowerShell and the 300 lines of code are very easy to follow and adapt to the relevant scenario.

Once I have downloaded, installed and imported the module, I start an instance by using the commandlet Start-HTTPListener.

Start-httpListener

To get the current user in Power Query I make an HTTP call to localhost:8888 with system command whoami.

Back in the PowerShell console, the flag -verbose provides more details to what is happening behind the scenes:

whoami

Pros: This method can be expanded to sourcing the output from other system commands as well as PowerShell commandlets.

Cons: Introduces an additional dependency which might interfere with users’ execution policies. The PowerShell commandlet has to be running in the background.

IMAO

We shouldn’t be asking Power BI team to implement only small utilities like UserName() or CookBreakfast(). Instead we should see the bigger problem and ask for a bigger hammer. I would want Power BI to expose a functions for parsing the console output, this would help with accessing a lot of obsolete data sources as well as standard system commands. Or if we would like to keep only to system specific domain how about having a connector for WMI the same as SSIS does?