Posts Tagged ‘Map’

I was asked the other day for some help on how to plot data by postcode on an SSRS spatial map. I’ve done this a few times, initially for a presentation I gave back in 2010 and most recently a couple of weeks ago when I wanted to analyse the SQLMidlands membership. It occurred to me that despite posting a number of blogs using spatial data, I’ve not done one on the basics of plotting postcode data. So here we go…

Scenario

You have a database containing customers, members, visitors, contacts, etc., each of which has a postcode. You want a simple map which shows where these are. Something like this…

How do we do it?

Firstly, the Reporting Services map component doesn’t understand postcodes, so we have to convert postcodes to latitude and longitude.

There are a number of ways of doing this, some more costly and/or time consuming than others. There are datasets that you can buy, or the Ordnance Survey now provide a free download of postcode and other mapping data. Read Jamie Thompson’s blog (No, not the SSIS-Junkie, another one!) for details on how to use it. [Edit: Thanks to Martin Bell for pointing out this link is now invalid, sorry!] These datasets provide full 7 digit postcode resolution, which means you can plot at the street level (approx 2 million different locations).

For a number of purposes this is excessive, and using a simpler 4 digit postcode is more than adequate, which breaks the UK down into about 3000 areas. For this you can download the details here.

We can then use the spatial functionality introduced in SQL Server 2008 (and R2) to convert the lat/long into a geography data type, which can be displayed natively in an SSRS report.

Convert Postcode to Latitude Longitude

Assuming you’ve loaded the dataset above into a database table, we can join this to our existing table of customers. As our customer table has a full 7 digit postcode but our postcode table only has 4 digit, we need to simplify our customer postcode down to take only those characters before the space (convert SY1 1AA into SY1). We can do this using a LEFT and CHARINDEX, as per the code below.

   CASE WHEN
         --If the postcode doesn't contain a space, it isn't valid
         --So ignore it and return an empty string
      CHARINDEX(' ', Postcode)=0 THEN ''
         --If it does contain a space, only take the characters
         --up to (and not including) the space
      ELSE LEFT(Postcode, CHARINDEX(' ', Postcode)-1)
   END

We can then join this data to the postcode table to link the lat/long to each customer. I’ve saved the postcode list in a table called PostcodeOuter.

   SELECT *
   FROM Customer c
      INNER JOIN PostcodeOuter p ON p.outcode = 
         CASE WHEN 
            CHARINDEX(' ', c.Postcode)=0 THEN ''
            ELSE LEFT(c.Postcode, CHARINDEX(' ', c.Postcode)-1)
           END

Latitude and Longitude aren’t quite enough for Reporting Services to be able to display. We need to convert them into the internal SQL Server Geography data type. We do this with the geography::STPointFromText function.

   geography::STPointFromText('POINT(' + 
      CAST(longitude AS VARCHAR(20)) + ' ' + 
      CAST(latitude AS VARCHAR(20)) + ')', 4326)

Note that the 4326 is the Spatial Reference Identifier (SRID), 4326 is the default – you can just leave this as it is.

We now want to join all of this together, and group the results by the post code outer code, so we can count the number of customers in each code.

   SELECT 
       p.outcode
      ,geography::STPointFromText('POINT(' + 
         CAST(MAX(p.lng) AS VARCHAR(20)) + ' ' + 
         CAST(MAX(p.lat) AS VARCHAR(20)) + ')', 4326) AS Geog
      ,COUNT(*) AS CustomerCount 
   FROM Customer c
      INNER JOIN PostcodeOuter p ON p.outcode = 
         CASE WHEN 
            CHARINDEX(' ', c.Postcode)=0 THEN ''
            ELSE LEFT(c.Postcode, CHARINDEX(' ', c.Postcode)-1)
           END
   GROUP BY p.outcode

Note that as we’re grouping the results, we have to aggregate the lat and long using max. We could aggregate the resulting geography data type, but doing it at the lat/long level reduces the number of geography calculations that have to be performed, improving performance. You can run this in Management Studio. Notice that you should now have an extra results tab, Spatial Results. Clicking on this will show you a preview of your data. The dots can be hard to see, so you can add .STBuffer(5000) to make the dots larger. You should end up with geography:STPointFromText(….., 4326).STBuffer(5000) AS Geog

We can now put this query directly into SSRS and show the data on a map.

Displaying Spatial Data in SSRS

