Skip to content

Commit

Permalink
SPS08 Updates
Browse files Browse the repository at this point in the history
  • Loading branch information
saphanaacademy committed Aug 29, 2014
1 parent b1bb040 commit 7ebea19
Show file tree
Hide file tree
Showing 24 changed files with 1,292 additions and 5 deletions.
12 changes: 12 additions & 0 deletions Code Snippets/PAL 53 Getting Started with SPS08.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
-- CHECK AFL PAL FUNCTIONS ARE INSTALLED
SELECT * FROM SYS.AFL_FUNCTIONS WHERE PACKAGE_NAME='PAL';

-- START SCRIPT SERVER
ALTER SYSTEM ALTER CONFIGURATION ('daemon.ini', 'SYSTEM') SET ('scriptserver', 'instances') = '1' WITH RECONFIGURE;

-- CREATE USER FOR AFL DEVELOPMENT
CREATE USER AFLUSER PASSWORD Password1;
GRANT CREATE ANY, ALTER, DROP, EXECUTE, SELECT, INSERT, UPDATE, DELETE, INDEX, DEBUG, TRIGGER, REFERENCES ON SCHEMA PAL TO AFLUSER;
GRANT EXECUTE ON SYSTEM.AFL_WRAPPER_GENERATOR TO AFLUSER;
GRANT EXECUTE ON SYSTEM.AFL_WRAPPER_ERASER TO AFLUSER;
GRANT AFL__SYS_AFL_AFLPAL_EXECUTE TO AFLUSER;
62 changes: 62 additions & 0 deletions Code Snippets/PAL 54 Clustering - Kmeans Best K.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_KM_DATA;
DROP TYPE PAL_T_KM_PARAMS;
DROP TYPE PAL_T_KM_RESULTS;
DROP TYPE PAL_T_KM_CENTERS;
DROP TABLE PAL_KM_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_KM');
DROP VIEW V_KM_DATA;
DROP TABLE KM_RESULTS;
DROP TABLE KM_CENTERS;
DROP VIEW V_KM_RESULTS;

-- PAL setup
CREATE TYPE PAL_T_KM_DATA AS TABLE (ID INTEGER, LIFESPEND DOUBLE, NEWSPEND DOUBLE, INCOME DOUBLE, LOYALTY DOUBLE);
CREATE TYPE PAL_T_KM_PARAMS AS TABLE (NAME VARCHAR(60), INTARGS INTEGER, DOUBLEARGS DOUBLE, STRINGARGS VARCHAR(100));
CREATE TYPE PAL_T_KM_RESULTS AS TABLE (ID INTEGER, CENTER_ID INTEGER, DISTANCE DOUBLE);
CREATE TYPE PAL_T_KM_CENTERS AS TABLE (CENTER_ID INTEGER, LIFESPEND DOUBLE, NEWSPEND DOUBLE, INCOME DOUBLE, LOYALTY DOUBLE);

CREATE COLUMN TABLE PAL_KM_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_KM_SIGNATURE VALUES (1, 'PAL.PAL_T_KM_DATA', 'in');
INSERT INTO PAL_KM_SIGNATURE VALUES (2, 'PAL.PAL_T_KM_PARAMS', 'in');
INSERT INTO PAL_KM_SIGNATURE VALUES (3, 'PAL.PAL_T_KM_RESULTS', 'out');
INSERT INTO PAL_KM_SIGNATURE VALUES (4, 'PAL.PAL_T_KM_CENTERS', 'out');

GRANT SELECT ON PAL_KM_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_KM', 'AFLPAL', 'KMEANS', PAL_KM_SIGNATURE);

-- app setup
CREATE VIEW V_KM_DATA AS
SELECT ID, LIFESPEND, NEWSPEND, INCOME, LOYALTY
FROM CUSTOMERS
;
CREATE COLUMN TABLE KM_RESULTS LIKE PAL_T_KM_RESULTS;
CREATE COLUMN TABLE KM_CENTERS LIKE PAL_T_KM_CENTERS;
CREATE VIEW V_KM_RESULTS AS
SELECT a.ID, b.CUSTOMER, b.LIFESPEND, b.NEWSPEND, b.INCOME, b.LOYALTY, a.CENTER_ID + 1 AS CLUSTER_NUMBER
FROM KM_RESULTS a, CUSTOMERS b
WHERE a.ID = b.ID
;

