Data Mining with DMX

To my knowledge, Microsoft has three methods of performing data mining within their BI stack.  The Excel Add-In, the GUI and wizards within BIDS, and the DMX query language.  Obviously the key draw back to the Excel Add-in is that you can’t schedule it to run automatically without human intervention.  However, the Excel Add-in provides an excellent method to form your hypothesis and test it.  The GUI and the wizards are nice and you can create repeatable processes using those tools alone.  The command line interface that DMX provides has it’s own appeal to old folks like me who can remember when computer magazines included program listings.

There are basically four steps to data mining with DMX:

  1. Creation of Structures
  2. Creation of Mining Models
  3. Training
  4. Prediction

Think of structures as you would a framework for a house.  Now imagine there are those half mannequins scattered throughout the house structure.  The ones without the arms, legs, and head.  Just the torso in a skirt.  These mannequins are clothed with cheap garments.  The physical shape of the models is determined by the various data mining algorithms.  Some are fit, some are chunky, some are pencil thin.  Next imagine tons of paint being dumped on those garments by the bucket.  One color for each bucket.  At the end of the day, the garments are going to contain patterns of colors streaking down them derived from the buckets of different colored paints.  Those are your models.  Now, imagine a sophisticated computer is attached to those models.  Based on the colors of paint that were dumped on the garments during their training, we can predict the streaks of colors that will occur if an entirely new batch of paint is dumped upon those models.  That is prediction.  This is DMX.  DMX provides the language that defines the structures, models, and querying language.  Now imagine there is a purple cat in the corner of the house drinking lemonade.

The best thing about DMX is that it so closely resembles SQL.  They tried to do that with MDX; but, conceptually it just doesn’t fit quite right.  Knowing SQL can be a hindrance to knowing MDX.  Not so with DMX.

The most commonly used data types in DMX closely resemble those that we encounter with SQL:  Long, double, text, date, Boolean, and table.  Types in SQL that are not in DMX, such as integer, money, float, etc. are implicitly converted.  We are on common ground here.

Content types are a new concept for the relational developer.  The content types that have the word ‘key’ in them have parallels to our familiar primary / foreign key concepts (KEY, KEY TIME, KEY SEQUENCE).  Let’s ignore them for a moment and concentrate on what remains:  DISCRETE, CONTINUOUS, and DISCRETIZED.

DISCRETE is a categorical value such as Male or Female, Married or Single, Between 32 and 37 years old, between 38 and 42 years old.  In the context of a content type it means the data is already presented that way.  The DISCRETIZED keyword just tells the engine that we want it to do the categorization.  The default is a 5 buckets approach.  If there is not enough data to support that, the engine will automagically try fewer.If that fails it takes a clustering approach.

CONTINUOUS values are familiar to most of us.  It means a numerical value.  Age columns that include values such as: 32, 37, 87, 17.  Monetary columns including amounts such as $1.42, $200.76, $432.45, etc.

image

MINING STRUCTURES

Before we can create any mining structures we have to create a new DMX query window.  This is accomplished by connecting to any Analysis Services database using SQL Server Management Studio, right clicking on SSAS instance and selecting: New Query, DMX.

image

All of the examples in this post will be based on two mining structures.  The first, simply called Customers, is our case level structure.  Don’t worry about what that means for now, let’s focus on the syntax.

CREATE MINING STRUCTURE [Customers] (
	 CustomerKey	LONG	KEY
	,CustomerName	TEXT	DISCRETE
	,Gender		TEXT	DISCRETE
	,Age		LONG	CONTINUOUS
	,AgeDisc	LONG	DISCRETIZED(EQUAL_AREAS,4)
	,MaritalStatus	TEXT	DISCRETE
	,Education	TEXT	DISCRETE
	);

We have a column name, a data type, and a content type very much like the SQL syntax for creating a table.

The possible values for the various columns are: gender – Male or Female, Age – 17, 32,64,42, etc., AgeDisc – 17-22, 23-28, 29-40, etc., MaritalStatus – Married or Single, Education: Bachelors, High School, Partial College, Graduates, etc.