Firstly load up BIDS, load or create a Report Server Project, and then add a new report (don’t bother using the wizard).
Add a data source to your database. Use the query above as the dataset (obviously with the fields and tables modified to suit your database!).
From the Toolbox, drag a Map report item onto your report. This will start the Map wizard. Use the following details for each stage:

  • Choose ‘SQL Server spatial query’
  • Select the dataset that we just created
  • Select the Geog field in the first box, and Point in the second. Also make sure that you tick the box at the bottom – ‘Add a Bing Maps layer’, Selecting whether you want the map layer to show Road, Aerial or Hybrid
  • We want the size of each marker to change depending on the number of customers in that postcode, so select the Bubble Map
  • Select the same dataset that we created earlier
  • Tick the ‘Use bubble sizes to vizualize data’ option, and select [Sum(CustomerCount)]
  • Lets also change the colour of the markers to make it even clearer. Tick the ‘Use bubble colors to visualize data’ box and select [Sum(CustomerCount] and Red-Green as the color rule

And there you have it, you can run the report and see your map. Not that tricky huh?
You can then play around with the settings to change the look and feel, a good one is to set the Map layer transparency to 50, which makes the markers stand out more. But this is up to you.

There’s plenty more information on the internet about spatial data, both on the Frog-Blog and elsewhere. I’d recommend taking a look at Alistair Aitchison’s Spatial blog for some really interesting stuff to do using spatial data.

Thanks to Stephen Bennett for inspiring this post.

Frog-Blog-Out

[Edit 03/03/2014] This post is now over two years old, so some of the links are out of date, have changed or are invalid, and SQL Server has also moved on to new versions. Please take this into consideration when following this guide. Thanks again to Martin Bell for adding the following:

“You may want to add the link http://enterprisegeospatial.blogspot.co.uk/2011/01/using-powershell-to-load-ordnance.html as a means of loading and converting the coordinate files. One thing to be aware of is that it appears the header has changed since post was written and the code should be updated using the header detailed in the documents (Code-Point_Open_Column_Headers.csv) and making sure the attributes used in the code match those in the header (the header can be changed to fit the code)

I believe that a postcode will always have a 3 digit outbound part, so rather than checking there is a space you can take all but the last 3 characters (when trimmed).

© Alex Whittles, Purple Frog Systems Ltd

This is the 3rd and final post in this series of blog posts, showing how you can use SQL Server Reporting Services (SSRS), DMVs and spatial data to generate real time automated user guide documentation for your Analysis Services (SSAS) OLAP cube.

UPDATE: I presented a 1 hour session at SQLBits 8 covering this work, you can watch the video here.

In this post, I’m going to enhance the measure group report to include a visualisation of the star schema. To do this I’ll be enhancing one of the stored procedures to utilise SQL Server 2008′s new spatial data types combined with SSRS 2008 R2′s new map functionality.

To do this we’ll update the dbo.upCubeDocDimensionsForMeasureGroup stored proc so that it returns a SQL geometry polygon for each row, in the right place around the circumference of the star. There’s a little math in this, but nothing more than a bit of trigonometry.

First the theory. We have an arbitrary number of dimensions that we need to place in a circle around a central point (the measure group). If we have 6 dimensions, then we need to divide the whole circle (360 degrees) by 6 (=60 degrees each) to get the angle of each around the hypothetical axis.

Therefore the first dimension needs to be at 60, the second at 120, the third at 180 etc, with the 6th at 360, completing the full circle.
Obviously the angle needs to vary depending on the number of dimensions in the query, so we need to calculate it within the stored proc. To do this I’m using common table expressions (CTE) to perform further calculations on the basic query.

We wrap the original proc query into a CTE and call it BaseData. We also add an extra field called Seq, which uniquely identifies each row, we’ll use this later to enable us to rank the dimensions.

;WITH BaseData AS
(
    SELECT
          mgd.*
        , d.[DESCRIPTION]
        , REPLACE(REPLACE(CAST(mgd.[DIMENSION_UNIQUE_NAME]
              AS VARCHAR(255))
              ,'[',''),']','') AS DimensionCaption
        , REPLACE(REPLACE(CAST(mgd.[MEASUREGROUP_NAME]
              AS VARCHAR(255))
              ,'[',''),']','') AS MeasureGroupCaption
    FROM OPENQUERY(CubeLinkedServer, 'SELECT
                [CATALOG_NAME]
                   +[CUBE_NAME]
                   +[MEASUREGROUP_NAME]
                   +[DIMENSION_UNIQUE_NAME] AS Seq
                , [CATALOG_NAME]
                , [CUBE_NAME]
                , [MEASUREGROUP_NAME]
                , [MEASUREGROUP_CARDINALITY]
                , [DIMENSION_UNIQUE_NAME]
                , [DIMENSION_CARDINALITY]
                , [DIMENSION_IS_VISIBLE]
                , [DIMENSION_IS_FACT_DIMENSION]
                , [DIMENSION_GRANULARITY]
            FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS
            WHERE [DIMENSION_IS_VISIBLE]') mgd
        INNER JOIN OPENQUERY(CubeLinkedServer, 'SELECT
                [CATALOG_NAME]
                ,[CUBE_NAME]
                ,[DIMENSION_UNIQUE_NAME]
                ,[DESCRIPTION]
            FROM $SYSTEM.MDSCHEMA_DIMENSIONS
            WHERE [DIMENSION_IS_VISIBLE]') d
                ON  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))
                  = CAST(d.[CATALOG_NAME] AS VARCHAR(255))
                AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))
                  = CAST(d.[CUBE_NAME] AS VARCHAR(255))
                AND CAST(mgd.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
                  = CAST(d.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
     WHERE  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))     = @Catalog
       AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))         = @Cube
       AND CAST(mgd.[MEASUREGROUP_NAME] AS VARCHAR(255)) = @MeasureGroup
)

We’ll then add a new CTE which calculated the number of records returned by the previous query.

,TotCount AS
(
    SELECT COUNT(*) AS RecCount FROM BaseData
)

Next we cross join TotCount with the base data, so that every row has the extra RecCount field. We then rank each record, providing each with a unique number from 1 to n.

, RecCount AS
(
    SELECT RANK() OVER (ORDER BY CAST(Seq AS VARCHAR(255))) AS RecID
        , RecCount
        , BaseData.*
    FROM
        BaseData CROSS JOIN TotCount
)

Each record now contains its row number, as well as the total number of rows, so it’s easy to calculate its position around the circle (rank/n * 360). Now we have that, calculating the x and y coordinates of each dimension is simply a case of applying Sine and Cosine. Note that the SQL SIN and COS functions expect angles to be provided in radians not degrees, so we have to use the RADIANS function to convert it for us. I’m also multiplying the result by 1000 to scale the numbers up from -1 to +1 to -1000 to +1000, which makes our life easier later on.

, Angles AS
(
    SELECT
        *
        , SIN(RADIANS((CAST(RecID AS FLOAT)
            /CAST(RecCount AS FLOAT))
            * 360)) * 1000 AS x
        , COS(RADIANS((CAST(RecID AS FLOAT)
            /CAST(RecCount AS FLOAT))
            * 360)) * 1000 AS y
    FROM RecCount
)

We can now use the x and y coordinates to create a point indicating the position of each dimension, using the code below.

geometry::STGeomFromText('POINT('
   + CAST(y AS VARCHAR(20))
   + ' '
   + CAST(x AS VARCHAR(20))
   + ')',4326) AS Posn

This is a good start, but we want a polygon box, not a single point. We can use a similar geometry function to create a polygon around our point.

geometry::STPolyFromText('POLYGON ((' +
   CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
 	  + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
   CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
	  + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
   CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
	  + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
   CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
      + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
   CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
	  + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + '
   ))',0) AS Box

You’ll notice that I’m multiplying the y axis by a @Stretch variable. This is to allow us to squash or squeeze the resulting star to make it look better in the report. I’m also using a @BoxSize variable which we can use to change the relative size of the boxes. It’s for this reason why I like to work on a -1000 to +1000 scale, it means we can have an integer box size of say 250 instead of a fraction such as 0.25, I just think it’s easier to read.
So you’ll now have a stored proc similar to this.