-- app runtime
DROP TABLE #KM_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #KM_PARAMS LIKE PAL_T_KM_PARAMS;
INSERT INTO #KM_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #KM_PARAMS VALUES ('GROUP_NUMBER', 3, null, null);
--INSERT INTO #KM_PARAMS VALUES ('GROUP_NUMBER_MIN', 2, null, null);
--INSERT INTO #KM_PARAMS VALUES ('GROUP_NUMBER_MAX', 10, null, null);
INSERT INTO #KM_PARAMS VALUES ('INIT_TYPE', 1, null, null);
INSERT INTO #KM_PARAMS VALUES ('DISTANCE_LEVEL', 2, null, null);
INSERT INTO #KM_PARAMS VALUES ('MAX_ITERATION', 100, null, null);
INSERT INTO #KM_PARAMS VALUES ('NORMALIZATION', 0, null, null);
INSERT INTO #KM_PARAMS VALUES ('EXIT_THRESHOLD', null, 0.0001, null);

TRUNCATE TABLE KM_RESULTS;
TRUNCATE TABLE KM_CENTERS;

CALL _SYS_AFL.PAL_KM (V_KM_DATA, #KM_PARAMS, KM_RESULTS, KM_CENTERS) WITH OVERVIEW;

SELECT * FROM KM_RESULTS;
SELECT * FROM KM_CENTERS;
65 changes: 65 additions & 0 deletions Code Snippets/PAL 55 Clustering - Kmedoids.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_KM_DATA;
DROP TYPE PAL_T_KM_PARAMS;
DROP TYPE PAL_T_KM_RESULTS;
DROP TYPE PAL_T_KM_CENTERS;
DROP TABLE PAL_KM_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_KM');
DROP VIEW V_KM_DATA;
DROP TABLE KM_RESULTS;
DROP TABLE KM_CENTERS;
DROP VIEW V_KM_RESULTS;
DROP VIEW V_KM_CENTERS;

-- PAL setup
CREATE TYPE PAL_T_KM_DATA AS TABLE (ID INTEGER, LIFESPEND DOUBLE, NEWSPEND DOUBLE, INCOME DOUBLE, LOYALTY DOUBLE);
CREATE TYPE PAL_T_KM_PARAMS AS TABLE (NAME VARCHAR(60), INTARGS INTEGER, DOUBLEARGS DOUBLE, STRINGARGS VARCHAR(100));
CREATE TYPE PAL_T_KM_RESULTS AS TABLE (ID INTEGER, CENTER_ID INTEGER, DISTANCE DOUBLE);
CREATE TYPE PAL_T_KM_CENTERS AS TABLE (CENTER_ID INTEGER, LIFESPEND DOUBLE, NEWSPEND DOUBLE, INCOME DOUBLE, LOYALTY DOUBLE);

CREATE COLUMN TABLE PAL_KM_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_KM_SIGNATURE VALUES (1, 'PAL.PAL_T_KM_DATA', 'in');
INSERT INTO PAL_KM_SIGNATURE VALUES (2, 'PAL.PAL_T_KM_PARAMS', 'in');
INSERT INTO PAL_KM_SIGNATURE VALUES (3, 'PAL.PAL_T_KM_RESULTS', 'out');
INSERT INTO PAL_KM_SIGNATURE VALUES (4, 'PAL.PAL_T_KM_CENTERS', 'out');

GRANT SELECT ON PAL_KM_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_KM', 'AFLPAL', 'KMEDOIDS', PAL_KM_SIGNATURE);

-- app setup
CREATE VIEW V_KM_DATA AS
SELECT ID, LIFESPEND, NEWSPEND, INCOME, LOYALTY
FROM CUSTOMERS
;
CREATE COLUMN TABLE KM_RESULTS LIKE PAL_T_KM_RESULTS;
CREATE COLUMN TABLE KM_CENTERS LIKE PAL_T_KM_CENTERS;
CREATE VIEW V_KM_RESULTS AS
SELECT a.ID, b.CUSTOMER, b.LIFESPEND, b.NEWSPEND, b.INCOME, b.LOYALTY, a.CENTER_ID + 1 AS CLUSTER_NUMBER
FROM KM_RESULTS a, CUSTOMERS b
WHERE a.ID = b.ID
;
CREATE VIEW V_KM_CENTERS AS
SELECT CENTER_ID + 1 AS CLUSTER_NUMBER, LIFESPEND, NEWSPEND, INCOME, LOYALTY
FROM KM_CENTERS
;

-- app runtime
DROP TABLE #KM_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #KM_PARAMS LIKE PAL_T_KM_PARAMS;
INSERT INTO #KM_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #KM_PARAMS VALUES ('GROUP_NUMBER', 3, null, null);
INSERT INTO #KM_PARAMS VALUES ('INIT_TYPE', 1, null, null);
INSERT INTO #KM_PARAMS VALUES ('DISTANCE_LEVEL', 2, null, null);
INSERT INTO #KM_PARAMS VALUES ('MAX_ITERATION', 100, null, null);
INSERT INTO #KM_PARAMS VALUES ('NORMALIZATION', 0, null, null);
INSERT INTO #KM_PARAMS VALUES ('EXIT_THRESHOLD', null, 0.0001, null);

TRUNCATE TABLE KM_RESULTS;
TRUNCATE TABLE KM_CENTERS;

CALL _SYS_AFL.PAL_KM (V_KM_DATA, #KM_PARAMS, KM_RESULTS, KM_CENTERS) WITH OVERVIEW;

SELECT * FROM V_KM_RESULTS;
SELECT * FROM V_KM_CENTERS;
41 changes: 41 additions & 0 deletions Code Snippets/PAL 56 Time Series - ARIMA Model.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_TS_DATA;
DROP TYPE PAL_T_TS_PARAMS;
DROP TYPE PAL_T_TS_MODEL;
DROP TABLE PAL_TS_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_TS');
DROP TABLE TS_MODEL;

-- PAL setup
CREATE TYPE PAL_T_TS_DATA AS TABLE (ID INTEGER, PRICE DOUBLE);
CREATE TYPE PAL_T_TS_PARAMS AS TABLE (NAME VARCHAR(60), INTARGS INTEGER, DOUBLEARGS DOUBLE, STRINGARGS VARCHAR (100));
CREATE TYPE PAL_T_TS_MODEL AS TABLE (NAME VARCHAR(60), VALUE VARCHAR(5000));

CREATE COLUMN TABLE PAL_TS_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_TS_SIGNATURE VALUES (1, 'PAL.PAL_T_TS_DATA', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (2, 'PAL.PAL_T_TS_PARAMS', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (3, 'PAL.PAL_T_TS_MODEL', 'out');

GRANT SELECT ON PAL_TS_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_TS', 'AFLPAL', 'ARIMATRAIN', PAL_TS_SIGNATURE);

-- app setup
CREATE COLUMN TABLE TS_MODEL LIKE PAL_T_TS_MODEL;

-- app runtime
DROP TABLE #TS_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #TS_PARAMS LIKE PAL_T_TS_PARAMS;
INSERT INTO #TS_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #TS_PARAMS VALUES ('P', 1, null, null); -- Auto Regression
INSERT INTO #TS_PARAMS VALUES ('D', 0, null, null); -- Integrated
INSERT INTO #TS_PARAMS VALUES ('Q', 1, null, null); -- Moving Average
INSERT INTO #TS_PARAMS VALUES ('METHOD', 1, null, null); -- 0: conditional sum squares, 1: max likelihood estimation
INSERT INTO #TS_PARAMS VALUES ('STATIONARY', 1, null, null); -- 0: result may not be stationary, 1: is stationary

TRUNCATE TABLE TS_MODEL;

CALL _SYS_AFL.PAL_TS (STOCKS, #TS_PARAMS, TS_MODEL) WITH OVERVIEW;

SELECT * FROM TS_MODEL;
45 changes: 45 additions & 0 deletions Code Snippets/PAL 57 Time Series - ARIMA Predict.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_TS_RESULTS;
DROP TABLE PAL_TS_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_TSP');
DROP TABLE TS_RESULTS;
DROP VIEW V_TS_RESULTS;

-- PAL setup
CREATE TYPE PAL_T_TS_RESULTS AS TABLE(ID INTEGER, PRICE DOUBLE, LOW80 DOUBLE, HI80 DOUBLE, LOW95 DOUBLE, HI95 DOUBLE);
CREATE COLUMN TABLE PAL_TS_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_TS_SIGNATURE VALUES (1, 'PAL.PAL_T_TS_MODEL', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (2, 'PAL.PAL_T_TS_PARAMS', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (3, 'PAL.PAL_T_TS_RESULTS', 'out');

GRANT SELECT ON PAL_TS_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_TSP', 'AFLPAL', 'ARIMAFORECAST', PAL_TS_SIGNATURE);

-- app setup
CREATE COLUMN TABLE TS_RESULTS LIKE PAL_T_TS_RESULTS;
CREATE VIEW V_TS_RESULTS AS
SELECT
CASE WHEN a.ID IS NOT NULL THEN a.ID ELSE b.ID END AS ID,
a.PRICE,
ROUND(b.PRICE,2) AS PRICE_PREDICTED,
ROUND(b.LOW80,2) AS LOW80,
ROUND(b.HI80,2) AS HI80,
ROUND(b.LOW95,2) AS LOW95,
ROUND(b.HI95,2) AS HI95
FROM STOCKS a
FULL JOIN TS_RESULTS b ON (a.ID=b.ID)
;

-- app runtime
DROP TABLE #TS_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #TS_PARAMS LIKE PAL_T_TS_PARAMS;
INSERT INTO #TS_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #TS_PARAMS VALUES ('ForecastLength', 200, null, null);

TRUNCATE TABLE TS_RESULTS;

CALL _SYS_AFL.PAL_TSP (TS_MODEL, #TS_PARAMS, TS_RESULTS) WITH OVERVIEW;

SELECT * FROM V_TS_RESULTS;
Original file line number Diff line number Diff line change
@@ -0,0 +1,75 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_TS_DATA;
DROP TYPE PAL_T_TS_PARAMS;
DROP TYPE PAL_T_TS_OPTIMAL_PARAMS;
DROP TYPE PAL_T_TS_RESULTS;
DROP TABLE PAL_TS_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_TS');
DROP TABLE TS_OPTIMAL_PARAMS;
DROP TABLE TS_RESULTS;
DROP VIEW V_TS_DATA;
DROP VIEW V_TS_RESULTS;

-- PAL setup
CREATE TYPE PAL_T_TS_DATA AS TABLE (CALENDAR_ID INTEGER, SALES_AMOUNT DOUBLE);
CREATE TYPE PAL_T_TS_PARAMS AS TABLE (NAME VARCHAR(60), INTARGS INTEGER, DOUBLEARGS DOUBLE, STRINGARGS VARCHAR (100));
CREATE TYPE PAL_T_TS_OPTIMAL_PARAMS AS TABLE (NAME VARCHAR(100), VALUE DOUBLE);
--CREATE TYPE PAL_T_TS_OPTIMAL_PARAMS AS TABLE (NAME VARCHAR(100), VALUE VARCHAR(5000));
CREATE TYPE PAL_T_TS_RESULTS AS TABLE (CALENDAR_ID INTEGER, SALES_AMOUNT DOUBLE, ERROR DOUBLE);

CREATE COLUMN TABLE PAL_TS_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_TS_SIGNATURE VALUES (1, 'PAL.PAL_T_TS_DATA', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (2, 'PAL.PAL_T_TS_PARAMS', 'in');
INSERT INTO PAL_TS_SIGNATURE VALUES (3, 'PAL.PAL_T_TS_OPTIMAL_PARAMS', 'out');
INSERT INTO PAL_TS_SIGNATURE VALUES (4, 'PAL.PAL_T_TS_RESULTS', 'out');

GRANT SELECT ON PAL_TS_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_TS', 'AFLPAL', 'FORECASTSMOOTHING', PAL_TS_SIGNATURE);

-- app setup
CREATE VIEW V_TS_DATA AS
SELECT CALENDAR_ID, SUM(SALES_AMOUNT) AS SALES_AMOUNT
FROM ORDER_FACTS
WHERE ITEM_ID BETWEEN 30 AND 39
GROUP BY CALENDAR_ID
ORDER BY CALENDAR_ID
;
CREATE COLUMN TABLE TS_OPTIMAL_PARAMS LIKE PAL_T_TS_OPTIMAL_PARAMS;
CREATE COLUMN TABLE TS_RESULTS LIKE PAL_T_TS_RESULTS;
CREATE VIEW V_TS_RESULTS AS
SELECT
CASE WHEN a.CALENDAR_ID IS NOT NULL THEN a.CALENDAR_ID ELSE b.CALENDAR_ID END AS CALENDAR_ID,
a.SALES_AMOUNT,
ROUND(b.SALES_AMOUNT) AS SALES_AMOUNT_PREDICTED
FROM V_TS_DATA a
FULL JOIN TS_RESULTS b ON (a.CALENDAR_ID=b.CALENDAR_ID)
;

-- app runtime
DROP TABLE #TS_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #TS_PARAMS LIKE PAL_T_TS_PARAMS;
INSERT INTO #TS_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #TS_PARAMS VALUES ('FORECAST_MODEL_NAME', null, null, 'SESM'); SESM: Single, DESM: Double, TESM: Triple
INSERT INTO #TS_PARAMS VALUES ('FORECAST_NUM', 6, null, null);
INSERT INTO #TS_PARAMS VALUES ('STARTTIME', 0, null, null);
INSERT INTO #TS_PARAMS VALUES ('CYCLE', 3, null, null);
--INSERT INTO #TS_PARAMS VALUES ('FORECAST_AUTOMATIC', 0, null, null);
--INSERT INTO #TS_PARAMS VALUES ('ALPHA', null, 0.1, null); 0-1 for smoothing weight
--INSERT INTO #TS_PARAMS VALUES ('BETA', null, 0.1, null); 0-1 for trend (DESM & TESM)
--INSERT INTO #TS_PARAMS VALUES ('GAMMA', null, 0.1, null); 0-1 for seasonality (TESM)
-- NEW WITH SPS08
--INSERT INTO #TS_PARAMS VALUES ('MODELSELECTION', 1, null, null);
--INSERT INTO #TS_PARAMS VALUES ('OPTIMIZER_TIME_BUDGET', 10, null, null);
--INSERT INTO #TS_PARAMS VALUES ('OPTIMIZER_RANDOM_SEED', 123, null, null); -- default is system time

TRUNCATE TABLE TS_OPTIMAL_PARAMS;
TRUNCATE TABLE TS_RESULTS;

CALL _SYS_AFL.PAL_TS (V_TS_DATA, #TS_PARAMS, TS_OPTIMAL_PARAMS, TS_RESULTS) WITH OVERVIEW;

SELECT * FROM V_TS_DATA;
SELECT * FROM TS_OPTIMAL_PARAMS;
SELECT * FROM TS_RESULTS;
SELECT * FROM V_TS_RESULTS;
64 changes: 64 additions & 0 deletions Code Snippets/PAL 59 Association - Apriori New Parameters.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,64 @@
SET SCHEMA PAL;

-- cleanup
DROP TYPE PAL_T_AP_DATA;
DROP TYPE PAL_T_AP_PARAMS;
DROP TYPE PAL_T_AP_RULES;
DROP TYPE PAL_T_AP_PMML;
DROP TABLE PAL_AP_SIGNATURE;
CALL SYSTEM.AFL_WRAPPER_ERASER ('PAL_AP');
DROP VIEW V_AP_DATA;
DROP TABLE AP_RULES;
DROP TABLE AP_PMML;

-- PAL setup
CREATE TYPE PAL_T_AP_DATA AS TABLE (ORDERID INTEGER, PRODUCTID INTEGER);
CREATE TYPE PAL_T_AP_PARAMS AS TABLE (NAME VARCHAR(60), INTARGS INTEGER, DOUBLEARGS DOUBLE, STRINGARGS VARCHAR (100));
CREATE TYPE PAL_T_AP_RULES AS TABLE (PRERULE VARCHAR(500), POSTRULE VARCHAR(500), SUPPORT DOUBLE, CONFIDENCE DOUBLE, LIFT DOUBLE);
CREATE TYPE PAL_T_AP_PMML AS TABLE (ID INTEGER, PMMLMODEL VARCHAR(5000));

CREATE COLUMN TABLE PAL_AP_SIGNATURE (ID INTEGER, TYPENAME VARCHAR(100), DIRECTION VARCHAR(100));
INSERT INTO PAL_AP_SIGNATURE VALUES (1, 'PAL.PAL_T_AP_DATA', 'in');
INSERT INTO PAL_AP_SIGNATURE VALUES (2, 'PAL.PAL_T_AP_PARAMS', 'in');
INSERT INTO PAL_AP_SIGNATURE VALUES (3, 'PAL.PAL_T_AP_RULES', 'out');
INSERT INTO PAL_AP_SIGNATURE VALUES (4, 'PAL.PAL_T_AP_PMML', 'out');

GRANT SELECT ON PAL_AP_SIGNATURE TO SYSTEM;
CALL SYSTEM.AFL_WRAPPER_GENERATOR ('PAL_AP', 'AFLPAL', 'APRIORIRULE', PAL_AP_SIGNATURE);

-- app setup
CREATE VIEW V_AP_DATA AS
SELECT ORDERID, PRODUCTID
FROM FCTCUSTOMERORDER
;
CREATE COLUMN TABLE AP_RULES LIKE PAL_T_AP_RULES;
CREATE COLUMN TABLE AP_PMML LIKE PAL_T_AP_PMML;

-- app runtime
DROP TABLE #AP_PARAMS;
CREATE LOCAL TEMPORARY COLUMN TABLE #AP_PARAMS LIKE PAL_T_AP_PARAMS;
INSERT INTO #AP_PARAMS VALUES ('THREAD_NUMBER', 2, null, null);
INSERT INTO #AP_PARAMS VALUES ('MIN_SUPPORT', null, 0.001, null);
INSERT INTO #AP_PARAMS VALUES ('MIN_CONFIDENCE', null, 0.001, null);
--INSERT INTO #AP_PARAMS VALUES ('MIN_LIFT', null, 1.0, null);
INSERT INTO #AP_PARAMS VALUES ('MAX_ITEM_LENGTH', 5, null, null);
--INSERT INTO #AP_PARAMS VALUES ('MAX_CONSEQUENT', 1, null, null);
INSERT INTO #AP_PARAMS VALUES ('PMML_EXPORT', 0, null, null);

-- NEW FROM SPS08
INSERT INTO #AP_PARAMS VALUES ('IS_USE_PREFIX_TREE', 0, null, null); -- 0: no, 1: yes
INSERT INTO #AP_PARAMS VALUES ('LHS_RESTRICT', null, null, '37');
--INSERT INTO #AP_PARAMS VALUES ('LHS_RESTRICT', null, null, '43');
--INSERT INTO #AP_PARAMS VALUES ('RHS_IS_COMPLEMENTARY_LHS', 0, null, null); -- 0: no, 1: yes
--INSERT INTO #AP_PARAMS VALUES ('RHS_RESTRICT', null, null, '10');
--INSERT INTO #AP_PARAMS VALUES ('RHS_RESTRICT', null, null, '11');
--INSERT INTO #AP_PARAMS VALUES ('LHS_IS_COMPLEMENTARY_RHS', 0, null, null); -- 0: no, 1: yes

TRUNCATE TABLE AP_RULES;
TRUNCATE TABLE AP_PMML;

CALL _SYS_AFL.PAL_AP (V_AP_DATA, #AP_PARAMS, AP_RULES, AP_PMML) WITH OVERVIEW;

--SELECT * FROM V_AP_DATA;
SELECT * FROM AP_RULES ORDER BY PRERULE, POSTRULE;
--SELECT * FROM AP_PMML;
Loading

0 comments on commit 7ebea19

Please sign in to comment.