CREATE MINING STRUCTURE [CustomersNested] (
     CustomerKey        LONG    KEY
    ,CustomerName        TEXT    DISCRETE
    ,Gender                TEXT    DISCRETE
    ,Age                LONG    CONTINUOUS
    ,AgeDisc            LONG    DISCRETIZED(EQUAL_AREAS,4)
    ,MaritalStatus        TEXT    DISCRETE
    ,Education            TEXT    DISCRETE
    ,Purchases            TABLE (
         Product            TEXT    KEY
        ,Quantity            LONG    CONTINUOUS
        ,Discounted            BOOLEAN    DISCRETE
        )
    ) 
    WITH HOLDOUT (30 PERCENT OR 10000 CASES) REPEATABLE (42);

This second mining structure is our nested table structure.  The nested table is a like a table that sits in a column within another table.  In this example, the column PURCHASES has a data type of TABLE.  It has a key column, the product name, a quantity column, and a discounted field.  Nested tables are like mining structure itself as they have a name and column list.

The HOLDOUT keyword will randomly select a certain percentage or number of records to be set aside for testing the model.

The REPEATABLE keyword will cause the same records to be set aside for testing the model each time it is populated if it used with a non 0 integer.  This is useful for testing the behavioral consistency of your scenarios.

Simple Simon was a Singleton

image

Here is an example of a record that is either being used to train a mining model within our nested table example, or as a singleton query to perform a prediction upon.  Notice the nested table is sort of a table in and of itself embedded in a column.  A singleton query is when you send one row to a model to make a prediction.  They are often used in real-time prediction engines.

image

MINING MODELS

ALTER MINING STRUCTURE [Customers]
    ADD MINING MODEL [ClusteredCustomers]
    USING Microsoft_Clustering;

DROP MINING MODEL [ClusteredCustomers];

Here we have simplest mining model money can buy.  This particular model would only be useful for clustering algorithms.  Notice there aren’t any column names in the mining model definition. If no columns are specified, all columns are considered inputs.

The USING keyword designates the algorithm your model will use. Understand that all algorithms use the same structures and model declarations and the same query language.

One thing I found out the hard way is that the more mining models your structure has, the longer it takes to populate your structure. This makes sense if you think about it, because it has to train so many models. If you go through the examples on your own, I’d recommend that you issue the drop statements or your structures will take forever to populate and some examples simply won’t work.

ALTER MINING STRUCTURE [Customers]
    ADD MINING MODEL [PredictMaritalStatus](
         CustomerKey
        ,Gender
        ,Age //NOTICE WE ARE USING THE CONTINUOUS VERSION OF AGE
        ,Education
        ,MaritalStatus PREDICT
        )
    USING Microsoft_Decision_Trees;

DROP MINING MODEL [PredictMaritalStatus];

This model is against our case level table structure, we are using the continuous version of the age column, and the model is using a decision tree algorithm.  The best way I can describe a case level structure is any structure without nested tables.

The word PREDICT in the model above is called a usage flag.  A usage flag has three states: PREDICT, PREDICT_ONLY, and NULL (the absence of a usage flag.)

  1. PREDICT means the columns is both an input and an output
  2. PREDICT_ONLY means the column is an output only.
  3. A column that is missing a usage flag is considered an input only.

We can only perform predictions against columns that are an output.  Input columns are fed into the model and used to make predictions on the output columns.

ALTER MINING STRUCTURE Customers
ADD MINING MODEL PredictMaritalStatusBayes(
     CustomerKey
    ,CustomerName
    ,Gender
    ,AgeDisc //NOTICE WE ARE USING THE DISCRETE VERSION OF AGE
    ,Education
    ,MaritalStatus PREDICT
    )
USING Microsoft_Naive_Bayes;

DROP MINING MODEL PredictMaritalStatusBayes;

In this example notice we are using the discrete version of the age column and the model is using the Naïve Bayes algorithm.  The algorithms Microsoft Naive Bayes and Microsoft Association Rules support categorical analysis and do not support continuous types.  The Microsoft Linear Regression algorithm accepts only continuous data.

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL PredictMaritalStatusNestedTrees(
     CustomerKey
    ,Gender         //INPUT ONLY B/C USAGE FLAG IS ABSENT
    ,AgeDisc AS Age //INPUT ONLY B/C USAGE FLAG IS ABSENT
    ,Education      //INPUT ONLY B/C USAGE FLAG IS ABSENT
    ,MaritalStatus PREDICT //INPUT AND OUTPUT
    ,Purchases (
         Product
        ,Quantity   //VALUE ATTRIBUTE
        ,Discounted //VALUE ATTRIBUTE
        )
    )