CREATE PROCEDURE [dbo].[upCubeDocDimensionsForMeasureGroup]
    (@Catalog       VARCHAR(255)
    ,@Cube          VARCHAR(255)
    ,@MeasureGroup  VARCHAR(255)
    )
AS

 DECLARE @BoxSize INT
 DECLARE @Stretch FLOAT
 SET @BoxSize = 250
 SET @Stretch = 1.4

;WITH BaseData AS
(
    SELECT
          mgd.*
        , d.[DESCRIPTION]
        , REPLACE(REPLACE(CAST(mgd.[DIMENSION_UNIQUE_NAME]
              AS VARCHAR(255))
              ,'[',''),']','') AS DimensionCaption
        , REPLACE(REPLACE(CAST(mgd.[MEASUREGROUP_NAME]
              AS VARCHAR(255))
              ,'[',''),']','') AS MeasureGroupCaption
    FROM OPENQUERY(CubeLinkedServer, 'SELECT
                [CATALOG_NAME]
                   +[CUBE_NAME]
                   +[MEASUREGROUP_NAME]
                   +[DIMENSION_UNIQUE_NAME] AS Seq
                , [CATALOG_NAME]
                , [CUBE_NAME]
                , [MEASUREGROUP_NAME]
                , [MEASUREGROUP_CARDINALITY]
                , [DIMENSION_UNIQUE_NAME]
                , [DIMENSION_CARDINALITY]
                , [DIMENSION_IS_VISIBLE]
                , [DIMENSION_IS_FACT_DIMENSION]
                , [DIMENSION_GRANULARITY]
            FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS
            WHERE [DIMENSION_IS_VISIBLE]') mgd
        INNER JOIN OPENQUERY(CubeLinkedServer, 'SELECT
                [CATALOG_NAME]
                ,[CUBE_NAME]
                ,[DIMENSION_UNIQUE_NAME]
                ,[DESCRIPTION]
            FROM $SYSTEM.MDSCHEMA_DIMENSIONS
            WHERE [DIMENSION_IS_VISIBLE]') d
                ON  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))
                  = CAST(d.[CATALOG_NAME] AS VARCHAR(255))
                AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))
                  = CAST(d.[CUBE_NAME] AS VARCHAR(255))
                AND CAST(mgd.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
                  = CAST(d.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
     WHERE  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))      = @Catalog
        AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))         = @Cube
        AND CAST(mgd.[MEASUREGROUP_NAME] AS VARCHAR(255)) = @MeasureGroup
)
,TotCount AS
(
    SELECT COUNT(*) AS RecCount FROM BaseData
)
, RecCount AS
(
    SELECT RANK() OVER (ORDER BY CAST(Seq AS VARCHAR(255))) AS RecID
        , RecCount
        , BaseData.*
    FROM
        BaseData CROSS JOIN TotCount
)
, Angles AS
(
    SELECT
        *
        , SIN(RADIANS((CAST(RecID    AS FLOAT)
             /CAST(RecCount AS FLOAT))
             * 360)) * 1000 AS x
        , COS(RADIANS((CAST(RecID AS FLOAT)
             /CAST(RecCount AS FLOAT))
             * 360)) * 1000 AS y
    FROM RecCount
)
,Results AS
(
    SELECT
        *
        , geometry::STGeomFromText('POINT('
            + CAST(y AS VARCHAR(20))
            + ' '
            + CAST(x AS VARCHAR(20))
            + ')',4326) AS Posn
        , geometry::STPolyFromText('POLYGON ((' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + '
            ))',0) AS Box
    FROM Angles
)
SELECT * FROM Results
GO

If you then execute this in Management Studio, you’ll notice an extra tab in the result window called Spatial Results.

EXEC [dbo].[upCubeDocDimensionsForMeasureGroup]
    @Catalog = 'Adventure Works DW 2008R2',
    @Cube = 'Adventure Works',
    @MeasureGroup = 'Financial Reporting'

Click on the Spatial Results tab, then select Box as the spatial column, and you’ll see the boxes that we’ve created in a preview window.

This is now getting somewhere close. But as well as the dimensions, we also want to show the measure group in the middle, as well as lines linking them together to actuallly create our star. We can do this by adding a couple more geometry functions to our query. We end up with the end of our proc looking like this.