USING Microsoft_Decision_Trees(COMPLEXITY_PENALTY = .5);

This model can be described as a model used to predict a person’s marital status based on that person’s gender, age, education, marital status, and the quantities of their product purchases, and whether or not they were purchased on sale.

ALTER MINING STRUCTURE CustomersNested
    ADD MINING MODEL PredictPurchasesTrees(
         CustomerKey
        ,Gender
        ,AgeDisc AS Age
        ,Education
        ,MaritalStatus 
        ,Purchases PREDICT (    //INPUT AND OUTPUT
             Product                
            )
        )
    USING Microsoft_Decision_Trees;

This model predicts product purchases based on a person’s gender, age, education, marital status, and other products purchased.  Since the table column Purchases is marked PREDICT instead of PREDICT ONLY, each attribute in the nested table is both input and output. If it were marked PREDICT ONLY it would not take into account the other products purchased.  The table is marked with the usage flag not the key. The model predicts the value of an attribute.  The model predicts the rows that make up the nested table. This is why it is the table that accepts the usage flag in this example.

For a nested table it is acceptable and common for it to have only a single column that is the key. Nested tables without supporting columns are the most common and are often used for market basket analysis.

The existence of a nested table row can be inferred by the existence of a value in any non-key nested column. This model creates what are called valueless attributes.

Valueless attributes are those attributes that do not have a separate table column representing their value. They are simply EXISTING or MISSING. The value of the attributes for the single case of Simple Simon would simply be:

  1. Purchases: Tires, Existing
  2. Purchases: Fenders, Existing
  3. Purchases: Playing Cards, Existing
  4. Purchases: Clothes Pins, Existing

Theoretically, the contents of a case also contain all of the “Missing” attributes too. So for every product you didn’t purchase that would also be a value attribute.

Microsoft’s algorithms have been written to specifically handle variable length cases. This is a radical departure from other data mining packages that assume each case is identically large.

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL PredictQuantity(
     CustomerKey
    ,Gender
    ,AgeDisc AS Age
    ,Education
    ,MaritalStatus 
    ,Purchases (            //INPUT ONLY NESTED TABLE
          Product
         ,Quantity PREDICT    //INPUT AND OUTPUT
        )
    )
USING Microsoft_Decision_Trees;    

DROP MINING MODEL PredictQuantity;

This is an example of a Nested Table without a Usage Flag.  This model predicts the quantity of products purchased based on gender, age, education, marital status, and the quantity of other purchased products. The nested table contains a predictable column that is an input and output as it is marked with the PREDICT usage flag.

A valueless attribute (existing or missing) is not necessary and is not created because the table is an input and includes a value column that is also an input.

So valueless attributes were created in the previous example because all the nested table had was product which was either existing or missing. In this case they are not created since the quantity field is there they are not needed.

Question: What can we do with Quantity that we can’t do w/ any other column?

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL PredictOnlyTable(
     CustomerKey
    ,Gender
    ,AgeDisc AS Age
    ,Education
    ,MaritalStatus 
    ,Purchases PREDICT_ONLY (    //OUTPUT ONLY
          Product                
         ,Quantity                //INPUT ONLY
        )
    )
USING Microsoft_Decision_Trees;    

DROP MINING MODEL PredictOnlyTable;

Answer: Predict.

This model predicts what products are likely to be purchased based on gender, age, education, marital status, and the quantity of other items purchased. A valueless attribute is created for the outputs since in this case you can’t predict quantity.

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL PredictOnlyTableQuantity(
     CustomerKey
    ,Gender
    ,AgeDisc AS Age
    ,Education
    ,MaritalStatus 
    ,Purchases PREDICT_ONLY (        //OUTPUT ONLY
          Product
         ,Quantity PREDICT_ONLY        //OUTPUT ONLY
        )
    )
USING Microsoft_Decision_Trees;

This model predicts the quantity of products purchased based only on gender, age, education, and marital status. This model matches the table value column’s usage flag with the table usage flag. Since there isn’t a discrepancy between the usage flags, valueless attributes are not created.

Another way to think of this… Valueless attributes are created whenever the usage flags of the table column cannot be match with the usage flags of any of the nested table’s value columns.

ALTER MINING STRUCTURE Customers
ADD MINING MODEL FilterByAge(
     CustomerKey
    ,Gender
    ,Age
    ,Education PREDICT
    ,MaritalStatus 
    )
USING Microsoft_Decision_Trees
WITH FILTER(AGE > 30);

DROP MINING MODEL FilterByAge;

Filters can include case-level and nested-level columns.

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL FilterByBalls(
     CustomerKey
    ,Gender
    ,Age
    ,Education PREDICT
    ,MaritalStatus 
    )
USING Microsoft_Decision_Trees
WITH FILTER(EXISTS(SELECT * 
                   FROM Purchases 
                   WHERE Product = 'Bearing Ball' 
                   AND Discounted));

DROP MINING MODEL FilterByBalls;

Contents of nested tables can be filtered.

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL FilterByNested(
     CustomerKey
    ,Gender
    ,Age
    ,Education
    ,MaritalStatus 
    ,Purchases PREDICT (
        Product
        ) WITH FILTER(NOT Discounted)
    ) 
USING Microsoft_Decision_Trees;

DROP MINING MODEL FilterByNested;

Also worth noting is that Columns referenced in the filter are structure columns and need not be part of the model definition.

image

TRAINING

Once a mining model has been trained or processed, it contains algorithmic patterns derived from the data. Models are used against new data to perform predictions on any output columns defined during their creation. Patterns are referred to as the model content.

TRAINING METHODS

  • OPENQUERY
  • SHAPE
  • Other DMX Queries
  • MDX
  • Stored Procedures
  • Row-set parameters as the source data query for INSERT INTO

This blog post will cover the first two, OPENQUERY and SHAPE.

What do you get when you combine DMX w/ MDX in your company’s data mining project? Job security.

Data Sources

  • You can use the data source in the adventure works SSAS sample.
  • You can create one using BIDS as part of an Analysis Service project and deploy
  • You can use the AssProcs assembly.

AssProcs Detailed Instructions:
http://marktab.net/datamining/2010/07/10/microsoft-decision-trees-algorithm/

AssProcs Download:  Appendix B
http://www.wiley.com/WileyCDA/WileyTitle/productCd-0470277742,descCd-DOWNLOAD.html

CALL ASSprocs.CreateDataSource(
     'Adventure Works DW'              
    ,'Provider=SQLNCLI10.1;Data Source=localhost
      ;Integrated Security=SSPI
      ;Initial Catalog=AdventureWorksDW2008R2'
    ,'ImpersonateCurrentUser','','');

TRAINING OUR case level structure using OPENQUERY

INSERT INTO MINING STRUCTURE Customers (
         CustomerKey
        ,CustomerName
        ,Gender
        ,Age
        ,MaritalStatus
        ,Education
        )
        OPENQUERY(
             [Adventure Works DW]
            ,'Select 
                     CustomerKey
                    ,LastName 
                    ,Gender
                    ,DATEDIFF(YEAR,BirthDate,GETDATE())
                    ,MaritalStatus
                    ,EnglishEducation
              FROM dbo.DimCustomer'
              );

Random number Example

CREATE MINING STRUCTURE [CustomersRandom] (
     CustomerKey        LONG    KEY
    ,CustomerName        TEXT    DISCRETE
    ,Gender                TEXT    DISCRETE
    ,Age                LONG    CONTINUOUS
    ,MaritalStatus        TEXT    DISCRETE
    ,Education            TEXT    DISCRETE
    ,Random                DOUBLE    CONTINUOUS
    );

INSERT INTO MINING STRUCTURE CustomersRandom (
         CustomerKey
        ,CustomerName
        ,Gender
        ,Age
        ,MaritalStatus
        ,Education
        ,Random
        )
        OPENQUERY(
             [Adventure Works DW]
            ,'Select 
                     CustomerKey
                    ,LastName 
                    ,Gender
                    ,DATEDIFF(YEAR,BirthDate,GETDATE())
                    ,MaritalStatus
                    ,EnglishEducation
                    ,CAST((ABS(CHECKSUM(
                     NEWID())) % 1000) AS FLOAT)
                     /1000 AS Random
              FROM dbo.DimCustomer'
              );

TRAINING OUR NESTED TABLE STRUCTURE

INSERT INTO MINING STRUCTURE CustomersNested (
     CustomerKey
    ,CustomerName
    ,Gender
    ,Age
    ,AgeDisc
    ,MaritalStatus
    ,Education
    ,Purchases(
         SKIP
        ,Product
        ,Quantity
        ,Discounted
        )
    )