,Results AS
(
    SELECT
        *
        , geometry::STGeomFromText('POINT('
            + CAST(y AS VARCHAR(20))
            + ' '
            + CAST(x AS VARCHAR(20))
            + ')',4326) AS Posn
        , geometry::STPolyFromText('POLYGON ((' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST((y*@Stretch)+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(x+(@BoxSize/2) AS VARCHAR(20)) + '
            ))',0) AS Box
         , geometry::STLineFromText('LINESTRING (0 0, '
              + CAST((y*@Stretch) AS VARCHAR(20))
              + ' ' + CAST(x AS VARCHAR(20))
              + ')', 0) AS Line
         , geometry::STPolyFromText('POLYGON ((' +
            CAST(0+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(0+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST(0-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(0+(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST(0-@BoxSize AS VARCHAR(20)) + ' '
              + CAST(0-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST(0+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(0-(@BoxSize/2) AS VARCHAR(20)) + ', ' +
            CAST(0+@BoxSize AS VARCHAR(20)) + ' '
              + CAST(0+(@BoxSize/2) AS VARCHAR(20)) + '
            ))',0) AS CenterBox

    FROM Angles
)
SELECT * FROM Results
GO

So, we’ve now got the polygons and lines being generated by the proc, it’s now time to add them into the report and display them to our users.

Firstly open up the CubeDoc_MeasureGroup.rdl report, and go to the properties of the dsDimensions dataset. Click Refresh Fields and the new x, y, Posn, Box, Line and CenterBox fields should now be available.
Then drag a Map from the toolbox onto the report. This will start the map wizard.
Select SQL Server Spatial Query as the source for the data and click Next.
Choose dsDimensions as the dataset to use for the data and click Next.
Choose Box as the spatial field, and Polygon as the layer type. It may well give you an error, just ignore it.
Don’t select the embed map or Bing maps layer.

Click Next, then select a basic map, select the default options for the remaining wizard stages and you’ll end up with a map in your report.

If you preview the report at this stage you won’t see the polygons. This is because the map still thinks it’s a geographical map, and it is trying to draw our boxes as latitude and longitudes. We don’t want this, but want it to show them on our own scale. To fix this, just change the CoordinateSystem property of the map from Geographic to Planar.

You can then preview the report, which should show you something like this

It still doesn’t look like a star but we’ve still got a few more changes to make. We need to add a couple more layers to the map, the center box for the measure group and then the lines to link them all together.
Add a new polygon layer to the map and then set the layer data to use the CenterBox field from the dsDimensions dataset.

Repeat the above, but with a new line layer instead of a polygon layer. Set the layer data to use the Line field of dsDimensions.

To move the lines behind the boxes, just rearrange the order of the layers by using the blue arrows in the map layers window. We want the Lines layer to be at the bottom.

Set the PolygonTemplate.BackgroundColour property of the CenterBox layer to Khaki, and the set the same property of the dimension box layer to LightBlue.

Then set the PolygonTemplate.Label property of the CenterBox layer to the MeasureGroupCaption field, and set the ShowLabel property to True. If you don’t then SSRS will decide whether or not to show the label, we want it to always show.
Set the PolygonTemplate.Label property of the Dimension layer to the DimensionCaption field, and set the ShowLabel property to True.
You can then play around with font sizes, zoom, background colours, line widths etc. to get the effects that you want, but you’ll end up with a star schema visualisation similar to this.

You can also configure actions for each layer. Using this you can hyperlink each dimension box to show the CubeDoc_Dimension report for the selected dimension etc, making the star schema interactive.

This has been quite a fun blog post to investigate, I hope you can take something useful from it and have as much fun with it as I’ve had with it. Every demo that I’ve seen using spatial data has been using maps, hopefully this shows an alternative use beyond geographical mapping.

© Alex Whittles, Purple Frog Systems Ltd

In my previous post I described how to create a number of stored procedures that use Dynamic Management Views (DMVs) to return the metadata structure of an SSAS 2008 OLAP cube, including dimensions, attributes, measure groups, BUS matrix etc.

In this post I’m going to use those procs to create a set of SSRS 2008 reports that will serve as the automated documentation of your cube. I’m going to make the following assumptions:

  • You’ve read the part 1 post, and already have the stored procs in a database.
  • You know the basics of SSRS 2008

If you haven’t read part 1, you can jump to it here.

UPDATE: I presented a 1 hour session at SQLBits 8 covering this work, you can watch the video here.

Firstly I create a basic template report which has an appropriate header, with date/time stamp, server name and logos etc. This means that all of the reports will have a common look and feel. I could of course make use of the new report parts in SSRS 2008 R2 for this, but to maintain compatibility with pre R2 I’ll keep it simple.

The expression in the box on the top right is just to display today’s date in UK format dd/mm/yyyy.

  =FORMAT(Today(),"dd/MM/yyyy")

The reports that we’ll build will include the following:

  • CubeDoc_Cubes.rdl – Entry page, list of all cubes in the database
  • CubeDoc_Cube.rdl – showing all measure groups and dimensions within the selected cube
  • CubeDoc_Dimension.rdl – showing all hierarchies, attributes and related measure groups
  • CubeDoc_MeasureGroup.rdl – showing all measures and related dimensions
  • CubeDoc_Search.rdl – search names and descriptions of cubes, dimensions, measure groups, etc

Create the first report (CubeDoc_Cubes.rdl) which will act as the entry screen and menu of cubes.
Add a dataset dsCubes, and point it at the stored proc dbo.upCubeDocCubes

The proc has a @Catalog parameter, which filters the result set to a specific SSAS database (catalog). We want to return all cubes from all catalogs, so set the parameter value to =Nothing

All we have to do now is add a table and pull in the dataset fields that we want to see.

We can then preview the report to test that it returns the right list of cubes. You should see something like this.

Note that the AdventureWorks database doesn’t contain any descriptions, so you won’t see any in the report but they will be there when you add descriptions to your own cubes.

The next report we’re going to write is the CubeDoc_Cube report, which will list the measure groups, dimensions and BUS matrix of a single cube. We’ll link the two reports together later on.

Create a new report, using the template report you created earlier (select the template report in the solution explorer window, then CTRL+C then CTRL+V) and rename the new file as CubeDoc_Cube.rdl.

Add a report parameter called @Catalog which should be Text. I’ve set mine to default to “Adventure Works DW 2008R2″ to make testing easier.

Add a dataset called dsCubes, and point it at the dbo.upCubeDocCubes proc, and link the @Catalog dataset parameter to the @Catalog report parameter.

This dataset will query the available cubes for the selected catalog, and populate a new parameter which we’ll now create, called @Cube. This should also be a text parameter, but this time we’ll set the available values to those returned by the dsCubes dataset.

If you want you can also set the default value of the parameter to the CUBE_NAME field of dsCubes. This parameter is not a multi value parameter, so by defaulting it to the dataset it will just default to the first record.

We can now use @Catalog and @Cube parameters to query the available measure groups and dimensions.
So, create a three new datasets:

  • dsDimensions – pointing to dbo.upCubeDocDimensionsInCube
  • dsMeasureGroups – pointing to dbo.upCubeDocMeasureGroupsInCube
  • dsBusMatrix – pointing to dbo.upCubeDocBUSMatrix

Set each of their @Catalog parameters to the report’s @Catalog parameter, and their @Cube parameters to the report’s @Cube parameter.

Create two tables in the report, one for measure groups and one for dimensions. Drag in the fields that you want to see, and preview the report. You should see something like this.

I’ve added a couple of textbox titles for good measure.

The third dataset, dsBUSMatrix requires something a little more interesting. For those that aren’t familiar with Kimball’s BUS Matrix concept, it’s a grid that shows the relationship and connectivity between facts (measure groups) and their dimensions. As the name suggests, we’ll use SSRS’s Matrix control for this. Once you’ve added a matrix control onto the report, follow these steps (using the dsBUSMatrix dataset):

  • Drag DIMENSION_UNIQUE_NAME onto the Rows of the matrix
  • Drag MEASUREGROUP_NAME onto the columns of the matrix
  • Right click on the Data box of the matrix, and type in the expression below. This checks the cardinality of the dimensions/measures to determine whether it is a regular relationship, a many to many or a degenerate fact
=SWITCH(SUM(Fields!Relationship.Value)=0,"",
   Fields!DIMENSION_IS_FACT_DIMENSION.Value=1,"F",
   Fields!MEASUREGROUP_CARDINALITY.Value="MANY","M",
   True,"X")

This will either show an X if there is a regular relationship, or show an M or F if there’s a many to many or degenerate relationship respectively.
To make it easier to read, I also like to set the background colour of the Data textbox to highlight the type of relationship further.

=SWITCH(SUM(Fields!Relationship.Value)=0,"Transparent",
   Fields!DIMENSION_IS_FACT_DIMENSION.Value=1,"Yellow",
   Fields!MEASUREGROUP_CARDINALITY.Value="MANY","Red",
   True,"CornflowerBlue")

If you preview the report you should see the following

It shows the concept, but it needs a little tidying up. Centering the text in the data textbox helps, but we can also use a fantastic new feature in SSRS 2008 R2 to rotate the column titles. Simply set the WritingMode property in the Localization group to Rotate270, and then shrink the width of the column.

I’ve also added a title, with a key, and level of row grouping using the DIMENSION_MASTER_NAME field, which groups role playing dimensions by their master dimension. It should now look something like this.

That’s it for this report, so save it, then go back to the first report (CubeDoc_Cubes.rdl) and right click, properties on the [CUBE_NAME] textbox. Go to the action tab, and set the action to navigate to the CubeDoc_Cube report, passing through the CATALOG_NAME and CUBE_NAME fields from the dataset as the parameter values. This sets up a hyperlink from one report to the other, allowing users to navigate around the cube doc reports by clicking on what they want to know about.

We then need to do the same for 3 other reports:
CubeDoc_Dimensions

  • dbo.upCubeDocAttributesInDimension results in a table
  • dbo.upCubeDocMeasureGroupsForDimension results in a table
  • Add an extra @Dimension parameter, populated from dbo.upCubeDocDimensionsInCube

CubeDoc_MeasureGroup

  • dbo.upCubeDocMeasuresInMeasureGroup results in a table
  • dbo.upCubeDocDimensionsForMeasureGroup results in a table
  • Add an extra @MeasureGroup parameter, populated from dbo.upCubeDocMeasureGroupsInCube

CubeDoc_Search

  • Add an extra @Search parameter, text, with no default
  • Table containing results from dbo.upCubeDocSearch, using the @Search parameter

Link all appropriate textboxes (measure groups, dimensions, search etc.) to their relevant report using the report action, and hey presto – a fully automated, real time, self-documenting cube report.

In the next and final installment of this series of blog posts, we’ll explore SQL 2008′s spatial data to generate an automated star schema visualisation to add that little something extra to the reports.

© Alex Whittles, Purple Frog Systems Ltd

Being a business intelligence consultant, I like to spend my time designing data warehouses, ETL scripts and OLAP cubes. An unfortunate consequence of this is having to write the documentation that goes with the fun techy work. So it got me thnking, is there a slightly more fun techy way of automating the documentation of OLAP cubes…

There are some good tools out there such as BI Documenter, but I wanted a way of having more control over the output, and also automating it further so that you don’t have to run an overnight build of the documentation.

I found a great article by Vincent Rainardi describing some DMVs (Dynamic Management Views) available in SQL 2008 which got me thinking, why not just build a number of SSRS reports calling these DMVs, which would then dynamically create the cube structure documentation in real time whenever the report rendered..

This post is the first in a 3 part set which will demonstrate how you can use these DMVs to automate the SSAS cube documentation and user guide.

UPDATE: I presented a 1 hour session at SQLBits 8 covering all of this work, you can watch the video here.

There’s a full list of DMVs available in SQL 2008 R2 on the msdn site.

The primary DMVs that are of interest are:

DMV Description
MDSCHEMA_CUBES Lists the cubes in an SSAS database
MDSCHEMA_MEASUREGROUPS Lists measure groups
MDSCHEMA_DIMENSIONS Lists dimensions
MDSCHEMA_LEVELS Dimension attributes
MDSCHEMA_MEASUREGROUP_DIMENSIONS Enumerates dimensions of measure groups
MDSCHEMA_MEASURES Lists measures

When querying DMVs we can use SQL style SELECT statements, but executed against the cube in a DMX window.

SELECT *
FROM $SYSTEM.MDSCHEMA_CUBES

This returns a dataset like any other SQL query.

We can even enhance it with DISTINCT and WHERE clauses, although they are more restricted than basic SQL. One of the main limitations is the lack of a JOIN operator. A number of the queries that I’ll perform below need to use JOIN, so to get around this I wrap up each query in an SQL OPENROWSET command, executed against a SQL database with a linked server to the cube. This enables me to perform JOINs using queries such as

SELECT *
FROM OPENQUERY(CubeLinkedServer,
   'SELECT *
    FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS') mgd
INNER JOIN OPENQUERY(CubeLinkedServer,
   'SELECT *
    FROM $SYSTEM.MDSCHEMA_MEASUREGROUPS') mg
ON mgd.XXX = mg.XXX


etc.

I’m therefore going to create a number of stored procs to wrap up this functionality, the SSRS reports can then just call the procs.

Within BIDS, every item (cube, measure group, measure, dimension, attribute, hierarchy, KPI, etc.) has a description in the properties pane which is a multi-line free text property. These are exposed by the DMVs, so I’m going to make use of them and bring them out in the reports. This allows you to create the descriptions within BIDS as you’re developing the cube, meaning they’re version controlled and always in sync with the code.

I should also point out that I’m using SQL Server 2008 R2. All of the queries below will work with SQL 2008, but I want to use the spatial report functionality of SSRS 2008 R2 to generate dynamic star schema visualisations, which is only supported in R2.

In this post I’ll script out the stored procedures used as the basis of the documentation. In my next post I’ll put these into SSRS reports.

Lets get started.

Firstly we need to create our linked server. This script will create a linked server called CubeLinkedServer pointing to the Adventure Works DW 2008R2 OLAP database on the local server.

EXEC master.dbo.sp_addlinkedserver
   @server = N'CubeLinkedServer',
   @srvproduct=N'MSOLAP',
   @provider=N'MSOLAP',
   @datasrc=N'(local)',
   @catalog=N'Adventure Works DW 2008R2'


You’ll have to set up the security according to your requirements. So now lets start creating the source procs.

The first proc lists all of the cubes. The MDSCHEMA_CUBES DMV returns not only cubes, but also dimensions, I’m filtering it to only return cubes by specifying CUBE_SOURCE=1.

CREATE PROCEDURE [dbo].[upCubeDocCubes]
  (@Catalog       VARCHAR(255) = NULL
  )
AS
  SELECT *
  FROM OPENQUERY(CubeLinkedServer,
    'SELECT *
     FROM $SYSTEM.MDSCHEMA_CUBES
     WHERE CUBE_SOURCE = 1')
  WHERE CAST([CATALOG_NAME] AS VARCHAR(255)) = @Catalog
    OR @Catalog IS NULL
GO


The next proc returns all measure groups found within a specified cube.

CREATE PROCEDURE [dbo].[upCubeDocMeasureGroupsInCube]
  (@Catalog       VARCHAR(255)
  ,@Cube          VARCHAR(255)
  )
AS
  SELECT *
  FROM OPENQUERY(CubeLinkedServer,
    'SELECT *
     FROM $SYSTEM.MDSCHEMA_MEASUREGROUPS ')
  WHERE CAST([CATALOG_NAME] AS VARCHAR(255)) = @Catalog
    AND CAST([CUBE_NAME] AS VARCHAR(255))    = @Cube
GO


This next proc returns a list of measures within a specified measure group.

CREATE PROCEDURE [dbo].[upCubeDocMeasuresInMeasureGroup]
  (@Catalog       VARCHAR(255)
  ,@Cube          VARCHAR(255)
  ,@MeasureGroup  VARCHAR(255)
  )
AS
SELECT * FROM OPENQUERY(CubeLinkedServer,
  'SELECT *
   FROM $SYSTEM.MDSCHEMA_MEASURES
     WHERE [MEASURE_IS_VISIBLE]')
   WHERE CAST([CATALOG_NAME] AS VARCHAR(255))      = @Catalog
     AND CAST([CUBE_NAME] AS VARCHAR(255))         = @Cube
     AND CAST([MEASUREGROUP_NAME] AS VARCHAR(255)) = @MeasureGroup
GO


The following proc queries all dimensions available within a specified cube. I’m filtering using the DIMENSION_IS_VISIBLE column to only show visible dimensions.

CREATE PROCEDURE [dbo].[upCubeDocDimensionsInCube]
  (@Catalog       VARCHAR(255)
  ,@Cube          VARCHAR(255)
  )
AS
SELECT * FROM OPENQUERY(CubeLinkedServer,
  'SELECT *
   FROM $SYSTEM.MDSCHEMA_DIMENSIONS
     WHERE [DIMENSION_IS_VISIBLE]')
   WHERE CAST([CATALOG_NAME] AS VARCHAR(255)) = @Catalog
     AND CAST([CUBE_NAME] AS VARCHAR(255))    = @Cube
GO


Then we can query all available attributes within a dimension. This DMV returns a bitmask field (LEVEL_ORIGIN) which defines whether the attribute is a key, attribute or hierarchy. I’m using bitwise AND (&) to split this into three seperate fields for ease of use. I’m also filtering out invisible attributes, as well as those with a level of 0. Level 0 is the [All] member of any attribute, which we can ignore for this purpose.

CREATE PROCEDURE [dbo].[upCubeDocAttributesInDimension]
  (@Catalog       VARCHAR(255)
  ,@Cube          VARCHAR(255)
  ,@Dimension  VARCHAR(255)
  )
AS
  SELECT *
    , CASE WHEN CAST([LEVEL_ORIGIN] AS INT) & 1 = 1
        THEN 1 ELSE 0 END AS IsHierarchy
    , CASE WHEN CAST([LEVEL_ORIGIN] AS INT) & 2 = 2
        THEN 1 ELSE 0 END AS IsAttribute
    , CASE WHEN CAST([LEVEL_ORIGIN] AS INT) & 4 = 4
        THEN 1 ELSE 0 END AS IsKey
  FROM OPENQUERY(CubeLinkedServer,
    'SELECT *
     FROM $SYSTEM.MDSCHEMA_LEVELS
     WHERE [LEVEL_NUMBER]>0
       AND [LEVEL_IS_VISIBLE]')
  WHERE CAST([CATALOG_NAME] AS VARCHAR(255))          = @Catalog
    AND CAST([CUBE_NAME] AS VARCHAR(255))             = @Cube
    AND CAST([DIMENSION_UNIQUE_NAME] AS VARCHAR(255)) = @Dimension
GO


The next proc returns measure groups with their associated dimensions. We have to join two DMVs together in order to get the description columns of both the dimension and measure group.

CREATE PROCEDURE [dbo].[upCubeDocMeasureGroupsForDimension]
    (@Catalog       VARCHAR(255)
    ,@Cube          VARCHAR(255)
    ,@Dimension     VARCHAR(255)
    )
AS
  SELECT
    mgd.*
    , m.[DESCRIPTION]
  FROM OPENQUERY(CubeLinkedServer,
    'SELECT
       [CATALOG_NAME]
       , [CUBE_NAME]
       , [MEASUREGROUP_NAME]
       , [MEASUREGROUP_CARDINALITY]
       , [DIMENSION_UNIQUE_NAME]
     FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS
       WHERE [DIMENSION_IS_VISIBLE]') mgd
   INNER JOIN OPENQUERY(CubeLinkedServer,
     'SELECT
       [CATALOG_NAME]
       ,[CUBE_NAME]
       ,[MEASUREGROUP_NAME]
       ,[DESCRIPTION]
     FROM $SYSTEM.MDSCHEMA_MEASUREGROUPS') mg
        ON  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))
           = CAST(mg.[CATALOG_NAME] AS VARCHAR(255))
        AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))
           = CAST(mg.[CUBE_NAME] AS VARCHAR(255))
        AND CAST(mgd.[MEASUREGROUP_NAME] AS VARCHAR(255))
           = CAST(mg.[MEASUREGROUP_NAME] AS VARCHAR(255))
  WHERE CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))            = @Catalog
    AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))               = @Cube
    AND CAST(mgd.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))   = @Dimension
GO


The next proc is similar to the above, but the opposite way around. It returns all dimensions that are related to a measure group.

CREATE PROCEDURE [dbo].[upCubeDocDimensionsForMeasureGroup]
  (@Catalog       VARCHAR(255)
  ,@Cube          VARCHAR(255)
  ,@MeasureGroup  VARCHAR(255)
  )
AS
  SELECT
    mgd.*
    , d.[DESCRIPTION]
  FROM OPENQUERY(CubeLinkedServer,
    'SELECT
        [CATALOG_NAME]
       ,[CUBE_NAME]
       ,[MEASUREGROUP_NAME]
       ,[MEASUREGROUP_CARDINALITY]
       ,[DIMENSION_UNIQUE_NAME]
       ,[DIMENSION_CARDINALITY]
       ,[DIMENSION_IS_VISIBLE]
       ,[DIMENSION_IS_FACT_DIMENSION]
       ,[DIMENSION_GRANULARITY]
     FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS
       WHERE [DIMENSION_IS_VISIBLE]') mgd
  INNER JOIN OPENQUERY(CubeLinkedServer,
    'SELECT
       [CATALOG_NAME]
       ,[CUBE_NAME]
       ,[DIMENSION_UNIQUE_NAME]
       ,[DESCRIPTION]
     FROM $SYSTEM.MDSCHEMA_DIMENSIONS
       WHERE [DIMENSION_IS_VISIBLE]') d
   ON  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))
       = CAST(d.[CATALOG_NAME] AS VARCHAR(255))
   AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))
       = CAST(d.[CUBE_NAME] AS VARCHAR(255))
   AND CAST(mgd.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
       = CAST(d.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
  WHERE  CAST(mgd.[CATALOG_NAME] AS VARCHAR(255))        = @Catalog
     AND CAST(mgd.[CUBE_NAME] AS VARCHAR(255))           = @Cube
     AND CAST(mgd.[MEASUREGROUP_NAME] AS VARCHAR(255))   = @MeasureGroup
GO


The next proc builds a BUS matrix, joining every dimension to its related measure groups. Later we’ll use the SSRS tablix control to pivot this into matrix form.

CREATE PROCEDURE [dbo].[upCubeDocBUSMatrix]
    (@Catalog       VARCHAR(255),
     @Cube          VARCHAR(255)
    )
AS
  SELECT
     bus.[CATALOG_NAME]
    ,bus.[CUBE_NAME]
    ,bus.[MEASUREGROUP_NAME]
    ,bus.[MEASUREGROUP_CARDINALITY]
    ,bus.[DIMENSION_UNIQUE_NAME]
    ,bus.[DIMENSION_CARDINALITY]
    ,bus.[DIMENSION_IS_FACT_DIMENSION]
    ,bus.[DIMENSION_GRANULARITY]
    ,dim.[DIMENSION_MASTER_NAME]
    ,1 AS Relationship
  FROM
    OPENQUERY(CubeLinkedServer,
      'SELECT
        [CATALOG_NAME]
        ,[CUBE_NAME]
        ,[MEASUREGROUP_NAME]
        ,[MEASUREGROUP_CARDINALITY]
        ,[DIMENSION_UNIQUE_NAME]
        ,[DIMENSION_CARDINALITY]
        ,[DIMENSION_IS_FACT_DIMENSION]
        ,[DIMENSION_GRANULARITY]
       FROM $SYSTEM.MDSCHEMA_MEASUREGROUP_DIMENSIONS
        WHERE [DIMENSION_IS_VISIBLE]') bus
    INNER JOIN OPENQUERY(CubeLinkedServer,
      'SELECT
        [CATALOG_NAME]
        ,[CUBE_NAME]
        ,[DIMENSION_UNIQUE_NAME]
        ,[DIMENSION_MASTER_NAME]
       FROM $SYSTEM.MDSCHEMA_DIMENSIONS') dim
    ON CAST(bus.[CATALOG_NAME] AS VARCHAR(255))
     = CAST(dim.[CATALOG_NAME] AS VARCHAR(255))
    AND CAST(bus.[CUBE_NAME] AS VARCHAR(255))
     = CAST(dim.[CUBE_NAME] AS VARCHAR(255))
    AND CAST(bus.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
     = CAST(dim.[DIMENSION_UNIQUE_NAME] AS VARCHAR(255))
  WHERE  CAST(bus.[CATALOG_NAME] AS VARCHAR(255)) = @Catalog
     AND CAST(bus.[CUBE_NAME] AS VARCHAR(255)) = @Cube
GO


Next, in order to make it easier for users to find items within the cube, I’ve created a searching proc which will scour a number of the DMVs for anything containing the search term.

CREATE PROCEDURE [dbo].[upCubeDocSearch]
    (@Search        VARCHAR(255)
    ,@Catalog       VARCHAR(255)=NULL
    ,@Cube          VARCHAR(255)=NULL
    )
AS
  WITH MetaData AS
  (
   --Cubes
    SELECT CAST('Cube' AS VARCHAR(20))            AS [Type]
      , CAST(CATALOG_NAME AS VARCHAR(255))     AS [Catalog]
      , CAST(CUBE_NAME AS VARCHAR(255))           AS [Cube]
      , CAST(CUBE_NAME AS VARCHAR(255))           AS [Name]
      , CAST(DESCRIPTION AS VARCHAR(4000)) AS [Description]
      , CAST(CUBE_NAME AS VARCHAR(255))           AS [Link]
    FROM OPENQUERY(CubeLinkedServer,
      'SELECT [CATALOG_NAME], [CUBE_NAME], [DESCRIPTION]
       FROM $SYSTEM.MDSCHEMA_CUBES
       WHERE CUBE_SOURCE = 1')
    WHERE  (CAST([CATALOG_NAME] AS VARCHAR(255))
       = @Catalog OR @Catalog IS NULL)

    UNION ALL

   --Dimensions
    SELECT CAST('Dimension' AS VARCHAR(20))         AS [Type]
      , CAST(CATALOG_NAME AS VARCHAR(255))       AS [Catalog]
      , CAST(CUBE_NAME AS VARCHAR(255))             AS [Cube]
      , CAST(DIMENSION_NAME AS VARCHAR(255))        AS [Name]
      , CAST(DESCRIPTION AS VARCHAR(4000))   AS [Description]
      , CAST(DIMENSION_UNIQUE_NAME AS VARCHAR(255)) AS [Link]
    FROM OPENQUERY(CubeLinkedServer,
      'SELECT [CATALOG_NAME], [CUBE_NAME]
          , [DIMENSION_NAME], [DESCRIPTION]
          , [DIMENSION_UNIQUE_NAME]
       FROM $SYSTEM.MDSCHEMA_DIMENSIONS
         WHERE [DIMENSION_IS_VISIBLE]')
    WHERE  (CAST([CATALOG_NAME] AS VARCHAR(255))
        = @Catalog OR @Catalog IS NULL)
      AND (CAST([CUBE_NAME] AS VARCHAR(255))
        = @Cube OR @Cube IS NULL)
      AND LEFT(CAST(CUBE_NAME AS VARCHAR(255)),1)
        <>'$' --Filter out dimensions not in a cube

    UNION ALL

   --Attributes
    SELECT CAST('Attribute' AS VARCHAR(20))         AS [Type]
      , CAST(CATALOG_NAME AS VARCHAR(255))       AS [Catalog]
      , CAST(CUBE_NAME AS VARCHAR(255))             AS [Cube]
      , CAST(LEVEL_CAPTION AS VARCHAR(255))         AS [Name]
      , CAST(DESCRIPTION AS VARCHAR(4000))   AS [Description]
      , CAST(DIMENSION_UNIQUE_NAME AS VARCHAR(255)) AS [Link]
    FROM OPENQUERY(CubeLinkedServer,
      'SELECT [CATALOG_NAME], [CUBE_NAME]
         , [LEVEL_CAPTION], [DESCRIPTION],
         , [DIMENSION_UNIQUE_NAME]
       FROM $SYSTEM.MDSCHEMA_LEVELS
       WHERE [LEVEL_NUMBER]>0
         AND [LEVEL_IS_VISIBLE]')
    WHERE  (CAST([CATALOG_NAME] AS VARCHAR(255))
         = @Catalog OR @Catalog IS NULL)
      AND (CAST([CUBE_NAME] AS VARCHAR(255))
         = @Cube OR @Cube IS NULL)
      AND LEFT(CAST(CUBE_NAME AS VARCHAR(255)),1)
         <>'$' --Filter out dimensions not in a cube

    UNION ALL

   --Measure Groups
    SELECT CAST('Measure Group' AS VARCHAR(20))   AS [Type]
      , CAST(CATALOG_NAME AS VARCHAR(255))     AS [Catalog]
      , CAST(CUBE_NAME AS VARCHAR(255))           AS [Cube]
      , CAST(MEASUREGROUP_NAME AS VARCHAR(255))   AS [Name]
      , CAST(DESCRIPTION AS VARCHAR(4000)) AS [Description]
      , CAST(MEASUREGROUP_NAME AS VARCHAR(255))   AS [Link]
    FROM OPENQUERY(CubeLinkedServer,
       'SELECT [CATALOG_NAME], [CUBE_NAME]
          , [MEASUREGROUP_NAME],
          , [DESCRIPTION]
        FROM $SYSTEM.MDSCHEMA_MEASUREGROUPS')
    WHERE  (CAST([CATALOG_NAME] AS VARCHAR(255))
       = @Catalog OR @Catalog IS NULL)
     AND (CAST([CUBE_NAME] AS VARCHAR(255))
       = @Cube OR @Cube IS NULL)
     AND LEFT(CAST(CUBE_NAME AS VARCHAR(255)),1)
       <>'$' --Filter out dimensions not in a cube

    UNION ALL

   --Measures
    SELECT CAST('Measure' AS VARCHAR(20))         AS [Type]
      , CAST(CATALOG_NAME AS VARCHAR(255))     AS [Catalog]
      , CAST(CUBE_NAME AS VARCHAR(255))           AS [Cube]
      , CAST(MEASURE_NAME AS VARCHAR(255))        AS [Name]
      , CAST(DESCRIPTION AS VARCHAR(4000)) AS [Description]
      , CAST(MEASUREGROUP_NAME AS VARCHAR(255))   AS [Link]
    FROM OPENQUERY(CubeLinkedServer,
      'SELECT [CATALOG_NAME], [CUBE_NAME]
         , [MEASURE_NAME], [DESCRIPTION],
         , [MEASUREGROUP_NAME]
       FROM $SYSTEM.MDSCHEMA_MEASURES
          WHERE [MEASURE_IS_VISIBLE]')
    WHERE  (CAST([CATALOG_NAME] AS VARCHAR(255))
          = @Catalog OR @Catalog IS NULL)
      AND (CAST([CUBE_NAME] AS VARCHAR(255))
          = @Cube OR @Cube IS NULL)
      AND LEFT(CAST(CUBE_NAME AS VARCHAR(255)),1)
          <>'$' --Filter out dimensions not in a cube

    )
    SELECT *
    FROM MetaData
    WHERE @Search<>''
        AND ([Name] LIKE '%' + @Search + '%'
          OR [Description] LIKE '%' + @Search + '%'
        )
GO


We can now use these procs to form the basis of a number of SSRS reports which will dynamically query the DMVs to generate the SSAS cube documentation. I’ll be covering this stage in my next post.

 

© Alex Whittles, Purple Frog Systems Ltd
The Frog Blog

I'm Alex Whittles.

I specialise in designing and implementing SQL Server business intelligence solutions, and this is my blog! Just a collection of thoughts, techniques and ramblings on SQL Server, Cubes, Data Warehouses, MDX, DAX and whatever else comes to mind.

Organising SQLRelay

Submit a session for SQLBits

Frog Blog Out
twitter
rssicon