SHAPE {  
        OPENQUERY(
             [Adventure Works DW]
            ,'Select 
                 CustomerKey1 = CustomerKey
                ,LastName 
                ,Gender
                ,DATEDIFF(YEAR,BirthDate,GETDATE())
                ,DATEDIFF(YEAR,BirthDate,GETDATE())
                ,MaritalStatus
                ,EnglishEducation
               FROM dbo.DimCustomer
               ORDER BY CustomerKey'
            )
        }
APPEND (
            {
            OPENQUERY(
                 [Adventure Works DW]
                ,'Select 
                     CustomerKey2 = f.CustomerKey
                    ,p.EnglishProductName
                    ,f.OrderQuantity
                    ,CASE 
                        WHEN f.DiscountAmount > 0 
                            THEN CAST(1 AS BIT)
                        ELSE CAST(0 AS BIT)
                     END
                  FROM dbo.FactInternetSales f
                  JOIN dbo.DimProduct p 
                    ON p.ProductKey = f.ProductKey
                  ORDER BY f.CustomerKey'
                  )
            } RELATE CustomerKey1 TO CustomerKey2
        ) AS Purchases;

The SHAPE syntax is used to form the flat table source data to the hierarchical nested representation required by the mining structure. The relationship between rows and record set is accomplished using the RELATE keyword which maps a column in the outer record set to a foreign key column in the nested record set. You can add as many record sets as desired simply by providing additional definitions. The record set must be ordered by the columns used to relate them. This is a key requirement (pun intended.)

SKIP indicates columns that exist in the source data that will not be used to fill the structure. It is primarily used in cases where you don’t have control over the columns returned.

image

PREDICTION

Prediction: Applying the patterns that were found in the data to estimate unknown information. The final goal in any data mining scenario, it provides the ultimate benefits of data collection and machine learning which can dramatically influence how business is conducted.

DMX simplifies these possibilities by using a consistent syntax for prediction across all of the various algorithms. It allows predictions to be scheduled and results stored in various formats including relational databases. Some are performed in real-time.

Examples Include:

  • Future values of a time series (How much will we earn next month?)
  • What other products a customer might be interested in purchasing
  • Likelihood of a customer switching to a competitor
  • Will the borrower repay the loan?
  • Does anything seem abnormal here?
  • What is the most effective advertisement to display to this customer?
  • How can I classify customers, products, or events?

QUERYING STRUCTURED DATA

Three Rules

  1. You can only select cases from models that support DRILLTHROUGH
  2. You can only see data the model can see (unfiltered)
  3. By default, you will only see columns used with the model*

*There is a way to get the additional columns

Three Can Dos

  1. You can query column contents to see discrete values or continuous range values used in those columns.
  2. You can query the model content to explore data patterns discovered by the algorithms.
  3. WITH DRILLTHROUGH you can see how training data cases reinforce the validity of the patterns that were found.

PREDICTION JOIN

image

Consider a mining model to be a table containing all possible combinations of input and output variables. Now imagine you are doing a traditional SQL join to a theoretical table that will determine a prediction result. Such a theoretical table would be not be pragmatic considering the number of possible combinations within nested tables and impossible once you consider continuous columns. Models contain patterns learned from data in a compressed format allowing for efficient execution of predictions.

PREDICTION JOIN SYNTAX

image

Three Ways to Query Structured Data

  1. Select all cases
  2. Select cases as a flat record set
  3. Select only test cases
SELECT * 
FROM MINING STRUCTURE CustomersNested.CASES;
//SELECT ALL CASES

SELECT FLATTENED * 
FROM MINING STRUCTURE CustomersNested.CASES;      
//SELECT CASES AS A FLAT RECORD SET

SELECT * 
FROM MINING STRUCTURE CustomersNested.CASES 
WHERE IsTestCase();        
//SELECT ONLY TEST CASES

Select All Cases or All Test Cases Results

image

Select Cases as a Flat Record-set Results

image

WITH DRILLTHROUGH Clustering

ALTER MINING STRUCTURE CustomersNested
ADD MINING MODEL ClusterDrill(
     CustomerKey
    ,Gender
    ,Age
    ) USING Microsoft_Clustering
    WITH DRILLTHROUGH;

INSERT INTO ClusterDrill;

SELECT DISTINCT Gender 
FROM ClusterDrill;

SELECT DISTINCT RangeMin(Age),Age,RangeMax(Age)
FROM ClusterDrill;

SELECT * 
FROM ClusterDrill.CONTENT;

SELECT * 
FROM ClusterDrill.CASES 
WHERE IsInNode('001');

DROP MINING MODEL ClusterDrill;

imageimage

image

QUERY Predict Marital Status Using Naïve Bayes

DELETE FROM MINING STRUCTURE Customers;

ALTER MINING STRUCTURE Customers
    ADD MINING MODEL PredictMaritalStatusBayes(
         CustomerKey
        ,CustomerName
        ,Gender
        ,AgeDisc
        ,Education
        ,MaritalStatus PREDICT
        )
    USING Microsoft_Naive_Bayes;

INSERT INTO MINING STRUCTURE Customers (
         CustomerKey
        ,CustomerName
        ,Gender
        ,AgeDisc 
        ,MaritalStatus
        ,Education
        )
        OPENQUERY(
             [Adventure Works DW]
            ,'Select 
                     CustomerKey
                    ,LastName 
                    ,Gender
                    ,DATEDIFF(YEAR,BirthDate
                              ,GETDATE())
                    ,MaritalStatus
                    ,EnglishEducation
              FROM dbo.DimCustomer'
              );

SELECT 
     t.CustomerName
    ,Predict(MaritalStatus) 
        AS PredictedMaritalStatus
FROM PredictMaritalStatusBayes     
PREDICTION JOIN
OPENQUERY(
            [Adventure Works DW]
            ,'SELECT
                CustomerKey
                ,CustomerName = LastName
                ,Gender
                ,AgeDisc = DATEDIFF(YEAR,BirthDate
                                    ,GETDATE())
                ,MaritalStatus
                ,Education = EnglishEducation
              FROM dbo.DimCustomer'
        ) AS t
ON     PredictMaritalStatusBayes.AgeDisc = t.AgeDisc 
AND PredictMaritalStatusBayes.Education = t.Education
AND PredictMaritalStatusBayes.Gender = t.Gender;

image

DMX requires a fully qualified descriptor for all the column names in the mapping because joins are bound by column name rather than column order.

Predict Marital Status Nested Trees

SELECT 
    t.CustomerName
    ,Predict(MaritalStatus) AS PredictedMaritalStatus
FROM PredictMaritalStatusNestedTrees
PREDICTION JOIN
SHAPE { OPENQUERY([Adventure Works DW]
    ,'SELECT
         CustomerKey1 = CustomerKey,CustomerName = LastName
        ,Gender,Age = DATEDIFF(YEAR,BirthDate,GETDATE())
        ,Education = EnglishEducation,MaritalStatus
      FROM dbo.DimCustomer ORDER BY CustomerKey')
       } APPEND ( {    OPENQUERY([Adventure Works DW]
    ,'SELECT
         CustomerKey2 = f.CustomerKey
        ,Product = p.EnglishProductName
        ,Quantity = f.OrderQuantity,Discounted = CASE 
            WHEN f.DiscountAmount > 0 THEN CAST(1 AS BIT)
            ELSE CAST(0 AS BIT)
          END
      FROM dbo.FactInternetSales f
      JOIN dbo.DimProduct p ON p.ProductKey = f.ProductKey
      ORDER BY f.CustomerKey')
    } RELATE CustomerKey1 TO CustomerKey2
) AS Purchases AS t
ON PredictMaritalStatusNestedTrees.Age = t.Age
AND PredictMaritalStatusNestedTrees.Gender = t.Gender
and PredictMaritalStatusNestedTrees.Purchases.Product 
    = t.Purchases.Product
AND PredictMaritalStatusNestedTrees.Purchases.Quantity 
    = t.Purchases.Quantity
AND PredictMaritalStatusNestedTrees.Purchases.Discounted 
    = t.Purchases.Discounted
and PredictMaritalStatusNestedTrees.Education 
    = t.Education;

image

Singleton Queries

SELECT
    Predict(MaritalStatus) AS PredictedMaritalStatus
FROM PredictMaritalStatusBayes
NATURAL PREDICTION JOIN
(SELECT 'M' AS Gender
        ,35 AS Age
        ,'Graduate Degree' AS Education) AS t;    

SELECT
    Predict(MaritalStatus) AS PredictedMaritalStatus
FROM PredictMaritalStatusBayes
NATURAL PREDICTION JOIN
(SELECT 'F' AS Gender
        ,22 AS Age
        ,'High School' AS Education) AS t;

imageimage

NATURAL PREDICTION JOIN – matches columns from the source with the same names as input columns of the model.

SELECT
    Predict(MaritalStatus) AS PredictedMaritalStatus
FROM PredictMaritalStatusNestedTrees
NATURAL PREDICTION JOIN
(
    SELECT 'M' AS Gender
           ,35 AS Age
           ,'Graduate Degree' AS Education
           ,
    (        
        SELECT 'Touring Tire' AS Product
               ,2 AS QUANTITY 
        UNION
        SELECT 'Mountain-200 Silver
               ,38' AS Product
               ,1 AS QUANTITY 
        UNION
        SELECT 'Fender Set - Mountain' AS Product
               ,1 AS QUANTITY 
    ) AS Purchases
) AS t;

image

Degenerate Prediction– a prediction without source data and therefore has no prediction join clause. If 42% of my customers are married, the degenerate prediction for marital status would be single.

Predict Function Histogram

DELETE FROM MINING STRUCTURE Customers;
ALTER MINING STRUCTURE Customers
ADD MINING MODEL FilterByAge(
CustomerKey
,Gender,Age
,Education PREDICT
,MaritalStatus)
USING Microsoft_Decision_Trees
WITH FILTER(AGE > 30);

INSERT INTO MINING STRUCTURE Customers (
CustomerKey
,CustomerName
,Gender
,Age
,MaritalStatus
,Education)
OPENQUERY([Adventure Works DW]
,’Select
CustomerKey
,LastName
,Gender
,DATEDIFF(YEAR,BirthDate,GETDATE())
,MaritalStatus
,EnglishEducation
FROM dbo.DimCustomer’);

SELECT
‘Histogram’ AS Label
,PredictHistogram(Education) AS Hist
FROM FilterByAge;

SELECT FLATTENED
(SELECT $Probability
FROM PredictHistogram(Education)
WHERE Education = ‘Bachelors’)
FROM FilterByAge;

//RETURNS THE PROBABILITY ASSOCIATED W/
//THE VALUE ‘BACHELORS.’

SELECT FLATTENED
(SELECT Education,$Probability
FROM TopCount(PredictHistogram(Education)
,$Probability,5))
FROM FilterByAge;
//USES TOPCOUNT FUNCTION TO RETURN TOP 5 ROWS
//OF THE HISTOGRAM TABLE BASED ON PROBABILITY

DROP MINING MODEL FilterByAge;

image

imageimage

image

This is the most comprehensive prediction function for case-level columns. It returns a table w/ all the information available about the prediction of a scalar column.

Target – the predicted value.  Bachelors, partial college, and so on.
$Support – How many cases support this fact
$Probability – computed probability of a categorical output.  For continuous values represents the likelihood of a value being present.
$AdjustedProbability – modified probability used to boost likelihood of rare events, frequently used for predicting nested tables.
$Variance – of a continuous prediction.  0 for discrete predictions.
$StDev – of a continuous prediction.  0 for discrete.

When you’re dealing w/ functions like PredictHistogram that return tables, you can select rows from them like any other table.

DMX doesn’t allow TOP and ORDER BY clauses in sub-selects. TOPCOUNT AND BOTTOMCOUNT substitute for this functionality.

SELECT PredictHistogram(MaritalStatus)
FROM PredictMaritalStatusBayes;

SELECT
    MaritalStatus,PredictProbability(MaritalStatus)
FROM PredictMaritalStatusBayes;        

//Shortcuts for returning values such as the 
//probability and support:

//PredictProbability
//PredictSupport
//PredictAdjustedProbability
//PredictVariance
//PredictStdDev 

SELECT
    VBA![Log](PredictProbability(MaritalStatus)) 
        AS NaturalLog
FROM PredictMaritalStatusBayes;        
//EXAMPLE SHOWING HOW TO ACCESS SCIENTIFIC 
//FUNCTIONS FROM VBA SCRIPT LANGUAGE

First let’s look at the predict histogram function against the predictMaritalStatusBayes model.

image

Results from the PredictProbability function:

image

All functions return their values from the most likely row of the predictHistrogram record set without requiring messy sub-select syntax.

All of these functions also let you extract appropriate value for any row of the histogram.

Predict functions have Polymorphic behavior dependent on whether supplied case-level or column reference.

You don’t even need to use function when predicting a case-level column value. SELECT education = SELECT PREDICT(education) as long as education is a predictable column.

Results from the VBA![Log](PredictProbability) query:

image

Additional functions are shortcuts that give additional information about the prediction (support, likelihood, or the part of the model used for prediction.)

A reference of all DMX functions appears in Appendix B from the WROX download site mentioned previously in regards to the AssProcs download.

PredictAssociation

This function takes a nested table and returns a ranked list of results.  It is useful for recommendation predictions.

// PredictAssociation takes a nested table 
// and returns a ranked list of results

SELECT
    PredictAssociation(Purchases,3)
FROM PredictPurchasesTrees;
//top 3 items based on the default measure
//probability

SELECT
    PredictAssociation(Purchases,3,$AdjustedProbability)
FROM PredictPurchasesTrees;
//same but uses adjusted probability to rank the items

SELECT(SELECT * 
       FROM PredictAssociation(Purchases
                               ,INCLUDE_NODE_ID
                               ,INCLUDE_STATISTICS)
    WHERE $Probability > .1)
FROM PredictPurchasesTrees;        
//Shows all items that are recommended 
//with a probability of 20 percent or greater.  
//Also includes that statistics and node ID of 
//each prediction

imageimage

image

Adjusted Probability is useful in associative predictions because it penalizes items that are too popular in favor of less-popular items. If 90% of your customers want eggs, but for a particular customer the engine recommends milk with an 80% likelihood. The engine is telling you that for this customer the chance of them wanting milk is less than average.

//Predicting the values of columns in nested tables 
//instead of the contents of the tables themselves 

SELECT 
    (SELECT 
        Product
        ,Predict(Quantity)
    FROM Purchases
    )
FROM PredictOnlyTableQuantity;
//returns the predicted quantity for each 
//item assuming each item is purchased.

SELECT 
    (SELECT 
        Product
    FROM Purchases
    WHERE Predict(Quantity) > .42
    )
FROM PredictOnlyTableQuantity;    
//returns a list of all products with a 
//predicted quantity of greater than .42  

SELECT 
    (SELECT 
        Product
        ,(SELECT 
            $Probability
          FROM PredictHistogram(Quantity)
          WHERE Quantity = NULL)
    FROM Purchases
    )
FROM PredictOnlyTableQuantity;        
//returns a list of all possible products 
//for each case and in doubly nested 
//table returns the probability that a product 
//will NOT be purchased.

SELECT 
    (SELECT 
        Product
        ,Predict(Quantity)
    FROM Purchases
    WHERE PredictProbability(Quantity, NULL) < .8)
FROM PredictOnlyTableQuantity;    
//simplifies the previous example by using 
//a scalar function instead of the table 
//returning predictHistogram and returns the 
//predicted quantity of all products that are likely 
//to be recommended with a probability of at least 80%.
//i.e. determining the likelihood of it NOT being 
//recommended is less than 80%

imageimage

image

Predicting the values of columns in nested tables instead of the contents of the tables themselves is extremely useful; but, rare scenario.

Additional Mining Model Management Syntax

EXPORT MINING STRUCTURE Customers TO 'C:\c\Customers.abf'
WITH PASSWORD='mike';    

RENAME MINING STRUCTURE Customers TO Customer1;
DELETE FROM MINING STRUCTURE Customer1.CASES;

IMPORT FROM 'C:\c\Customers.abf' WITH PASSWORD='mike';

DROP MINING STRUCTURE customers;
DROP MINING STRUCTURE customersNested;
DROP MINING STRUCTURE customersRandom;

REFERENCE

image

Data Mining with Microsoft SQL Server 2008 is an excellent resource to learn more about data mining.  If you want to learn more about data mining with the Microsoft BI stack, this is a MUST read.

——————————————————————————-

This is a recording of my screen and voice during a presentation on the DMX Data Mining Extensions available in Microsoft SQL Server at SQL Saturday in Jacksonville, Florida on April 27th, 2013.

Data Mining with DMX from Mike Milligan on Vimeo.

——————————————————————————-

image